738 lines
24 KiB
SQL
738 lines
24 KiB
SQL
-- Script containing customer specific configuration sql statements for BOFO: Bouwfonds ontwikkeling zuid-west
|
|
-- (c) 2009 SG|facilitor
|
|
-- $Revision: 9 $
|
|
-- $Modtime: 3-01-11 17:50 $
|
|
--
|
|
-- Support: +31 53 4800710
|
|
|
|
|
|
|
|
SPOOL xBOFO.LST
|
|
SET ECHO ON
|
|
--------------
|
|
|
|
CREATE OR REPLACE VIEW bofo_v_info_verkoopkamer (
|
|
bezoekers,
|
|
bezet,
|
|
res_ruimte_nr,
|
|
res_ruimte_key,
|
|
vrij_tot,
|
|
bezet_tot
|
|
)
|
|
AS
|
|
SELECT NVL (bezoekers.bez_afspraak_naam, 'geen'),
|
|
(SELECT COUNT ( * )
|
|
FROM res_rsv_ruimte rrr
|
|
WHERE SYSDATE BETWEEN res_rsv_ruimte_van AND res_rsv_ruimte_tot
|
|
AND rrr.res_ruimte_opstel_key = ro.res_ruimte_opstel_key)
|
|
bezet,
|
|
res_ruimte_nr,
|
|
rr.res_ruimte_key,
|
|
(SELECT NVL (MIN (TO_CHAR (res_rsv_ruimte_van, 'hh24:mi')), '24:00')
|
|
FROM res_rsv_ruimte rrr
|
|
WHERE res_rsv_ruimte_van BETWEEN SYSDATE AND TRUNC (SYSDATE + 1)
|
|
AND rrr.res_ruimte_opstel_key = ro.res_ruimte_opstel_key)
|
|
vrij_tot,
|
|
(SELECT MIN (TO_CHAR (res_rsv_ruimte_tot, 'hh24:mi'))
|
|
FROM res_rsv_ruimte rrr
|
|
WHERE res_rsv_ruimte_tot BETWEEN SYSDATE AND TRUNC (SYSDATE + 1)
|
|
AND rrr.res_ruimte_opstel_key = ro.res_ruimte_opstel_key)
|
|
bezet_tot
|
|
FROM res_ruimte_opstelling ro,
|
|
res_ruimte rr,
|
|
(SELECT bez_afspraak_naam, res_ruimte_opstel_key
|
|
FROM bez_bezoekers b, bez_afspraak a, res_rsv_ruimte rrr
|
|
WHERE b.bez_afspraak_key = a.bez_afspraak_key
|
|
AND rrr.res_rsv_ruimte_key = a.res_rsv_ruimte_key
|
|
AND rrr.res_rsv_ruimte_van BETWEEN SYSDATE - 1 / 96
|
|
AND SYSDATE + 1 / 96) bezoekers
|
|
WHERE ro.res_ruimte_key = rr.res_ruimte_key
|
|
AND bezoekers.res_ruimte_opstel_key(+) = ro.res_ruimte_opstel_key;
|
|
|
|
|
|
CREATE OR REPLACE VIEW BOFO_V_RAP_ZIEKMELDING (naam
|
|
,datum_ziekmelding
|
|
,omschrijving
|
|
,opmerking
|
|
,datum_betermelding
|
|
,nummer)
|
|
AS
|
|
SELECT pf.prs_perslid_naam_full naam,
|
|
mld_melding_datum datum_ziekmelding,
|
|
SUBSTR (mld_melding_omschrijving, 1, 1000) omschijving,
|
|
SUBSTR (mld_melding_opmerking, 1, 1000) opmerking,
|
|
fac.gettrackingdate('MLDAFM', m.mld_melding_key) datum_betermelding,
|
|
mld_melding_key nummer
|
|
FROM mld_melding m, prs_v_perslid_fullnames pf
|
|
WHERE mld_stdmelding_key = 79 -- ziekmelding
|
|
AND m.prs_perslid_key = pf.prs_perslid_key
|
|
AND COALESCE (fac.gettrackingdate('MLDAFM', m.mld_melding_key), SYSDATE) > SYSDATE - 5;
|
|
|
|
-- no_show rapport met bijbehorende artikelen.
|
|
CREATE OR REPLACE VIEW bofo_v_rap_res_noshow (
|
|
reservering,
|
|
onderwerp,
|
|
fclt_d_datum,
|
|
aantal,
|
|
omschrijving,
|
|
prijs
|
|
)
|
|
AS
|
|
SELECT rrr.res_reservering_key || '/' || res_rsv_ruimte_volgnr,
|
|
res_rsv_ruimte_omschrijving,
|
|
TO_CHAR (res_rsv_ruimte_van, 'dd-mm-yyyy'),
|
|
rra.res_rsv_artikel_aantal,
|
|
ra.res_artikel_omschrijving,
|
|
res.getartikelprijs (res_rsv_artikel_key) prijs
|
|
FROM res_v_aanwezigrsv_artikel rra,
|
|
res_artikel ra,
|
|
res_v_aanwezigrsv_ruimte rrr
|
|
WHERE ra.res_artikel_key = rra.res_artikel_key
|
|
AND rra.res_rsv_ruimte_key = rrr.res_rsv_ruimte_key
|
|
AND res_rsv_ruimte_noshow = 1
|
|
UNION ALL
|
|
SELECT rrr.res_reservering_key || '/' || res_rsv_ruimte_volgnr,
|
|
res_rsv_ruimte_omschrijving,
|
|
TO_CHAR (res_rsv_ruimte_van, 'dd-mm-yyyy'),
|
|
1,
|
|
d.ins_deel_omschrijving,
|
|
res.getdeelprijs (res_rsv_deel_key) prijs
|
|
FROM res_v_aanwezigrsv_deel rrd,
|
|
ins_deel d,
|
|
res_deel rd,
|
|
res_v_aanwezigrsv_ruimte rrr
|
|
WHERE rd.res_deel_key = rrd.res_deel_key
|
|
AND rrd.res_rsv_ruimte_key = rrr.res_rsv_ruimte_key
|
|
AND rd.res_ins_deel_key = d.ins_deel_key
|
|
AND res_rsv_ruimte_noshow = 1;
|
|
|
|
|
|
CREATE OR REPLACE VIEW bofo_v_vak_recht (
|
|
prs_perslid_key,
|
|
vak,
|
|
jaar
|
|
)
|
|
AS
|
|
SELECT prs_perslid_key,
|
|
fac.safe_to_number (prs_kenmerklink_waarde),
|
|
SUBSTR (prs_kenmerk_omschrijving,
|
|
LENGTH (prs_kenmerk_omschrijving) - 3,
|
|
4
|
|
)
|
|
jaar
|
|
FROM prs_v_aanwezigperslid, prs_kenmerklink kl, prs_kenmerk k
|
|
WHERE prs_link_key = prs_perslid_key
|
|
AND kl.prs_kenmerk_key = k.prs_kenmerk_key
|
|
AND UPPER (k.prs_kenmerk_omschrijving) LIKE '%SALDO%VAK%';
|
|
|
|
|
|
CREATE OR REPLACE VIEW bofo_v_atv_recht (
|
|
prs_perslid_key,
|
|
atv,
|
|
jaar
|
|
)
|
|
AS
|
|
SELECT prs_perslid_key,
|
|
fac.safe_to_number (prs_kenmerklink_waarde),
|
|
SUBSTR (prs_kenmerk_omschrijving,
|
|
LENGTH (prs_kenmerk_omschrijving) - 3,
|
|
4
|
|
)
|
|
jaar
|
|
FROM prs_v_aanwezigperslid, prs_kenmerklink kl, prs_kenmerk k
|
|
WHERE prs_link_key = prs_perslid_key
|
|
AND kl.prs_kenmerk_key = k.prs_kenmerk_key
|
|
AND UPPER (k.prs_kenmerk_omschrijving) LIKE '%SALDO%ATV%';
|
|
|
|
CREATE OR REPLACE VIEW bofo_v_verlof_gegevens (
|
|
mld_melding_key,
|
|
prs_perslid_key,
|
|
prs_afdeling_key,
|
|
van,
|
|
tot,
|
|
status,
|
|
vak,
|
|
atv,
|
|
bijz
|
|
)
|
|
AS
|
|
SELECT m.mld_melding_key,
|
|
m.prs_perslid_key,
|
|
p.prs_afdeling_key,
|
|
(SELECT TO_DATE (mld_kenmerkmelding_waarde, 'dd-mm-yyyy')
|
|
FROM mld_kenmerkmelding km
|
|
WHERE km.mld_melding_key = m.mld_melding_key
|
|
AND km.mld_kenmerk_key = 121) -- datum van
|
|
van,
|
|
(SELECT TO_DATE (mld_kenmerkmelding_waarde, 'dd-mm-yyyy')
|
|
FROM mld_kenmerkmelding km
|
|
WHERE km.mld_melding_key = m.mld_melding_key
|
|
AND km.mld_kenmerk_key = 122) -- datum tot
|
|
tot,
|
|
mld_melding_status,
|
|
COALESCE ( (SELECT fac.safe_to_number (mld_kenmerkmelding_waarde)
|
|
FROM mld_kenmerkmelding km
|
|
WHERE km.mld_melding_key = m.mld_melding_key
|
|
AND km.mld_kenmerk_key = 123), -- vak_dagen
|
|
0
|
|
)
|
|
vak,
|
|
COALESCE ( (SELECT fac.safe_to_number (mld_kenmerkmelding_waarde)
|
|
FROM mld_kenmerkmelding km
|
|
WHERE km.mld_melding_key = m.mld_melding_key
|
|
AND km.mld_kenmerk_key = 142), -- atv dagen
|
|
0
|
|
)
|
|
atv,
|
|
COALESCE ( (SELECT fac.safe_to_number (mld_kenmerkmelding_waarde)
|
|
FROM mld_kenmerkmelding km
|
|
WHERE km.mld_melding_key = m.mld_melding_key
|
|
AND km.mld_kenmerk_key = 221), -- atv dagen
|
|
0
|
|
)
|
|
bijz
|
|
FROM mld_melding m,
|
|
prs_perslid p
|
|
WHERE mld_stdmelding_key = 201
|
|
AND m.prs_perslid_key = p.prs_perslid_key;
|
|
|
|
|
|
CREATE OR REPLACE VIEW bofo_v_verlof (
|
|
naam,
|
|
offset,
|
|
prs_perslid_key,
|
|
van,
|
|
tot,
|
|
status,
|
|
vak,
|
|
atv,
|
|
bijz
|
|
)
|
|
AS
|
|
SELECT prs_perslid_naam_full,
|
|
-1000 offset,
|
|
p.prs_perslid_key,
|
|
NULL van,
|
|
NULL tot,
|
|
'saldo 01-01-'||to_char(sysdate,'yyyy') status,
|
|
coalesce(vak,0),
|
|
coalesce(atv,0),
|
|
null
|
|
FROM bofo_v_vak_recht vr, bofo_v_atv_recht ar, prs_v_perslid_fullnames pf, prs_perslid p
|
|
WHERE p.prs_perslid_key = pf.prs_perslid_key
|
|
AND vr.prs_perslid_key(+) = pf.prs_perslid_key
|
|
AND ar.prs_perslid_key(+) = pf.prs_perslid_key
|
|
AND vr.jaar = to_char(sysdate, 'yyyy')
|
|
AND ar.jaar = to_char(sysdate, 'yyyy')
|
|
UNION ALL
|
|
SELECT prs_perslid_naam_full,
|
|
van - SYSDATE offset,
|
|
pf.prs_perslid_key,
|
|
van,
|
|
tot,
|
|
decode (to_char(m.van, 'yyyy'), to_char(m.tot, 'yyyy'),'goedgekeurd','***********'),
|
|
-1 * fac.safe_to_number (vak),
|
|
-1 * fac.safe_to_number (atv),
|
|
-1 * fac.safe_to_number (bijz)
|
|
FROM bofo_v_verlof_gegevens m, prs_v_perslid_fullnames pf
|
|
WHERE m.prs_perslid_key = pf.prs_perslid_key AND status IN (4, 5, 6, 7)
|
|
AND (to_char(m.van, 'yyyy') = to_char(sysdate, 'yyyy')
|
|
OR to_char(m.tot, 'yyyy') = to_char(sysdate, 'yyyy'))
|
|
UNION ALL
|
|
SELECT prs_perslid_naam_full,
|
|
van - SYSDATE offset,
|
|
pf.prs_perslid_key,
|
|
van,
|
|
tot,
|
|
decode (to_char(m.van, 'yyyy'), to_char(m.tot, 'yyyy'),'aangevraagd','***********'),
|
|
-1 * fac.safe_to_number (vak),
|
|
-1 * fac.safe_to_number (atv),
|
|
-1 * fac.safe_to_number (bijz)
|
|
FROM bofo_v_verlof_gegevens m, prs_v_perslid_fullnames pf
|
|
WHERE m.prs_perslid_key = pf.prs_perslid_key AND status IN (2,3)
|
|
AND (to_char(m.van, 'yyyy') = to_char(sysdate, 'yyyy')
|
|
OR to_char(m.tot, 'yyyy') = to_char(sysdate, 'yyyy'))
|
|
UNION ALL
|
|
SELECT prs_perslid_naam_full,
|
|
1000 offset,
|
|
p.prs_perslid_key,
|
|
NULL van,
|
|
NULL tot,
|
|
'huidig saldo' status,
|
|
vak - svak,
|
|
atv - satv,
|
|
sbijz
|
|
FROM bofo_v_vak_recht vr,
|
|
bofo_v_atv_recht ar,
|
|
prs_perslid p,
|
|
prs_v_perslid_fullnames pf,
|
|
(SELECT prs_perslid_key, SUM (vak) svak, SUM (atv) satv, SUM(bijz) sbijz
|
|
FROM bofo_v_verlof_gegevens m
|
|
WHERE status IN (4, 5, 6, 7)
|
|
AND (to_char(m.van, 'yyyy') = to_char(sysdate, 'yyyy')
|
|
OR to_char(m.tot, 'yyyy') = to_char(sysdate, 'yyyy'))
|
|
GROUP BY prs_perslid_key) verbruik
|
|
WHERE verbruik.prs_perslid_key = pf.prs_perslid_key
|
|
AND p.prs_perslid_key = pf.prs_perslid_key
|
|
AND vr.prs_perslid_key = pf.prs_perslid_key
|
|
AND vr.prs_perslid_key(+) = pf.prs_perslid_key
|
|
AND ar.prs_perslid_key(+) = pf.prs_perslid_key
|
|
AND vr.jaar = to_char(sysdate, 'yyyy')
|
|
AND ar.jaar = to_char(sysdate, 'yyyy');
|
|
|
|
CREATE OR REPLACE VIEW bofo_v_rap_verlof (
|
|
fclt_f_naam,
|
|
hide_f_offset,
|
|
prs_perslid_key,
|
|
van,
|
|
tot,
|
|
status,
|
|
vak,
|
|
atv,
|
|
bijz
|
|
)
|
|
AS
|
|
SELECT
|
|
naam,
|
|
offset,
|
|
prs_perslid_key,
|
|
van,
|
|
tot,
|
|
status,
|
|
vak,
|
|
atv,
|
|
bijz
|
|
FROM bofo_v_verlof;
|
|
|
|
|
|
-- rapport verlofuren voor leidinggevenden.
|
|
CREATE OR REPLACE VIEW bofo_v_rap_verlof_totaal (
|
|
fclt_f_naam,
|
|
fclt_3d_user_key,
|
|
prs_perslid_key,
|
|
begin_v,
|
|
begin_a,
|
|
aangevr_v,
|
|
aangevr_a,
|
|
goedgek_v,
|
|
goedgek_a,
|
|
saldo_v,
|
|
saldo_a
|
|
)
|
|
AS
|
|
SELECT pf.prs_perslid_naam_full,
|
|
fac.safe_to_number(kl.prs_kenmerklink_waarde),
|
|
p.prs_perslid_key,
|
|
(SELECT vak
|
|
FROM bofo_v_verlof v
|
|
WHERE status LIKE 'saldo%'
|
|
AND v.prs_perslid_key = p.prs_perslid_key)
|
|
begin_v,
|
|
(SELECT atv
|
|
FROM bofo_v_verlof v
|
|
WHERE status LIKE 'saldo%'
|
|
AND v.prs_perslid_key = p.prs_perslid_key)
|
|
begin_a,
|
|
(SELECT SUM (vak)
|
|
FROM bofo_v_verlof v
|
|
WHERE status = 'aangevraagd'
|
|
AND v.prs_perslid_key = p.prs_perslid_key)
|
|
aangevr_v,
|
|
(SELECT SUM (atv)
|
|
FROM bofo_v_verlof v
|
|
WHERE status = 'aangevraagd'
|
|
AND v.prs_perslid_key = p.prs_perslid_key)
|
|
aangevr_a,
|
|
(SELECT SUM (vak)
|
|
FROM bofo_v_verlof v
|
|
WHERE status = 'goedgekeurd'
|
|
AND v.prs_perslid_key = p.prs_perslid_key)
|
|
goedgek_v,
|
|
(SELECT SUM (atv)
|
|
FROM bofo_v_verlof v
|
|
WHERE status = 'goedgekeurd'
|
|
AND v.prs_perslid_key = p.prs_perslid_key)
|
|
goedgek_a,
|
|
(SELECT vak
|
|
FROM bofo_v_verlof v
|
|
WHERE status LIKE 'huidig%'
|
|
AND v.prs_perslid_key = p.prs_perslid_key)
|
|
saldo_v,
|
|
(SELECT atv
|
|
FROM bofo_v_verlof v
|
|
WHERE status LIKE 'huidig%'
|
|
AND v.prs_perslid_key = p.prs_perslid_key)
|
|
saldo_a
|
|
FROM prs_perslid p, prs_v_perslid_fullnames pf, prs_kenmerklink kl
|
|
WHERE p.prs_perslid_key = pf.prs_perslid_key
|
|
AND p.prs_perslid_key = kl.prs_link_key
|
|
AND kl.prs_kenmerk_key = 1040;
|
|
-- leidinggevende
|
|
|
|
|
|
-- rapport verlofuren voor leidinggevenden.
|
|
CREATE OR REPLACE VIEW bofo_v_rap_verlof_detail (
|
|
fclt_f_naam,
|
|
hide_f_offset,
|
|
fclt_3d_user_key,
|
|
prs_perslid_key,
|
|
van,
|
|
tot,
|
|
status,
|
|
vak,
|
|
atv,
|
|
bijz
|
|
)
|
|
AS
|
|
SELECT naam,
|
|
offset,
|
|
fac.safe_to_number(kl.prs_kenmerklink_waarde),
|
|
prs_perslid_key,
|
|
TO_CHAR (van, 'dd-mm-yyyy'),
|
|
TO_CHAR (tot, 'dd-mm-yyyy'),
|
|
status,
|
|
vak,
|
|
atv,
|
|
bijz
|
|
FROM bofo_v_verlof v, prs_kenmerklink kl
|
|
WHERE v.prs_perslid_key = kl.prs_link_key
|
|
AND kl.prs_kenmerk_key = 1040;
|
|
-- leidinggevende
|
|
|
|
-- rapport verlofuren voor medewerker.
|
|
CREATE OR REPLACE VIEW bofo_v_rap_verlof_medew (
|
|
fclt_f_naam,
|
|
hide_f_offset,
|
|
fclt_3d_user_key,
|
|
van,
|
|
tot,
|
|
status,
|
|
vak,
|
|
atv,
|
|
bijz
|
|
)
|
|
AS
|
|
SELECT naam,
|
|
offset,
|
|
prs_perslid_key,
|
|
TO_CHAR (van, 'dd-mm-yyyy'),
|
|
TO_CHAR (tot, 'dd-mm-yyyy'),
|
|
status,
|
|
vak,
|
|
atv,
|
|
bijz
|
|
FROM bofo_v_verlof;
|
|
|
|
|
|
CREATE OR REPLACE VIEW bofo_v_noti_verlof (
|
|
code,
|
|
sender,
|
|
receiver,
|
|
text,
|
|
key,
|
|
xkey
|
|
)
|
|
AS
|
|
SELECT 'MLDINF',
|
|
NULL,
|
|
fac.safe_to_number(kl.prs_kenmerklink_waarde),
|
|
'Verlofaanvraag medewerker: ' || pf.prs_perslid_naam_full,
|
|
m.mld_melding_key,
|
|
NULL
|
|
FROM mld_melding m,
|
|
prs_v_perslid_fullnames pf,
|
|
prs_kenmerklink kl
|
|
WHERE m.prs_perslid_key = pf.prs_perslid_key
|
|
AND m.mld_stdmelding_key = 201 -- verlofaanvraag
|
|
AND m.mld_melding_status IN (2, 3)
|
|
AND m.mld_melding_datum > SYSDATE - 1
|
|
AND m.prs_perslid_key = kl.prs_link_key
|
|
AND kl.prs_kenmerk_key = 1040;
|
|
-- leidinggevende
|
|
|
|
CREATE OR REPLACE VIEW bofo_v_rap_verlof_goedkeuring (
|
|
fclt_3d_user_key,
|
|
mld_melding_key,
|
|
naam,
|
|
van,
|
|
tot,
|
|
vak,
|
|
atv,
|
|
bijz,
|
|
omschrijving
|
|
)
|
|
AS
|
|
SELECT fac.safe_to_number(kl.prs_kenmerklink_waarde),
|
|
m.mld_melding_key,
|
|
prs_perslid_naam_full naam,
|
|
van,
|
|
tot,
|
|
vak,
|
|
atv,
|
|
bijz,
|
|
mld_melding_omschrijving omschrijving
|
|
FROM bofo_v_verlof_gegevens vg, mld_melding m, prs_v_perslid_fullnames pf, prs_kenmerklink kl
|
|
WHERE vg.mld_melding_key = m.mld_melding_key
|
|
AND vg.prs_perslid_key = pf.prs_perslid_key
|
|
AND m.mld_melding_status IN (2, 3) -- ingevoerd, ingezien
|
|
AND vg.prs_perslid_key = kl.prs_link_key
|
|
AND kl.prs_kenmerk_key = 1040;
|
|
-- leidinggevende
|
|
|
|
|
|
CREATE OR REPLACE VIEW bofo_v_verlof_afg_jaar (
|
|
naam,
|
|
offset,
|
|
prs_perslid_key,
|
|
van,
|
|
tot,
|
|
status,
|
|
vak,
|
|
atv,
|
|
bijz
|
|
)
|
|
AS
|
|
SELECT prs_perslid_naam_full,
|
|
-1000 offset,
|
|
p.prs_perslid_key,
|
|
NULL van,
|
|
NULL tot,
|
|
'saldo 01-01-'||to_char(sysdate-365,'yyyy') status,
|
|
coalesce(vak,0),
|
|
coalesce(atv,0),
|
|
null
|
|
FROM bofo_v_vak_recht vr, bofo_v_atv_recht ar, prs_v_perslid_fullnames pf, prs_perslid p
|
|
WHERE p.prs_perslid_key = pf.prs_perslid_key
|
|
AND vr.prs_perslid_key(+) = pf.prs_perslid_key
|
|
AND ar.prs_perslid_key(+) = pf.prs_perslid_key
|
|
AND vr.jaar = to_char(sysdate-365, 'yyyy')
|
|
AND ar.jaar = to_char(sysdate-365, 'yyyy')
|
|
UNION ALL
|
|
SELECT prs_perslid_naam_full,
|
|
van - SYSDATE offset,
|
|
pf.prs_perslid_key,
|
|
van,
|
|
tot,
|
|
decode (to_char(m.van, 'yyyy'), to_char(m.tot, 'yyyy'),'goedgekeurd','***********'),
|
|
-1 * fac.safe_to_number (vak),
|
|
-1 * fac.safe_to_number (atv),
|
|
-1 * fac.safe_to_number (bijz)
|
|
FROM bofo_v_verlof_gegevens m, prs_v_perslid_fullnames pf
|
|
WHERE m.prs_perslid_key = pf.prs_perslid_key AND status IN (4, 5, 6, 7)
|
|
AND (to_char(m.van, 'yyyy') = to_char(sysdate-365, 'yyyy')
|
|
OR to_char(m.tot, 'yyyy') = to_char(sysdate-365, 'yyyy'))
|
|
UNION ALL
|
|
SELECT prs_perslid_naam_full,
|
|
van - SYSDATE offset,
|
|
pf.prs_perslid_key,
|
|
van,
|
|
tot,
|
|
decode (to_char(m.van, 'yyyy'), to_char(m.tot, 'yyyy'),'aangevraagd','***********'),
|
|
-1 * fac.safe_to_number (vak),
|
|
-1 * fac.safe_to_number (atv),
|
|
-1 * fac.safe_to_number (bijz)
|
|
FROM bofo_v_verlof_gegevens m, prs_v_perslid_fullnames pf
|
|
WHERE m.prs_perslid_key = pf.prs_perslid_key AND status IN (2,3)
|
|
AND (to_char(m.van, 'yyyy') = to_char(sysdate-365, 'yyyy')
|
|
OR to_char(m.tot, 'yyyy') = to_char(sysdate-365, 'yyyy'))
|
|
UNION ALL
|
|
SELECT prs_perslid_naam_full,
|
|
1000 offset,
|
|
p.prs_perslid_key,
|
|
NULL van,
|
|
NULL tot,
|
|
'huidig saldo' status,
|
|
vak - svak,
|
|
atv - satv,
|
|
sbijz
|
|
FROM bofo_v_vak_recht vr,
|
|
bofo_v_atv_recht ar,
|
|
prs_perslid p,
|
|
prs_v_perslid_fullnames pf,
|
|
(SELECT prs_perslid_key, SUM (vak) svak, SUM (atv) satv, SUM(bijz) sbijz
|
|
FROM bofo_v_verlof_gegevens m
|
|
WHERE status IN (4, 5, 6, 7)
|
|
AND (to_char(m.van, 'yyyy') = to_char(sysdate-365, 'yyyy')
|
|
OR to_char(m.tot, 'yyyy') = to_char(sysdate-365, 'yyyy'))
|
|
GROUP BY prs_perslid_key) verbruik
|
|
WHERE verbruik.prs_perslid_key = pf.prs_perslid_key
|
|
AND p.prs_perslid_key = pf.prs_perslid_key
|
|
AND vr.prs_perslid_key = pf.prs_perslid_key
|
|
AND vr.prs_perslid_key(+) = pf.prs_perslid_key
|
|
AND ar.prs_perslid_key(+) = pf.prs_perslid_key
|
|
AND vr.jaar = to_char(sysdate-365, 'yyyy')
|
|
AND ar.jaar = to_char(sysdate-365, 'yyyy');
|
|
|
|
-- rapport verlofuren voor leidinggevenden.
|
|
CREATE OR REPLACE VIEW bofo_v_rap_verlof_tot_afg_jaar (
|
|
fclt_f_naam,
|
|
fclt_3d_user_key,
|
|
prs_perslid_key,
|
|
begin_v,
|
|
begin_a,
|
|
aangevr_v,
|
|
aangevr_a,
|
|
goedgek_v,
|
|
goedgek_a,
|
|
saldo_v,
|
|
saldo_a
|
|
)
|
|
AS
|
|
SELECT pf.prs_perslid_naam_full,
|
|
fac.safe_to_number(kl.prs_kenmerklink_waarde),
|
|
p.prs_perslid_key,
|
|
(SELECT vak
|
|
FROM bofo_v_verlof_afg_jaar v
|
|
WHERE status LIKE 'saldo%'
|
|
AND v.prs_perslid_key = p.prs_perslid_key)
|
|
begin_v,
|
|
(SELECT atv
|
|
FROM bofo_v_verlof_afg_jaar v
|
|
WHERE status LIKE 'saldo%'
|
|
AND v.prs_perslid_key = p.prs_perslid_key)
|
|
begin_a,
|
|
(SELECT SUM (vak)
|
|
FROM bofo_v_verlof_afg_jaar v
|
|
WHERE status = 'aangevraagd'
|
|
AND v.prs_perslid_key = p.prs_perslid_key)
|
|
aangevr_v,
|
|
(SELECT SUM (atv)
|
|
FROM bofo_v_verlof_afg_jaar v
|
|
WHERE status = 'aangevraagd'
|
|
AND v.prs_perslid_key = p.prs_perslid_key)
|
|
aangevr_a,
|
|
(SELECT SUM (vak)
|
|
FROM bofo_v_verlof_afg_jaar v
|
|
WHERE status = 'goedgekeurd'
|
|
AND v.prs_perslid_key = p.prs_perslid_key)
|
|
goedgek_v,
|
|
(SELECT SUM (atv)
|
|
FROM bofo_v_verlof_afg_jaar v
|
|
WHERE status = 'goedgekeurd'
|
|
AND v.prs_perslid_key = p.prs_perslid_key)
|
|
goedgek_a,
|
|
(SELECT vak
|
|
FROM bofo_v_verlof_afg_jaar v
|
|
WHERE status LIKE 'huidig%'
|
|
AND v.prs_perslid_key = p.prs_perslid_key)
|
|
saldo_v,
|
|
(SELECT atv
|
|
FROM bofo_v_verlof_afg_jaar v
|
|
WHERE status LIKE 'huidig%'
|
|
AND v.prs_perslid_key = p.prs_perslid_key)
|
|
saldo_a
|
|
FROM prs_perslid p, prs_v_perslid_fullnames pf, prs_kenmerklink kl
|
|
WHERE p.prs_perslid_key = pf.prs_perslid_key
|
|
AND p.prs_perslid_key = kl.prs_link_key
|
|
AND kl.prs_kenmerk_key = 1040;
|
|
-- leidinggevende
|
|
|
|
|
|
CREATE OR REPLACE VIEW bofo_v_rap_verlof_afg_jaar (
|
|
fclt_f_naam,
|
|
hide_f_offset,
|
|
prs_perslid_key,
|
|
van,
|
|
tot,
|
|
status,
|
|
vak,
|
|
atv,
|
|
bijz
|
|
)
|
|
AS
|
|
SELECT
|
|
naam,
|
|
offset,
|
|
prs_perslid_key,
|
|
van,
|
|
tot,
|
|
status,
|
|
vak,
|
|
atv,
|
|
bijz
|
|
FROM bofo_v_verlof_afg_jaar;
|
|
|
|
|
|
CREATE OR REPLACE PACKAGE BOFO AS
|
|
-- PACKAGES voor de BOFO specifieke rapportages
|
|
TYPE t_cursor IS REF CURSOR;
|
|
FUNCTION vt (p_offset IN number, p_prs_perslid_key IN NUMBER) RETURN VARCHAR2;
|
|
PROCEDURE rap_verlof_overzicht (user_key IN NUMBER, p_datum_van IN VARCHAR2, p_datum_tot IN VARCHAR2, p_cursor OUT t_cursor);
|
|
END;
|
|
/
|
|
|
|
CREATE OR REPLACE PACKAGE BODY BOFO
|
|
AS
|
|
-- Bepaal de of een persoon verlof aangevraagd heeft op deze datum.
|
|
FUNCTION vt (p_offset IN number, p_prs_perslid_key IN number)
|
|
RETURN VARCHAR2
|
|
IS
|
|
v_result VARCHAR2 (100);
|
|
v_day_of_week VARCHAR2 (3);
|
|
BEGIN
|
|
v_day_of_week := TO_CHAR (TRUNC (SYSDATE) + p_offset, 'd');
|
|
|
|
SELECT v_day_of_week || '-' || NVL (MAX (status), 'geen')
|
|
INTO v_result
|
|
FROM bofo_v_rap_verlof v
|
|
WHERE v.prs_perslid_key = p_prs_perslid_key
|
|
AND TRUNC (SYSDATE) + p_offset BETWEEN van AND tot;
|
|
RETURN v_result;
|
|
END vt;
|
|
|
|
PROCEDURE rap_verlof_overzicht (user_key IN number,
|
|
p_datum_van IN varchar2 -- Let wel: formaat '13-05-2005'
|
|
,
|
|
p_datum_tot IN varchar2,
|
|
p_cursor OUT t_cursor
|
|
)
|
|
AS
|
|
v_datum_van DATE;
|
|
v_datum_tot DATE;
|
|
v_query_st VARCHAR2 (4000);
|
|
v_query VARCHAR2 (4000);
|
|
v_query_end VARCHAR2 (4000);
|
|
v_loop_date DATE;
|
|
v_count NUMBER;
|
|
BEGIN
|
|
v_datum_van := fac.safe_to_date (p_datum_van, 'dd-mm-yyyy');
|
|
v_datum_tot := fac.safe_to_date (p_datum_tot, 'dd-mm-yyyy') + 1;
|
|
|
|
-- we ondersteunen een interval van max 100 dagen. Anders past de query niet meer in de variabele
|
|
IF v_datum_tot - v_datum_van > 100
|
|
THEN
|
|
v_datum_tot := v_datum_van + 100;
|
|
END IF;
|
|
|
|
v_query := '';
|
|
v_query_st := 'SELECT pf.prs_perslid_naam_full naam, prs_afdeling_omschrijving afd ';
|
|
v_loop_date := v_datum_van;
|
|
v_count := v_datum_van - TRUNC (SYSDATE);
|
|
|
|
WHILE v_loop_date < v_datum_tot
|
|
LOOP
|
|
v_query :=
|
|
v_query
|
|
|| ' ,bofo.vt ('
|
|
|| v_count
|
|
|| ', p.prs_perslid_key) d'
|
|
|| TO_CHAR (SYSDATE + v_count, 'mmdd');
|
|
v_loop_date := v_loop_date + 1;
|
|
v_count := v_count + 1;
|
|
END LOOP;
|
|
|
|
v_query_end := ' FROM prs_v_perslid_fullnames pf, prs_perslid p, prs_afdeling a WHERE pf.prs_perslid_key = p.prs_perslid_key AND a.prs_afdeling_key = p.prs_afdeling_key';
|
|
|
|
OPEN p_cursor FOR v_query_st || v_query || v_query_end;
|
|
END rap_verlof_overzicht;
|
|
END;
|
|
/
|
|
|
|
BEGIN fac.registercustversion('BOFO', 11); END;
|
|
/
|
|
|
|
|
|
COMMIT;
|
|
|
|
spool off
|