2886 lines
106 KiB
SQL
2886 lines
106 KiB
SQL
-- Script containing customer specific configuration sql statements for AONL
|
||
-- (c) 2008 SG|facilitor bv
|
||
-- $Revision$
|
||
-- $Id$
|
||
--
|
||
-- Support: +31 53 4800700
|
||
|
||
set echo on
|
||
|
||
spool xaonl.lst
|
||
|
||
/* Formatted on 4-2-2010 10:52:52 (QP5 v5.115.810.9015) */
|
||
CREATE OR REPLACE VIEW aonl_v_hv_actual
|
||
(
|
||
dis_oms,
|
||
loc_code,
|
||
geb_code,
|
||
ver_code,
|
||
ruimte_nr,
|
||
ruimtesoort,
|
||
wp_cap,
|
||
teken_opp,
|
||
sp_nummer,
|
||
sp_naam,
|
||
bezetting,
|
||
m2_wpnorm,
|
||
m2_tarief
|
||
)
|
||
AS
|
||
(SELECT a.alg_district_omschrijving,
|
||
a.alg_locatie_code,
|
||
a.alg_gebouw_code,
|
||
a.alg_verdieping_code,
|
||
a.alg_ruimte_nr,
|
||
b.ruimtesoort,
|
||
fac.safe_to_number (COALESCE (c.wp_cap, '0')),
|
||
a.opp,
|
||
d.afd_naam,
|
||
d.afd_oms,
|
||
d.afd_bez,
|
||
(SELECT fac.safe_to_number (
|
||
COALESCE (kl.prs_kenmerklink_waarde, '0')
|
||
)
|
||
FROM prs_kenmerklink kl
|
||
WHERE kl.prs_link_key = 21 -- Atos Origin
|
||
AND kl.prs_kenmerklink_niveau = 'B'
|
||
AND kl.prs_kenmerk_key = 1020)
|
||
m2_wpnorm, -- m2-wpnorm
|
||
a.m2_tarief
|
||
FROM (SELECT r.alg_ruimte_key,
|
||
r.alg_ruimte_nr,
|
||
v.alg_verdieping_code,
|
||
g.alg_gebouw_code,
|
||
l.alg_locatie_code,
|
||
d.alg_district_omschrijving,
|
||
r.alg_ruimte_bruto_vloeropp opp,
|
||
(SELECT fac.safe_to_number(COALESCE (
|
||
ok.alg_onrgoedkenmerk_waarde,
|
||
'0'
|
||
))
|
||
FROM alg_onrgoedkenmerk ok
|
||
WHERE ok.alg_kenmerk_key = 1060 -- m2-tarief
|
||
AND ok.alg_onrgoed_niveau = 'G'
|
||
AND ok.alg_onrgoed_key =
|
||
g.alg_gebouw_key)
|
||
m2_tarief
|
||
FROM alg_v_aanwezigruimte r,
|
||
alg_verdieping v,
|
||
alg_gebouw g,
|
||
alg_locatie l,
|
||
alg_district d
|
||
WHERE r.alg_verdieping_key = v.alg_verdieping_key
|
||
AND v.alg_gebouw_key = g.alg_gebouw_key
|
||
AND g.alg_locatie_key = l.alg_locatie_key
|
||
AND l.alg_district_key = d.alg_district_key)
|
||
a
|
||
LEFT JOIN
|
||
(SELECT r.alg_ruimte_key,
|
||
COALESCE (sr.alg_srtruimte_omschrijving, '-')
|
||
ruimtesoort
|
||
FROM alg_v_aanwezigruimte r, alg_srtruimte sr
|
||
WHERE r.alg_srtruimte_key = sr.alg_srtruimte_key) b
|
||
ON a.alg_ruimte_key = b.alg_ruimte_key
|
||
LEFT JOIN
|
||
(SELECT ok.alg_onrgoed_key,
|
||
ok.alg_onrgoedkenmerk_waarde wp_cap
|
||
FROM alg_onrgoedkenmerk ok
|
||
WHERE ok.alg_kenmerk_key = 1020 -- wp_cap
|
||
AND ok.alg_onrgoed_niveau = 'R') c
|
||
ON a.alg_ruimte_key = c.alg_onrgoed_key
|
||
LEFT JOIN -- afdeling(en) op ruimte
|
||
(SELECT ra.alg_ruimte_key,
|
||
afd.prs_afdeling_naam afd_naam,
|
||
afd.prs_afdeling_omschrijving afd_oms,
|
||
ra.prs_ruimteafdeling_bezetting afd_bez
|
||
FROM prs_v_aanwezigruimteafdeling ra, prs_afdeling afd
|
||
WHERE ra.prs_afdeling_key = afd.prs_afdeling_key
|
||
UNION ALL
|
||
SELECT x.alg_ruimte_key,
|
||
NULL afd_naam,
|
||
NULL afd_oms,
|
||
(100 - x.rui_bez) afd_bez
|
||
FROM ( SELECT ra.alg_ruimte_key,
|
||
SUM (ra.prs_ruimteafdeling_bezetting)
|
||
rui_bez
|
||
FROM prs_v_aanwezigruimteafdeling ra
|
||
GROUP BY ra.alg_ruimte_key) x
|
||
WHERE x.rui_bez < 100) d
|
||
ON a.alg_ruimte_key = d.alg_ruimte_key)
|
||
/
|
||
CREATE OR REPLACE VIEW aonl_v_hv_xactual (
|
||
loc_code,
|
||
geb_code,
|
||
ver_code,
|
||
ruimte_nr,
|
||
ruimtesoort,
|
||
wp_cap,
|
||
teken_opp,
|
||
nor_opp,
|
||
sp_nummer,
|
||
sp_naam,
|
||
bezetting,
|
||
m2_wpnorm,
|
||
m2_tarief
|
||
)
|
||
AS
|
||
(SELECT a.alg_locatie_code,
|
||
a.alg_gebouw_code,
|
||
a.alg_verdieping_code,
|
||
a.alg_ruimte_nr,
|
||
b.ruimtesoort,
|
||
fac.safe_to_number (COALESCE (c.wp_cap, '0')),
|
||
a.opp,
|
||
fac.safe_to_number (COALESCE (x.opp, '0')),
|
||
d.afd_naam,
|
||
d.afd_oms,
|
||
d.afd_bez,
|
||
(SELECT fac.safe_to_number(COALESCE (kl.prs_kenmerklink_waarde, '0'
|
||
))
|
||
FROM prs_kenmerklink kl
|
||
WHERE kl.prs_link_key = 21 -- Atos Origin
|
||
AND kl.prs_kenmerklink_niveau = 'B'
|
||
AND kl.prs_kenmerk_key = 1020)
|
||
m2_wpnorm, -- m2-wpnorm
|
||
(SELECT fac.safe_to_number(COALESCE (kl.prs_kenmerklink_waarde, '0'
|
||
))
|
||
FROM prs_kenmerklink kl
|
||
WHERE kl.prs_link_key = 21 -- Atos Origin
|
||
AND kl.prs_kenmerklink_niveau = 'B'
|
||
AND kl.prs_kenmerk_key = 1021)
|
||
m2_tarief -- m2-tarief
|
||
FROM (SELECT r.alg_ruimte_key,
|
||
r.alg_ruimte_nr,
|
||
v.alg_verdieping_code,
|
||
g.alg_gebouw_code,
|
||
l.alg_locatie_code,
|
||
r.alg_ruimte_bruto_vloeropp opp
|
||
FROM alg_v_aanwezigruimte r,
|
||
alg_verdieping v,
|
||
alg_gebouw g,
|
||
alg_locatie l
|
||
WHERE r.alg_verdieping_key = v.alg_verdieping_key
|
||
AND v.alg_gebouw_key = g.alg_gebouw_key
|
||
AND g.alg_locatie_key = l.alg_locatie_key) a
|
||
LEFT JOIN
|
||
(SELECT r.alg_ruimte_key,
|
||
COALESCE (sr.alg_srtruimte_omschrijving, '-')
|
||
ruimtesoort
|
||
FROM alg_v_aanwezigruimte r, alg_srtruimte sr
|
||
WHERE r.alg_srtruimte_key = sr.alg_srtruimte_key) b
|
||
ON a.alg_ruimte_key = b.alg_ruimte_key
|
||
LEFT JOIN
|
||
(SELECT ok.alg_onrgoed_key,
|
||
ok.alg_onrgoedkenmerk_waarde wp_cap
|
||
FROM alg_onrgoedkenmerk ok
|
||
WHERE ok.alg_kenmerk_key = 1020 -- wp_cap
|
||
AND ok.alg_onrgoed_niveau = 'R') c
|
||
ON a.alg_ruimte_key = c.alg_onrgoed_key
|
||
LEFT JOIN
|
||
(SELECT ok.alg_onrgoed_key, ok.alg_onrgoedkenmerk_waarde opp
|
||
FROM alg_onrgoedkenmerk ok
|
||
WHERE ok.alg_kenmerk_key = 1081 -- nor_opp
|
||
AND ok.alg_onrgoed_niveau = 'R') x
|
||
ON a.alg_ruimte_key = x.alg_onrgoed_key
|
||
LEFT JOIN -- afdeling(en) op ruimte
|
||
(SELECT ra.alg_ruimte_key,
|
||
afd.prs_afdeling_naam afd_naam,
|
||
afd.prs_afdeling_omschrijving afd_oms,
|
||
ra.prs_ruimteafdeling_bezetting afd_bez
|
||
FROM prs_v_aanwezigruimteafdeling ra, prs_afdeling afd
|
||
WHERE ra.prs_afdeling_key = afd.prs_afdeling_key) d
|
||
ON a.alg_ruimte_key = d.alg_ruimte_key)
|
||
/
|
||
|
||
/* Formatted on 3-2-2010 17:55:00 (QP5 v5.115.810.9015) */
|
||
CREATE OR REPLACE VIEW aonl_v_rap_hv_doorbelasting
|
||
(
|
||
fclt_f_district,
|
||
fclt_f_locatie,
|
||
fclt_f_gebouw,
|
||
fclt_f_practice_naam,
|
||
fclt_f_practice_nr,
|
||
hide_f_tarief,
|
||
aantal_m2,
|
||
kosten
|
||
)
|
||
AS
|
||
( SELECT x.dis_oms,
|
||
x.loc_code,
|
||
x.geb_code,
|
||
COALESCE (x.sp_naam, '[Leegstand]'),
|
||
COALESCE (x.sp_nummer, '[Leegstand]'),
|
||
x.m2_tarief,
|
||
SUM(DECODE (UPPER (x.ruimtesoort),
|
||
'OPEN WERKPLEK', x.wp * x.m2_wpnorm,
|
||
x.teken_opp))
|
||
reken_opp,
|
||
SUM(DECODE (UPPER (x.ruimtesoort),
|
||
'OPEN WERKPLEK', x.wp * x.m2_wpnorm * x.m2_tarief,
|
||
x.teken_opp * x.m2_tarief))
|
||
kosten
|
||
FROM ( SELECT v.dis_oms,
|
||
v.loc_code,
|
||
v.geb_code,
|
||
v.sp_nummer,
|
||
v.sp_naam,
|
||
v.ruimtesoort,
|
||
v.m2_tarief,
|
||
v.m2_wpnorm,
|
||
SUM (v.wp_cap * COALESCE (v.bezetting, 100) / 100) wp,
|
||
SUM (v.teken_opp * COALESCE (v.bezetting, 100) / 100)
|
||
teken_opp
|
||
FROM aonl_v_hv_actual v
|
||
GROUP BY v.dis_oms,
|
||
v.loc_code,
|
||
v.geb_code,
|
||
v.sp_nummer,
|
||
v.sp_naam,
|
||
v.ruimtesoort,
|
||
v.m2_tarief,
|
||
v.m2_wpnorm) x
|
||
GROUP BY x.dis_oms,
|
||
x.loc_code,
|
||
x.geb_code,
|
||
x.sp_naam,
|
||
x.sp_nummer,
|
||
x.m2_tarief)
|
||
/
|
||
CREATE OR REPLACE VIEW aonl_v_rap_hv_xdoorbelasting (fclt_f_gebouw,
|
||
fclt_f_practice_naam,
|
||
fclt_f_practice_nr,
|
||
reken_opp
|
||
)
|
||
AS
|
||
(SELECT v.geb_code, COALESCE (v.sp_naam, '[Leegstand]'),
|
||
COALESCE (v.sp_nummer, '[Leegstand]'),
|
||
REPLACE (TO_CHAR (SUM (DECODE (UPPER (v.ruimtesoort),
|
||
'OPEN WERKPLEK', v.wp_cap
|
||
* v.m2_wpnorm,
|
||
v.nor_opp
|
||
)
|
||
),
|
||
'999999990D99'
|
||
),
|
||
'.',
|
||
','
|
||
) reken_opp
|
||
FROM aonl_v_hv_xactual v
|
||
GROUP BY v.geb_code, v.sp_naam, v.sp_nummer)
|
||
/
|
||
|
||
/* Formatted on 11-12-2008 9:35:35 (QP5 v5.115.810.9015) */
|
||
CREATE OR REPLACE VIEW aonl_v_rap_hv_xnieuwoudopp
|
||
(
|
||
fclt_f_locatie,
|
||
fclt_f_gebouw,
|
||
fclt_f_verdieping,
|
||
ruimte_nr,
|
||
fclt_f_ruimtesoort,
|
||
teken_opp,
|
||
nor_opp,
|
||
verschil,
|
||
fclt_f_marge
|
||
)
|
||
AS
|
||
(SELECT v.loc_code,
|
||
v.geb_code,
|
||
v.ver_code,
|
||
v.ruimte_nr,
|
||
v.ruimtesoort,
|
||
REPLACE (TO_CHAR (v.teken_opp, '999999990D99'), '.', ',')
|
||
teken_opp,
|
||
REPLACE (TO_CHAR (v.nor_opp, '999999990D99'), '.', ',') nor_opp,
|
||
REPLACE (TO_CHAR (v.teken_opp - v.nor_opp, '999999990D99'),
|
||
'.',
|
||
','
|
||
)
|
||
verschil,
|
||
CASE
|
||
WHEN ABS (v.teken_opp - v.nor_opp) = 0 THEN '='
|
||
WHEN ABS (v.teken_opp - v.nor_opp) > 0.1 THEN '>0,1'
|
||
ELSE '~'
|
||
END
|
||
marge
|
||
FROM aonl_v_hv_xactual v
|
||
WHERE UPPER (v.ruimtesoort) <> 'OPEN WERKPLEK')
|
||
/
|
||
|
||
/* Formatted on 3-2-2010 17:56:00 (QP5 v5.115.810.9015) */
|
||
CREATE OR REPLACE VIEW aonl_v_rap_hv_doorbelfrozen
|
||
(
|
||
fclt_f_datum,
|
||
fclt_f_district,
|
||
fclt_f_locatie,
|
||
fclt_f_gebouw,
|
||
fclt_f_practice_naam,
|
||
fclt_f_practice_nr,
|
||
hide_f_tarief,
|
||
aantal_m2,
|
||
kosten
|
||
)
|
||
AS
|
||
( SELECT TO_CHAR (x.freeze_datum, 'YYYY-MM-DD') datum,
|
||
x.dis_oms,
|
||
x.loc_code,
|
||
x.geb_code,
|
||
COALESCE (x.sp_naam, '[Leegstand]'),
|
||
COALESCE (x.sp_nummer, '[Leegstand]'),
|
||
x.m2_tarief,
|
||
SUM(DECODE (UPPER (x.ruimtesoort),
|
||
'OPEN WERKPLEK', x.wp * x.m2_wpnorm,
|
||
x.teken_opp))
|
||
reken_opp,
|
||
SUM(DECODE (UPPER (x.ruimtesoort),
|
||
'OPEN WERKPLEK', x.wp * x.m2_wpnorm * x.m2_tarief,
|
||
x.teken_opp * x.m2_tarief))
|
||
kosten
|
||
FROM ( SELECT v.freeze_datum,
|
||
v.dis_oms,
|
||
v.loc_code,
|
||
v.geb_code,
|
||
v.sp_nummer,
|
||
v.sp_naam,
|
||
v.ruimtesoort,
|
||
v.m2_tarief,
|
||
v.m2_wpnorm,
|
||
SUM (v.wp_cap * COALESCE (v.bezetting, 100) / 100) wp,
|
||
SUM (v.teken_opp * COALESCE (v.bezetting, 100) / 100)
|
||
teken_opp
|
||
FROM aonl_hv_freeze v
|
||
GROUP BY v.freeze_datum,
|
||
v.dis_oms,
|
||
v.loc_code,
|
||
v.geb_code,
|
||
v.sp_nummer,
|
||
v.sp_naam,
|
||
v.ruimtesoort,
|
||
v.m2_tarief,
|
||
v.m2_wpnorm) x
|
||
GROUP BY x.freeze_datum,
|
||
x.dis_oms,
|
||
x.loc_code,
|
||
x.geb_code,
|
||
x.sp_naam,
|
||
x.sp_nummer,
|
||
x.m2_tarief)
|
||
/
|
||
|
||
/* Formatted on 14-1-2009 17:12:04 (QP5 v5.115.810.9015) */
|
||
CREATE OR REPLACE VIEW aonl_v_rap_hv_ruimte_details
|
||
(
|
||
fclt_f_district,
|
||
fclt_f_locatie,
|
||
fclt_f_gebouw,
|
||
fclt_f_verdieping,
|
||
ruimte_nr,
|
||
aantal_wp,
|
||
reken_opp,
|
||
fclt_f_practice_naam,
|
||
fclt_f_practice_nr,
|
||
fclt_f_ruimtesoort,
|
||
m2_tarief,
|
||
ruimteprijs
|
||
)
|
||
AS
|
||
SELECT v.dis_oms,
|
||
v.loc_code,
|
||
v.geb_code,
|
||
v.ver_code,
|
||
v.ruimte_nr,
|
||
TO_CHAR (v.wp_cap),
|
||
(DECODE (UPPER (v.ruimtesoort),
|
||
'OPEN WERKPLEK', v.wp_cap * v.m2_wpnorm,
|
||
v.teken_opp
|
||
)
|
||
* COALESCE (v.bezetting, 100)
|
||
/ 100)
|
||
reken_opp,
|
||
COALESCE (v.sp_naam, '[Leegstand]'),
|
||
COALESCE (v.sp_nummer, '[Leegstand]'),
|
||
v.ruimtesoort,
|
||
REPLACE (TO_CHAR (v.m2_tarief), '.', ','),
|
||
(DECODE (UPPER (v.ruimtesoort),
|
||
'OPEN WERKPLEK', v.wp_cap * v.m2_wpnorm * v.m2_tarief,
|
||
v.teken_opp * v.m2_tarief
|
||
)
|
||
* COALESCE (v.bezetting, 100)
|
||
/ 100)
|
||
ruimteprijs
|
||
FROM aonl_v_hv_actual v
|
||
/
|
||
|
||
/* Formatted on 2009/01/08 09:18 (Formatter Plus v4.8.7) */
|
||
CREATE OR REPLACE VIEW aonl_v_rap_hv_ruimteoverzicht (fclt_f_district,
|
||
fclt_f_locatie,
|
||
fclt_f_gebouw,
|
||
fclt_f_verdieping,
|
||
ruimte_nr,
|
||
fclt_f_ruimtesoort,
|
||
aantal_wp,
|
||
reken_opp
|
||
)
|
||
AS
|
||
SELECT DISTINCT v.dis_oms, v.loc_code, v.geb_code, v.ver_code, v.ruimte_nr,
|
||
v.ruimtesoort, TO_CHAR (v.wp_cap),
|
||
DECODE (UPPER (v.ruimtesoort),
|
||
'OPEN WERKPLEK', v.wp_cap * v.m2_wpnorm,
|
||
v.teken_opp
|
||
) reken_opp
|
||
FROM aonl_v_hv_actual v
|
||
/
|
||
|
||
/* Formatted on 2009/01/08 09:18 (Formatter Plus v4.8.7) */
|
||
CREATE OR REPLACE VIEW aonl_v_rap_hv_sp_totalen (fclt_f_district,
|
||
fclt_f_locatie,
|
||
fclt_f_gebouw,
|
||
fclt_f_verdieping,
|
||
fclt_f_practice_naam,
|
||
fclt_f_practice_nr,
|
||
fclt_f_ruimtesoort,
|
||
aantal_ruimten,
|
||
aantal_wp,
|
||
reken_opp,
|
||
m2_tarief,
|
||
prijs
|
||
)
|
||
AS
|
||
(SELECT x.dis_oms, x.loc_code, x.geb_code, x.ver_code,
|
||
COALESCE (x.sp_naam, '[Leegstand]'),
|
||
COALESCE (x.sp_nummer, '[Leegstand]'), x.ruimtesoort,
|
||
x.ruimten,
|
||
REPLACE (TO_CHAR (x.wp, '999999990D99'), '.', ',') wp,
|
||
DECODE (UPPER (x.ruimtesoort),
|
||
'OPEN WERKPLEK', x.wp * x.m2_wpnorm,
|
||
x.teken_opp
|
||
) reken_opp,
|
||
REPLACE (TO_CHAR (x.m2_tarief), '.', ','),
|
||
DECODE (UPPER (x.ruimtesoort),
|
||
'OPEN WERKPLEK', x.wp * x.m2_wpnorm * x.m2_tarief,
|
||
x.teken_opp * x.m2_tarief
|
||
) prijs
|
||
FROM (SELECT v.dis_oms, v.loc_code, v.geb_code, v.ver_code,
|
||
v.sp_nummer, v.sp_naam, v.ruimtesoort, v.m2_tarief,
|
||
v.m2_wpnorm,
|
||
SUM (COALESCE (v.bezetting, 100) / 100) ruimten,
|
||
SUM (v.wp_cap * COALESCE (v.bezetting, 100) / 100) wp,
|
||
SUM (v.teken_opp * COALESCE (v.bezetting, 100) / 100
|
||
) teken_opp
|
||
FROM aonl_v_hv_actual v
|
||
GROUP BY v.dis_oms,
|
||
v.loc_code,
|
||
v.geb_code,
|
||
v.ver_code,
|
||
v.sp_nummer,
|
||
v.sp_naam,
|
||
v.ruimtesoort,
|
||
v.m2_tarief,
|
||
v.m2_wpnorm) x)
|
||
/
|
||
|
||
/* Formatted on 15-4-2010 11:28:28 (QP5 v5.115.810.9015) */
|
||
CREATE OR REPLACE VIEW AONL_V_RAP_HV_LEEGSTAND
|
||
(
|
||
HIDE_F_SORTERING,
|
||
FCLT_F_DISTRICT,
|
||
FCLT_F_LOCATIE,
|
||
FCLT_F_GEBOUW,
|
||
TOTAAL_M2,
|
||
BUFFER_LEEG_M2,
|
||
STRUCT_LEEG_M2,
|
||
LEEGST_RATIO
|
||
)
|
||
AS
|
||
(SELECT '-',
|
||
tot.dis_oms,
|
||
tot.loc_code,
|
||
tot.geb_code,
|
||
REPLACE (TO_CHAR (COALESCE (tot.reken_opp, 0), '999999990D99'),
|
||
'.',
|
||
',')
|
||
tot_opp,
|
||
REPLACE (
|
||
TO_CHAR (COALESCE (leeg_buf.reken_opp, 0), '999999990D99'),
|
||
'.',
|
||
','
|
||
)
|
||
lg_buf_opp,
|
||
REPLACE (
|
||
TO_CHAR (COALESCE (leeg_str.reken_opp, 0), '999999990D99'),
|
||
'.',
|
||
','
|
||
)
|
||
lg_str_opp,
|
||
REPLACE (
|
||
TO_CHAR (
|
||
(COALESCE (leeg_buf.reken_opp, 0)
|
||
+ COALESCE (leeg_str.reken_opp, 0))
|
||
/ tot.reken_opp
|
||
* 100,
|
||
'999999990D99'
|
||
),
|
||
'.',
|
||
','
|
||
)
|
||
|| '%'
|
||
lg_ratio
|
||
FROM ( SELECT v.geb_code,
|
||
v.loc_code,
|
||
v.dis_oms,
|
||
SUM(DECODE (
|
||
UPPER (v.ruimtesoort),
|
||
'OPEN WERKPLEK',
|
||
v.wp_cap
|
||
* v.m2_wpnorm
|
||
* COALESCE (v.bezetting, 100)
|
||
/ 100,
|
||
v.teken_opp
|
||
* COALESCE (v.bezetting, 100)
|
||
/ 100
|
||
))
|
||
reken_opp
|
||
FROM aonl_v_hv_actual v
|
||
GROUP BY v.geb_code, v.loc_code, v.dis_oms) tot
|
||
LEFT JOIN
|
||
( SELECT v.geb_code,
|
||
SUM(DECODE (
|
||
UPPER (v.ruimtesoort),
|
||
'OPEN WERKPLEK',
|
||
v.wp_cap
|
||
* v.m2_wpnorm
|
||
* COALESCE (v.bezetting, 100)
|
||
/ 100,
|
||
v.teken_opp
|
||
* COALESCE (v.bezetting, 100)
|
||
/ 100
|
||
))
|
||
reken_opp
|
||
FROM aonl_v_hv_actual v
|
||
WHERE v.sp_nummer IS NULL
|
||
OR v.sp_nummer IN
|
||
(SELECT ud.fac_usrdata_omschr
|
||
FROM fac_usrdata ud
|
||
WHERE ud.fac_usrtab_key = 21)
|
||
GROUP BY v.geb_code) leeg_buf
|
||
ON tot.geb_code = leeg_buf.geb_code
|
||
LEFT JOIN
|
||
( SELECT v.geb_code,
|
||
SUM(DECODE (
|
||
UPPER (v.ruimtesoort),
|
||
'OPEN WERKPLEK',
|
||
v.wp_cap
|
||
* v.m2_wpnorm
|
||
* COALESCE (v.bezetting, 100)
|
||
/ 100,
|
||
v.teken_opp
|
||
* COALESCE (v.bezetting, 100)
|
||
/ 100
|
||
))
|
||
reken_opp
|
||
FROM aonl_v_hv_actual v
|
||
WHERE v.sp_nummer = 'NL22591104'
|
||
GROUP BY v.geb_code) leeg_str
|
||
ON tot.geb_code = leeg_str.geb_code)
|
||
UNION ALL
|
||
(SELECT 'z',
|
||
'LANDELIJK',
|
||
'-',
|
||
'-',
|
||
REPLACE (
|
||
TO_CHAR (SUM (COALESCE (tot.reken_opp, 0)), '999999990D99'),
|
||
'.',
|
||
','
|
||
)
|
||
tot_opp,
|
||
REPLACE (
|
||
TO_CHAR (SUM (COALESCE (leeg_buf.reken_opp, 0)),
|
||
'999999990D99'),
|
||
'.',
|
||
','
|
||
)
|
||
lg_buf_opp,
|
||
REPLACE (
|
||
TO_CHAR (SUM (COALESCE (leeg_str.reken_opp, 0)),
|
||
'999999990D99'),
|
||
'.',
|
||
','
|
||
)
|
||
lg_str_opp,
|
||
REPLACE (
|
||
TO_CHAR (
|
||
(SUM (COALESCE (leeg_buf.reken_opp, 0))
|
||
+ SUM (COALESCE (leeg_str.reken_opp, 0)))
|
||
/ SUM (COALESCE (tot.reken_opp, 0))
|
||
* 100,
|
||
'999999990D99'
|
||
),
|
||
'.',
|
||
','
|
||
)
|
||
|| '%'
|
||
lg_ratio
|
||
FROM ( SELECT v.geb_code,
|
||
v.loc_code,
|
||
v.dis_oms,
|
||
SUM(DECODE (
|
||
UPPER (v.ruimtesoort),
|
||
'OPEN WERKPLEK',
|
||
v.wp_cap
|
||
* v.m2_wpnorm
|
||
* COALESCE (v.bezetting, 100)
|
||
/ 100,
|
||
v.teken_opp
|
||
* COALESCE (v.bezetting, 100)
|
||
/ 100
|
||
))
|
||
reken_opp
|
||
FROM aonl_v_hv_actual v
|
||
GROUP BY v.geb_code, v.loc_code, v.dis_oms) tot
|
||
LEFT JOIN
|
||
( SELECT v.geb_code,
|
||
SUM(DECODE (
|
||
UPPER (v.ruimtesoort),
|
||
'OPEN WERKPLEK',
|
||
v.wp_cap
|
||
* v.m2_wpnorm
|
||
* COALESCE (v.bezetting, 100)
|
||
/ 100,
|
||
v.teken_opp
|
||
* COALESCE (v.bezetting, 100)
|
||
/ 100
|
||
))
|
||
reken_opp
|
||
FROM aonl_v_hv_actual v
|
||
WHERE v.sp_nummer IS NULL
|
||
OR v.sp_nummer IN
|
||
(SELECT ud.fac_usrdata_omschr
|
||
FROM fac_usrdata ud
|
||
WHERE ud.fac_usrtab_key = 21)
|
||
GROUP BY v.geb_code) leeg_buf
|
||
ON tot.geb_code = leeg_buf.geb_code
|
||
LEFT JOIN
|
||
( SELECT v.geb_code,
|
||
SUM(DECODE (
|
||
UPPER (v.ruimtesoort),
|
||
'OPEN WERKPLEK',
|
||
v.wp_cap
|
||
* v.m2_wpnorm
|
||
* COALESCE (v.bezetting, 100)
|
||
/ 100,
|
||
v.teken_opp
|
||
* COALESCE (v.bezetting, 100)
|
||
/ 100
|
||
))
|
||
reken_opp
|
||
FROM aonl_v_hv_actual v
|
||
WHERE v.sp_nummer = 'NL22591104'
|
||
GROUP BY v.geb_code) leeg_str
|
||
ON tot.geb_code = leeg_str.geb_code)
|
||
/
|
||
|
||
/* Formatted on 2009/01/08 13:55 (Formatter Plus v4.8.7) */
|
||
/* MAG WEG OF NIET? - NIET AANGEBODEN! */
|
||
CREATE OR REPLACE VIEW aonl_v_rap_hv_lg_frozen (hide_f_sortering,
|
||
fclt_f_datum,
|
||
fclt_f_district,
|
||
fclt_f_locatie,
|
||
fclt_f_gebouw,
|
||
totaal_opp,
|
||
leegst_opp,
|
||
leegst_ratio
|
||
)
|
||
AS
|
||
(SELECT TO_CHAR (tot.freeze_datum, 'YYYY-MM-DD') datum, '-', tot.dis_oms,
|
||
tot.loc_code, tot.geb_code,
|
||
REPLACE (TO_CHAR (tot.reken_opp, '999999990D99'), '.',
|
||
',') tot_opp,
|
||
REPLACE (TO_CHAR (leeg.reken_opp, '999999990D99'), '.',
|
||
',') lg_opp,
|
||
REPLACE (TO_CHAR (leeg.reken_opp / tot.reken_opp * 100,
|
||
'999999990D99'
|
||
),
|
||
'.',
|
||
','
|
||
)
|
||
|| '%' lg_ratio
|
||
FROM (SELECT v.geb_code, v.loc_code, v.dis_oms, v.freeze_datum,
|
||
SUM (DECODE (UPPER (v.ruimtesoort),
|
||
'OPEN WERKPLEK', v.wp_cap
|
||
* v.m2_wpnorm
|
||
* COALESCE (v.bezetting, 100)
|
||
/ 100,
|
||
v.teken_opp
|
||
* COALESCE (v.bezetting, 100)
|
||
/ 100
|
||
)
|
||
) reken_opp
|
||
FROM aonl_hv_freeze v
|
||
GROUP BY v.geb_code, v.loc_code, v.dis_oms, v.freeze_datum) tot
|
||
LEFT JOIN
|
||
(SELECT v.geb_code, v.freeze_datum,
|
||
SUM (DECODE (UPPER (v.ruimtesoort),
|
||
'OPEN WERKPLEK', v.wp_cap
|
||
* v.m2_wpnorm
|
||
* COALESCE (v.bezetting, 100)
|
||
/ 100,
|
||
v.teken_opp
|
||
* COALESCE (v.bezetting, 100)
|
||
/ 100
|
||
)
|
||
) reken_opp
|
||
FROM aonl_hv_freeze v
|
||
WHERE v.sp_nummer IS NULL
|
||
GROUP BY v.geb_code, v.freeze_datum) leeg
|
||
ON tot.geb_code = leeg.geb_code
|
||
AND tot.freeze_datum = leeg.freeze_datum
|
||
)
|
||
UNION ALL
|
||
(SELECT TO_CHAR (tot.freeze_datum, 'YYYY-MM-DD') datum, 'z', 'LANDELIJK',
|
||
'-', '-',
|
||
REPLACE (TO_CHAR (SUM (tot.reken_opp), '999999990D99'),
|
||
'.',
|
||
','
|
||
) tot_opp,
|
||
REPLACE (TO_CHAR (SUM (leeg.reken_opp), '999999990D99'),
|
||
'.',
|
||
','
|
||
) lg_opp,
|
||
REPLACE (TO_CHAR ( SUM (leeg.reken_opp)
|
||
/ SUM (tot.reken_opp)
|
||
* 100,
|
||
'999999990D99'
|
||
),
|
||
'.',
|
||
','
|
||
)
|
||
|| '%' lg_ratio
|
||
FROM (SELECT v.geb_code, v.loc_code, v.dis_oms, v.freeze_datum,
|
||
SUM (DECODE (UPPER (v.ruimtesoort),
|
||
'OPEN WERKPLEK', v.wp_cap
|
||
* v.m2_wpnorm
|
||
* COALESCE (v.bezetting, 100)
|
||
/ 100,
|
||
v.teken_opp
|
||
* COALESCE (v.bezetting, 100)
|
||
/ 100
|
||
)
|
||
) reken_opp
|
||
FROM aonl_hv_freeze v
|
||
GROUP BY v.geb_code, v.loc_code, v.dis_oms, v.freeze_datum) tot
|
||
LEFT JOIN
|
||
(SELECT v.geb_code, v.freeze_datum,
|
||
SUM (DECODE (UPPER (v.ruimtesoort),
|
||
'OPEN WERKPLEK', v.wp_cap
|
||
* v.m2_wpnorm
|
||
* COALESCE (v.bezetting, 100)
|
||
/ 100,
|
||
v.teken_opp
|
||
* COALESCE (v.bezetting, 100)
|
||
/ 100
|
||
)
|
||
) reken_opp
|
||
FROM aonl_hv_freeze v
|
||
WHERE v.sp_nummer IS NULL
|
||
GROUP BY v.geb_code, v.freeze_datum) leeg
|
||
ON tot.geb_code = leeg.geb_code
|
||
AND tot.freeze_datum = leeg.freeze_datum
|
||
GROUP BY tot.freeze_datum)
|
||
/
|
||
|
||
/* Formatted on 3-2-2010 17:58:58 (QP5 v5.115.810.9015) */
|
||
CREATE OR REPLACE VIEW aonl_v_rap_hv_doorbel_delta
|
||
(
|
||
fclt_f_district,
|
||
fclt_f_locatie,
|
||
fclt_f_gebouw,
|
||
fclt_f_practice_nr,
|
||
fclt_f_practice_naam,
|
||
tarief_nu,
|
||
tarief_delta,
|
||
m2_nu,
|
||
m2_delta
|
||
)
|
||
AS
|
||
(SELECT DISTINCT z.dis,
|
||
z.loc,
|
||
z.geb,
|
||
z.nr,
|
||
z.naam,
|
||
REPLACE (TO_CHAR (z.tarief_actueel), '.', ','),
|
||
REPLACE (TO_CHAR (z.tarief_verschil), '.', ','),
|
||
z.m2_actueel,
|
||
z.m2_verschil
|
||
FROM (SELECT COALESCE (x.dis, y.dis) dis,
|
||
COALESCE (x.loc, y.loc) loc,
|
||
COALESCE (x.geb, y.geb) geb,
|
||
COALESCE (x.nr, y.nr) nr,
|
||
DECODE (x.naam,
|
||
COALESCE (y.naam, x.naam), x.naam,
|
||
'***GEWIJZIGD: ' || COALESCE (x.naam, ''))
|
||
naam,
|
||
x.tarief tarief_actueel,
|
||
y.tarief tarief_laatste,
|
||
(COALESCE (x.tarief, 0) - COALESCE (y.tarief, 0))
|
||
tarief_verschil,
|
||
x.m2 m2_actueel,
|
||
y.m2 m2_laatste,
|
||
(COALESCE (x.m2, 0) - COALESCE (y.m2, 0)) m2_verschil
|
||
FROM (SELECT fclt_f_district dis,
|
||
fclt_f_locatie loc,
|
||
fclt_f_gebouw geb,
|
||
fclt_f_practice_nr nr,
|
||
fclt_f_practice_naam naam,
|
||
hide_f_tarief tarief,
|
||
aantal_m2 m2,
|
||
kosten kosten
|
||
FROM aonl_v_rap_hv_doorbelasting) x
|
||
LEFT JOIN
|
||
(SELECT fclt_f_district dis,
|
||
fclt_f_locatie loc,
|
||
fclt_f_gebouw geb,
|
||
fclt_f_practice_nr nr,
|
||
fclt_f_practice_naam naam,
|
||
hide_f_tarief tarief,
|
||
aantal_m2 m2,
|
||
kosten kosten
|
||
FROM aonl_v_rap_hv_doorbelfrozen
|
||
WHERE fclt_f_datum =
|
||
(SELECT TO_CHAR (MAX (freeze_datum),
|
||
'yyyy-mm-dd')
|
||
FROM aonl_hv_freeze)) y
|
||
ON x.dis = y.dis
|
||
AND x.loc = y.loc
|
||
AND x.geb = y.geb
|
||
AND x.nr = y.nr
|
||
UNION
|
||
SELECT COALESCE (x.dis, y.dis) dis,
|
||
COALESCE (x.loc, y.loc) loc,
|
||
COALESCE (x.geb, y.geb) geb,
|
||
COALESCE (x.nr, y.nr) nr,
|
||
DECODE (y.naam,
|
||
COALESCE (x.naam, y.naam), y.naam,
|
||
'***GEWIJZIGD: ' || COALESCE (x.naam, ''))
|
||
naam,
|
||
x.tarief tarief_actueel,
|
||
y.tarief tarief_laatste,
|
||
(COALESCE (x.tarief, 0) - COALESCE (y.tarief, 0))
|
||
tarief_verschil,
|
||
x.m2 m2_actueel,
|
||
y.m2 m2_laatste,
|
||
(COALESCE (x.m2, 0) - COALESCE (y.m2, 0)) m2_verschil
|
||
FROM (SELECT fclt_f_district dis,
|
||
fclt_f_locatie loc,
|
||
fclt_f_gebouw geb,
|
||
fclt_f_practice_nr nr,
|
||
fclt_f_practice_naam naam,
|
||
hide_f_tarief tarief,
|
||
aantal_m2 m2,
|
||
kosten kosten
|
||
FROM aonl_v_rap_hv_doorbelasting) x
|
||
RIGHT JOIN
|
||
(SELECT fclt_f_district dis,
|
||
fclt_f_locatie loc,
|
||
fclt_f_gebouw geb,
|
||
fclt_f_practice_nr nr,
|
||
fclt_f_practice_naam naam,
|
||
hide_f_tarief tarief,
|
||
aantal_m2 m2,
|
||
kosten kosten
|
||
FROM aonl_v_rap_hv_doorbelfrozen
|
||
WHERE fclt_f_datum =
|
||
(SELECT TO_CHAR (MAX (freeze_datum),
|
||
'yyyy-mm-dd')
|
||
FROM aonl_hv_freeze)) y
|
||
ON x.dis = y.dis
|
||
AND x.loc = y.loc
|
||
AND x.geb = y.geb
|
||
AND x.nr = y.nr) z);
|
||
|
||
/* Formatted on 19-1-2009 13:15:45 (QP5 v5.115.810.9015) */
|
||
CREATE OR REPLACE VIEW aonl_v_rap_hv_details_delta
|
||
(
|
||
fclt_f_district,
|
||
fclt_f_locatie,
|
||
fclt_f_gebouw,
|
||
fclt_f_verdieping,
|
||
ruimte_nr,
|
||
fclt_f_practice_nr,
|
||
fclt_f_practice_naam,
|
||
fclt_f_ruimtesoort,
|
||
wp_nu,
|
||
wp_delta,
|
||
m2_nu,
|
||
m2_delta
|
||
)
|
||
AS
|
||
(SELECT DISTINCT
|
||
z.dis,
|
||
z.loc,
|
||
z.geb,
|
||
z.ver,
|
||
z.rui,
|
||
z.nr,
|
||
z.naam,
|
||
z.soort,
|
||
z.wp_actueel,
|
||
z.wp_verschil,
|
||
z.m2_actueel,
|
||
z.m2_verschil
|
||
FROM (SELECT COALESCE (x.dis_oms, y.dis_oms) dis,
|
||
COALESCE (x.loc_code, y.loc_code) loc,
|
||
COALESCE (x.geb_code, y.geb_code) geb,
|
||
COALESCE (x.ver_code, y.ver_code) ver,
|
||
COALESCE (x.ruimte_nr, y.ruimte_nr) rui,
|
||
COALESCE (x.sp_nr, y.sp_nr) nr,
|
||
DECODE (x.sp_naam,
|
||
COALESCE (y.sp_naam, x.sp_naam), x.sp_naam,
|
||
'***GEWIJZIGD: ' || COALESCE (x.sp_naam, '')
|
||
)
|
||
naam,
|
||
DECODE (
|
||
x.ruimtesoort,
|
||
COALESCE (y.ruimtesoort, x.ruimtesoort),
|
||
x.ruimtesoort,
|
||
'***GEWIJZIGD: ' || COALESCE (x.ruimtesoort, '')
|
||
)
|
||
soort,
|
||
x.wp wp_actueel,
|
||
y.wp wp_laatste,
|
||
(COALESCE (x.wp, 0) - COALESCE (y.wp, 0)) wp_verschil,
|
||
x.m2 m2_actueel,
|
||
y.m2 m2_laatste,
|
||
(COALESCE (x.m2, 0) - COALESCE (y.m2, 0)) m2_verschil
|
||
FROM (SELECT v.dis_oms,
|
||
v.loc_code,
|
||
v.geb_code,
|
||
v.ver_code,
|
||
v.ruimte_nr,
|
||
COALESCE (v.sp_nummer, '[Leegstand]')
|
||
sp_nr,
|
||
v.sp_naam,
|
||
v.ruimtesoort,
|
||
v.bezetting bez,
|
||
v.wp_cap wp,
|
||
(DECODE (UPPER (v.ruimtesoort),
|
||
'OPEN WERKPLEK',
|
||
v.wp_cap * v.m2_wpnorm,
|
||
v.teken_opp
|
||
)
|
||
* COALESCE (v.bezetting, 100)
|
||
/ 100)
|
||
m2
|
||
FROM aonl_v_hv_actual v) x
|
||
LEFT JOIN
|
||
(SELECT v.dis_oms,
|
||
v.loc_code,
|
||
v.geb_code,
|
||
v.ver_code,
|
||
v.ruimte_nr,
|
||
COALESCE (v.sp_nummer, '[Leegstand]')
|
||
sp_nr,
|
||
v.sp_naam,
|
||
v.ruimtesoort,
|
||
v.bezetting bez,
|
||
v.wp_cap wp,
|
||
(DECODE (UPPER (v.ruimtesoort),
|
||
'OPEN WERKPLEK',
|
||
v.wp_cap * v.m2_wpnorm,
|
||
v.teken_opp
|
||
)
|
||
* COALESCE (v.bezetting, 100)
|
||
/ 100)
|
||
m2
|
||
FROM aonl_hv_freeze v
|
||
WHERE TRUNC (v.freeze_datum) =
|
||
( SELECT TRUNC (MAX (freeze_datum))
|
||
FROM aonl_hv_freeze)) y
|
||
ON x.dis_oms = y.dis_oms
|
||
AND x.loc_code = y.loc_code
|
||
AND x.geb_code = y.geb_code
|
||
AND x.ver_code = y.ver_code
|
||
AND x.ruimte_nr = y.ruimte_nr
|
||
AND x.sp_nr = y.sp_nr
|
||
UNION
|
||
SELECT COALESCE (x.dis_oms, y.dis_oms) dis,
|
||
COALESCE (x.loc_code, y.loc_code) loc,
|
||
COALESCE (x.geb_code, y.geb_code) geb,
|
||
COALESCE (x.ver_code, y.ver_code) ver,
|
||
COALESCE (x.ruimte_nr, y.ruimte_nr) rui,
|
||
COALESCE (x.sp_nr, y.sp_nr) nr,
|
||
DECODE (y.sp_naam,
|
||
COALESCE (x.sp_naam, y.sp_naam), y.sp_naam,
|
||
'***GEWIJZIGD: ' || COALESCE (x.sp_naam, '')
|
||
)
|
||
naam,
|
||
DECODE (
|
||
y.ruimtesoort,
|
||
COALESCE (x.ruimtesoort, y.ruimtesoort),
|
||
y.ruimtesoort,
|
||
'***GEWIJZIGD: ' || COALESCE (x.ruimtesoort, '')
|
||
)
|
||
soort,
|
||
x.wp wp_actueel,
|
||
y.wp wp_laatste,
|
||
(COALESCE (x.wp, 0) - COALESCE (y.wp, 0)) wp_verschil,
|
||
x.m2 m2_actueel,
|
||
y.m2 m2_laatste,
|
||
(COALESCE (x.m2, 0) - COALESCE (y.m2, 0)) m2_verschil
|
||
FROM (SELECT v.dis_oms,
|
||
v.loc_code,
|
||
v.geb_code,
|
||
v.ver_code,
|
||
v.ruimte_nr,
|
||
COALESCE (v.sp_nummer, '[Leegstand]')
|
||
sp_nr,
|
||
v.sp_naam,
|
||
v.ruimtesoort,
|
||
v.bezetting bez,
|
||
v.wp_cap wp,
|
||
(DECODE (UPPER (v.ruimtesoort),
|
||
'OPEN WERKPLEK',
|
||
v.wp_cap * v.m2_wpnorm,
|
||
v.teken_opp
|
||
)
|
||
* COALESCE (v.bezetting, 100)
|
||
/ 100)
|
||
m2
|
||
FROM aonl_v_hv_actual v) x
|
||
RIGHT JOIN
|
||
(SELECT v.dis_oms,
|
||
v.loc_code,
|
||
v.geb_code,
|
||
v.ver_code,
|
||
v.ruimte_nr,
|
||
COALESCE (v.sp_nummer, '[Leegstand]')
|
||
sp_nr,
|
||
v.sp_naam,
|
||
v.ruimtesoort,
|
||
v.bezetting bez,
|
||
v.wp_cap wp,
|
||
(DECODE (UPPER (v.ruimtesoort),
|
||
'OPEN WERKPLEK',
|
||
v.wp_cap * v.m2_wpnorm,
|
||
v.teken_opp
|
||
)
|
||
* COALESCE (v.bezetting, 100)
|
||
/ 100)
|
||
m2
|
||
FROM aonl_hv_freeze v
|
||
WHERE TRUNC (v.freeze_datum) =
|
||
( SELECT TRUNC (MAX (freeze_datum))
|
||
FROM aonl_hv_freeze)) y
|
||
ON x.dis_oms = y.dis_oms
|
||
AND x.loc_code = y.loc_code
|
||
AND x.geb_code = y.geb_code
|
||
AND x.ver_code = y.ver_code
|
||
AND x.ruimte_nr = y.ruimte_nr
|
||
AND x.sp_nr = y.sp_nr) z);
|
||
|
||
/* Formatted on 2008/11/27 12:45 (Formatter Plus v4.8.7) */
|
||
CREATE OR REPLACE VIEW aonl_v_label_ruimte_sp (
|
||
alg_ruimte_key,
|
||
waarde
|
||
)
|
||
AS
|
||
SELECT DISTINCT ra.alg_ruimte_key, a.prs_afdeling_naam1
|
||
FROM prs_v_aanwezigruimteafdeling ra, prs_v_aanwezigafdeling a
|
||
WHERE ra.prs_afdeling_key = a.prs_afdeling_key
|
||
UNION
|
||
SELECT DISTINCT r.alg_ruimte_key, '[Leegstand]' -- ruimten zonder sp
|
||
FROM alg_v_aanwezigruimte r
|
||
WHERE NOT EXISTS ( -- waar geen sp binnen bestaat
|
||
SELECT ra.alg_ruimte_key
|
||
FROM prs_v_aanwezigruimteafdeling ra
|
||
WHERE ra.alg_ruimte_key = r.alg_ruimte_key)
|
||
/
|
||
|
||
CREATE OR REPLACE VIEW aonl_v_prj_label_ruimte_sp (
|
||
prj_ruimte_key,
|
||
waarde
|
||
)
|
||
AS
|
||
SELECT DISTINCT ra.prj_ruimte_key, a.prs_afdeling_naam1
|
||
FROM prj_ruimteafdeling ra, prs_v_aanwezigafdeling a
|
||
WHERE ra.prs_afdeling_key = a.prs_afdeling_key
|
||
UNION
|
||
SELECT DISTINCT r.prj_ruimte_key, '[Leegstand]' -- ruimten zonder sp
|
||
FROM prj_ruimte r
|
||
WHERE r.prj_ruimte_verwijder IS NULL
|
||
AND NOT EXISTS
|
||
( -- waar geen sp binnen bestaat
|
||
SELECT ra.prj_ruimte_key
|
||
FROM prj_ruimteafdeling ra
|
||
WHERE ra.prj_ruimteafdeling_verwijder IS NULL
|
||
AND ra.prj_ruimte_key = r.prj_ruimte_key)
|
||
/
|
||
|
||
/* Formatted on 2008/09/19 14:14 (Formatter Plus v4.8.7) */
|
||
CREATE OR REPLACE VIEW aonl_v_label_ruimte_sp_nr (alg_ruimte_key, waarde)
|
||
AS
|
||
SELECT DISTINCT ra.alg_ruimte_key, a.prs_afdeling_naam
|
||
FROM prs_v_aanwezigruimteafdeling ra, prs_v_aanwezigafdeling a
|
||
WHERE ra.prs_afdeling_key = a.prs_afdeling_key
|
||
UNION
|
||
SELECT DISTINCT r.alg_ruimte_key, '[Leegstand]' -- ruimten zonder sp
|
||
FROM alg_v_aanwezigruimte r
|
||
WHERE NOT EXISTS ( -- waar geen sp binnen bestaat
|
||
SELECT ra.alg_ruimte_key
|
||
FROM prs_v_aanwezigruimteafdeling ra
|
||
WHERE ra.alg_ruimte_key = r.alg_ruimte_key)
|
||
/
|
||
|
||
CREATE OR REPLACE VIEW aonl_v_prj_label_ruimte_sp_nr (prj_ruimte_key, waarde)
|
||
AS
|
||
SELECT DISTINCT ra.prj_ruimte_key, a.prs_afdeling_naam
|
||
FROM prj_ruimteafdeling ra, prs_v_aanwezigafdeling a
|
||
WHERE ra.prs_afdeling_key = a.prs_afdeling_key
|
||
UNION
|
||
SELECT DISTINCT r.prj_ruimte_key, '[Leegstand]' -- ruimten zonder sp
|
||
FROM prj_ruimte r
|
||
WHERE r.prj_ruimte_verwijder IS NULL
|
||
AND NOT EXISTS
|
||
( -- waar geen sp binnen bestaat
|
||
SELECT ra.prj_ruimte_key
|
||
FROM prj_ruimteafdeling ra
|
||
WHERE ra.prj_ruimteafdeling_verwijder IS NULL
|
||
AND ra.prj_ruimte_key = r.prj_ruimte_key)
|
||
/
|
||
|
||
/* Formatted on 2008/09/19 14:14 (Formatter Plus v4.8.7) */
|
||
CREATE OR REPLACE VIEW aonl_v_label_ruimte_sp_oms (alg_ruimte_key, waarde)
|
||
AS
|
||
SELECT DISTINCT ra.alg_ruimte_key, a.prs_afdeling_omschrijving
|
||
FROM prs_v_aanwezigruimteafdeling ra, prs_v_aanwezigafdeling a
|
||
WHERE ra.prs_afdeling_key = a.prs_afdeling_key
|
||
UNION
|
||
SELECT DISTINCT r.alg_ruimte_key, '[Leegstand]' -- ruimten zonder sp
|
||
FROM alg_v_aanwezigruimte r
|
||
WHERE NOT EXISTS ( -- waar geen sp binnen bestaat
|
||
SELECT ra.alg_ruimte_key
|
||
FROM prs_v_aanwezigruimteafdeling ra
|
||
WHERE ra.alg_ruimte_key = r.alg_ruimte_key)
|
||
/
|
||
|
||
CREATE OR REPLACE VIEW aonl_v_prj_label_ruimte_sp_oms (prj_ruimte_key, waarde)
|
||
AS
|
||
SELECT DISTINCT ra.prj_ruimte_key, a.prs_afdeling_omschrijving
|
||
FROM prj_ruimteafdeling ra, prs_v_aanwezigafdeling a
|
||
WHERE ra.prs_afdeling_key = a.prs_afdeling_key
|
||
UNION
|
||
SELECT DISTINCT r.prj_ruimte_key, '[Leegstand]' -- ruimten zonder sp
|
||
FROM prj_ruimte r
|
||
WHERE r.prj_ruimte_verwijder IS NULL
|
||
AND NOT EXISTS
|
||
( -- waar geen sp binnen bestaat
|
||
SELECT ra.prj_ruimte_key
|
||
FROM prj_ruimteafdeling ra
|
||
WHERE ra.prj_ruimteafdeling_verwijder IS NULL
|
||
AND ra.prj_ruimte_key = r.prj_ruimte_key)
|
||
/
|
||
|
||
/* Formatted on 2008/09/19 14:14 (Formatter Plus v4.8.7) */
|
||
CREATE OR REPLACE VIEW aonl_v_label_wp_cnt (alg_ruimte_key, waarde)
|
||
AS
|
||
SELECT a.alg_ruimte_key, COALESCE (b.wp, '0') || ' werkplekken'
|
||
FROM (SELECT r.alg_ruimte_key
|
||
FROM alg_v_aanwezigruimte r) a
|
||
LEFT JOIN
|
||
(SELECT ok.alg_onrgoed_key, ok.alg_onrgoedkenmerk_waarde wp
|
||
FROM alg_onrgoedkenmerk ok
|
||
WHERE ok.alg_onrgoed_niveau = 'R'
|
||
AND ok.alg_kenmerk_key = 1020 -- werkplekken
|
||
AND ok.alg_onrgoedkenmerk_verwijder IS NULL) b
|
||
ON a.alg_ruimte_key = b.alg_onrgoed_key
|
||
/
|
||
|
||
CREATE OR REPLACE VIEW aonl_v_prj_label_wp_cnt (prj_ruimte_key, waarde)
|
||
AS
|
||
SELECT a.prj_ruimte_key, COALESCE (b.wp, '0') || ' werkplekken'
|
||
FROM (SELECT r.prj_ruimte_key
|
||
FROM prj_ruimte r
|
||
WHERE r.prj_ruimte_verwijder IS NULL) a
|
||
LEFT JOIN
|
||
(SELECT r.prj_ruimte_key, ok.alg_onrgoedkenmerk_waarde wp
|
||
FROM prj_ruimte r, alg_onrgoedkenmerk ok
|
||
WHERE r.alg_ruimte_key = ok.alg_onrgoed_key
|
||
AND ok.alg_onrgoed_niveau = 'R'
|
||
AND ok.alg_kenmerk_key = 1020 -- werkplekken
|
||
AND ok.alg_onrgoedkenmerk_verwijder IS NULL) b
|
||
ON a.prj_ruimte_key = b.prj_ruimte_key
|
||
/
|
||
|
||
/* Formatted on 23-9-2011 14:52:02 (QP5 v5.115.810.9015) */
|
||
CREATE OR REPLACE FORCE VIEW aonl_v_thema_ruimte_sp
|
||
(
|
||
alg_ruimte_key,
|
||
waarde,
|
||
waarde_key
|
||
)
|
||
AS
|
||
SELECT x.alg_ruimte_key,
|
||
DECODE (y.aantal,
|
||
NULL, '[Leegstand]',
|
||
1, SUBSTR (y.sp, 1, 60),
|
||
'Meer dan 1 service practice!'),
|
||
DECODE (y.aantal, NULL, -1, 1, y.sp_key, NULL)
|
||
FROM (SELECT r.alg_ruimte_key
|
||
FROM alg_v_aanwezigruimte r) x
|
||
LEFT JOIN
|
||
( SELECT ra.alg_ruimte_key,
|
||
MIN (a.prs_afdeling_naam1) sp,
|
||
MIN (a.prs_afdeling_key) sp_key,
|
||
COUNT (ra.prs_afdeling_key) aantal
|
||
FROM prs_v_aanwezigruimteafdeling ra,
|
||
prs_v_aanwezigafdeling a
|
||
WHERE ra.prs_afdeling_key = a.prs_afdeling_key
|
||
GROUP BY ra.alg_ruimte_key) y
|
||
ON x.alg_ruimte_key = y.alg_ruimte_key
|
||
UNION ALL
|
||
SELECT NULL, SUBSTR (a.prs_afdeling_naam1, 1, 60), a.prs_afdeling_key
|
||
FROM prs_v_aanwezigafdeling a
|
||
WHERE NOT EXISTS (SELECT 1
|
||
FROM prs_v_aanwezigruimteafdeling ra
|
||
WHERE ra.prs_afdeling_key = a.prs_afdeling_key)
|
||
UNION ALL
|
||
SELECT DISTINCT
|
||
NULL, SUBSTR (a.prs_afdeling_naam1, 1, 60), a.prs_afdeling_key
|
||
FROM prs_v_aanwezigafdeling a, prs_v_aanwezigruimteafdeling ra
|
||
WHERE a.prs_afdeling_key = ra.prs_afdeling_key
|
||
AND NOT EXISTS (SELECT 1
|
||
FROM alg_v_aanwezigruimte r
|
||
WHERE r.alg_ruimte_key = ra.alg_ruimte_key)
|
||
/
|
||
|
||
CREATE OR REPLACE TRIGGER aonl_t_thema_ruimte_sp_i_iu
|
||
INSTEAD OF INSERT OR UPDATE
|
||
ON aonl_v_thema_ruimte_sp
|
||
BEGIN
|
||
IF UPDATING -- oude hard weggooien; dus DELETE (lekker opruimen)!
|
||
THEN
|
||
DELETE FROM prs_ruimteafdeling
|
||
WHERE alg_ruimte_key = :new.alg_ruimte_key
|
||
AND prs_afdeling_key <> :new.waarde_key;
|
||
END IF;
|
||
|
||
BEGIN
|
||
IF :new.waarde_key <> -1
|
||
THEN
|
||
INSERT INTO prs_ruimteafdeling
|
||
(
|
||
alg_ruimte_key, prs_afdeling_key
|
||
)
|
||
VALUES (:new.alg_ruimte_key, :new.waarde_key);
|
||
END IF;
|
||
EXCEPTION
|
||
WHEN DUP_VAL_ON_INDEX -- was al aanwezig
|
||
THEN
|
||
NULL;
|
||
END;
|
||
END;
|
||
/
|
||
|
||
/* Formatted on 23-9-2011 14:58:08 (QP5 v5.115.810.9015) */
|
||
CREATE OR REPLACE VIEW aonl_v_prj_thema_ruimte_sp
|
||
(
|
||
prj_ruimte_key,
|
||
waarde,
|
||
waarde_key
|
||
)
|
||
AS
|
||
SELECT x.prj_ruimte_key,
|
||
DECODE (y.aantal,
|
||
NULL, '[Leegstand]',
|
||
1, SUBSTR (y.sp, 1, 60),
|
||
'Meer dan 1 service practice!'),
|
||
DECODE (y.aantal, NULL, -1, 1, y.sp_key, NULL)
|
||
FROM (SELECT r.prj_ruimte_key
|
||
FROM prj_ruimte r
|
||
WHERE r.prj_ruimte_verwijder IS NULL) x
|
||
LEFT JOIN
|
||
( SELECT ra.prj_ruimte_key,
|
||
MIN (a.prs_afdeling_naam1) sp,
|
||
MIN (a.prs_afdeling_key) sp_key,
|
||
COUNT (ra.prs_afdeling_key) aantal
|
||
FROM prj_ruimteafdeling ra, prs_v_aanwezigafdeling a
|
||
WHERE ra.prj_ruimteafdeling_verwijder IS NULL
|
||
AND ra.prs_afdeling_key = a.prs_afdeling_key
|
||
GROUP BY ra.prj_ruimte_key) y
|
||
ON x.prj_ruimte_key = y.prj_ruimte_key
|
||
UNION ALL
|
||
SELECT NULL, SUBSTR (a.prs_afdeling_naam1, 1, 60), a.prs_afdeling_key
|
||
FROM prs_v_aanwezigafdeling a
|
||
WHERE NOT EXISTS
|
||
(SELECT 1
|
||
FROM prj_ruimteafdeling ra
|
||
WHERE ra.prj_ruimteafdeling_verwijder IS NULL
|
||
AND ra.prs_afdeling_key = a.prs_afdeling_key)
|
||
UNION ALL
|
||
SELECT DISTINCT
|
||
NULL, SUBSTR (a.prs_afdeling_naam1, 1, 60), a.prs_afdeling_key
|
||
FROM prs_v_aanwezigafdeling a, prj_ruimteafdeling ra
|
||
WHERE a.prs_afdeling_key = ra.prs_afdeling_key
|
||
AND ra.prj_ruimteafdeling_verwijder IS NULL
|
||
AND NOT EXISTS
|
||
(SELECT 1
|
||
FROM prj_ruimte r
|
||
WHERE r.prj_ruimte_verwijder IS NULL
|
||
AND r.prj_ruimte_key = ra.prj_ruimte_key)
|
||
/
|
||
|
||
CREATE OR REPLACE TRIGGER aonl_t_prj_t_ruimte_sp_i_iu
|
||
INSTEAD OF INSERT OR UPDATE
|
||
ON aonl_v_prj_thema_ruimte_sp
|
||
BEGIN
|
||
IF UPDATING -- oude logisch weggooien, dus g<><67>n DELETE!
|
||
THEN
|
||
UPDATE prj_ruimteafdeling
|
||
SET prj_ruimteafdeling_verwijder = SYSDATE
|
||
WHERE prj_ruimte_key = :new.prj_ruimte_key
|
||
AND prs_afdeling_key <> :new.waarde_key;
|
||
END IF;
|
||
|
||
BEGIN
|
||
IF :new.waarde_key <> -1
|
||
THEN
|
||
UPDATE prj_ruimteafdeling
|
||
SET prj_ruimteafdeling_verwijder = NULL
|
||
WHERE prj_ruimte_key = :new.prj_ruimte_key
|
||
AND prs_afdeling_key = :new.waarde_key;
|
||
|
||
INSERT INTO prj_ruimteafdeling
|
||
(
|
||
prj_ruimte_key, prs_afdeling_key
|
||
)
|
||
VALUES (:new.prj_ruimte_key, :new.waarde_key);
|
||
END IF;
|
||
EXCEPTION
|
||
WHEN DUP_VAL_ON_INDEX -- was al aanwezig
|
||
THEN
|
||
NULL;
|
||
END;
|
||
END;
|
||
/
|
||
|
||
/* Formatted on 2008/09/19 15:30 (Formatter Plus v4.8.7) */
|
||
CREATE OR REPLACE VIEW aonl_v_thema_wp_cnt (alg_ruimte_key, waarde)
|
||
AS
|
||
SELECT a.alg_ruimte_key,
|
||
DECODE (b.wp,
|
||
NULL, '0',
|
||
'0', '0',
|
||
'1', '1',
|
||
'2', '2',
|
||
'3', '3',
|
||
'4', '4',
|
||
'5', '5',
|
||
'>5'
|
||
)
|
||
FROM (SELECT r.alg_ruimte_key
|
||
FROM alg_v_aanwezigruimte r) a
|
||
LEFT JOIN
|
||
(SELECT ok.alg_onrgoed_key, ok.alg_onrgoedkenmerk_waarde wp
|
||
FROM alg_onrgoedkenmerk ok
|
||
WHERE ok.alg_onrgoed_niveau = 'R'
|
||
AND ok.alg_kenmerk_key = 1020 -- werkplekken
|
||
AND ok.alg_onrgoedkenmerk_verwijder IS NULL) b
|
||
ON a.alg_ruimte_key = b.alg_onrgoed_key
|
||
/
|
||
|
||
CREATE OR REPLACE VIEW aonl_v_prj_thema_wp_cnt (prj_ruimte_key, waarde)
|
||
AS
|
||
SELECT a.prj_ruimte_key,
|
||
DECODE (b.wp,
|
||
NULL, '0',
|
||
'0', '0',
|
||
'1', '1',
|
||
'2', '2',
|
||
'3', '3',
|
||
'4', '4',
|
||
'5', '5',
|
||
'>5'
|
||
)
|
||
FROM (SELECT r.prj_ruimte_key
|
||
FROM prj_ruimte r
|
||
WHERE r.prj_ruimte_verwijder IS NULL) a
|
||
LEFT JOIN
|
||
(SELECT r.prj_ruimte_key, ok.alg_onrgoedkenmerk_waarde wp
|
||
FROM prj_ruimte r, alg_onrgoedkenmerk ok
|
||
WHERE r.alg_ruimte_key = ok.alg_onrgoed_key
|
||
AND ok.alg_onrgoed_niveau = 'R'
|
||
AND ok.alg_kenmerk_key = 1020 -- werkplekken
|
||
AND ok.alg_onrgoedkenmerk_verwijder IS NULL) b
|
||
ON a.prj_ruimte_key = b.prj_ruimte_key
|
||
/
|
||
|
||
/* Formatted on 2008/11/11 15:51 (Formatter Plus v4.8.7) */
|
||
CREATE OR REPLACE PROCEDURE aonl_import_ruimtegeg (
|
||
p_import_key IN NUMBER
|
||
)
|
||
IS
|
||
c_delim VARCHAR2 (1) := ';';
|
||
v_newline VARCHAR2 (1000); -- Input line
|
||
v_errormsg VARCHAR2 (1000);
|
||
v_errorhint VARCHAR2 (1000);
|
||
oracle_err_num NUMBER;
|
||
oracle_err_mes VARCHAR2 (200);
|
||
header_is_valid NUMBER;
|
||
v_count_tot NUMBER (10);
|
||
v_count_import NUMBER (10);
|
||
v_ongeldig NUMBER (1);
|
||
v_aanduiding VARCHAR (200);
|
||
-- De importvelden
|
||
v_alg_locatie_oms VARCHAR2 (255); -- C30
|
||
v_alg_gebouw_code VARCHAR2 (255); -- C10
|
||
v_alg_verdieping_volgnr VARCHAR2 (255); -- N3
|
||
v_alg_verdieping_volgnr_n NUMBER (3); -- N3
|
||
v_alg_ruimte_nr VARCHAR2 (255); -- C10
|
||
v_bezetting VARCHAR2 (255); -- N3
|
||
v_bezetting_n NUMBER (3); -- N3
|
||
v_m2kamers VARCHAR2 (255); -- N8.2
|
||
v_m2kamers_n NUMBER (8, 2); -- N8.2
|
||
v_m2open VARCHAR2 (255); -- N8.2
|
||
v_m2open_n NUMBER (8, 2); -- N8.2
|
||
v_aantalopenwp VARCHAR2 (255); -- N3
|
||
v_aantalopenwp_n NUMBER (3); -- N3
|
||
v_afdeling_naam VARCHAR2 (255); -- C10
|
||
v_afdeling_oms VARCHAR2 (255); -- C60
|
||
v_srtruimte_oms VARCHAR2 (255); -- C30
|
||
|
||
-- Overige velden:
|
||
CURSOR c1
|
||
IS
|
||
SELECT *
|
||
FROM fac_imp_file
|
||
WHERE fac_import_key = p_import_key
|
||
ORDER BY fac_imp_file_index;
|
||
BEGIN
|
||
DELETE FROM aonl_imp_ruimtegeg;
|
||
|
||
v_count_tot := 0;
|
||
v_count_import := 0;
|
||
header_is_valid := 0;
|
||
COMMIT;
|
||
|
||
FOR rec1 IN c1
|
||
LOOP
|
||
BEGIN
|
||
v_newline := rec1.fac_imp_file_line;
|
||
v_errormsg := 'Fout opvragen te importeren rij';
|
||
v_aanduiding := '';
|
||
v_ongeldig := 0;
|
||
-- Lees alle veldwaarden
|
||
fac.imp_getfield (v_newline, c_delim, v_alg_locatie_oms);
|
||
fac.imp_getfield (v_newline, c_delim, v_alg_gebouw_code);
|
||
fac.imp_getfield (v_newline, c_delim, v_alg_verdieping_volgnr);
|
||
fac.imp_getfield (v_newline, c_delim, v_alg_ruimte_nr);
|
||
fac.imp_getfield (v_newline, c_delim, v_bezetting);
|
||
fac.imp_getfield (v_newline, c_delim, v_m2kamers);
|
||
fac.imp_getfield (v_newline, c_delim, v_m2open);
|
||
fac.imp_getfield (v_newline, c_delim, v_aantalopenwp);
|
||
fac.imp_getfield (v_newline, c_delim, v_afdeling_naam);
|
||
fac.imp_getfield (v_newline, c_delim, v_afdeling_oms);
|
||
fac.imp_getfield (v_newline, c_delim, v_srtruimte_oms);
|
||
v_aanduiding :=
|
||
'['
|
||
|| v_alg_locatie_oms
|
||
|| '|'
|
||
|| v_alg_gebouw_code
|
||
|| '|'
|
||
|| v_alg_verdieping_volgnr
|
||
|| '|'
|
||
|| v_alg_ruimte_nr
|
||
|| '|'
|
||
|| v_afdeling_naam
|
||
|| '] ';
|
||
|
||
-- Ik controleer of ik een geldige header heb, dat is: in de juiste kolommen
|
||
-- de juiste kolomkop. Ik controleer daarbij ALLE kolommen!
|
||
-- Ik negeer alles totdat ik een geldige header ben gepasseerd.
|
||
IF (header_is_valid = 0)
|
||
THEN
|
||
IF UPPER (v_alg_locatie_oms) = 'LOKATIE'
|
||
AND UPPER (v_alg_gebouw_code) = 'GEBOUW'
|
||
AND UPPER (v_alg_verdieping_volgnr) = 'VERDIEPING'
|
||
AND UPPER (v_alg_ruimte_nr) = 'RUIMTENUMMER'
|
||
AND UPPER (v_bezetting) = '%'
|
||
AND UPPER (v_m2kamers) = 'M2KAMERS'
|
||
AND UPPER (v_m2open) = 'M2OPEN'
|
||
AND UPPER (v_aantalopenwp) = 'AANTALOPENWP'
|
||
AND UPPER (v_afdeling_naam) = 'COSTCENTERNR'
|
||
AND UPPER (v_afdeling_oms) = 'COSTCENTERNAAM'
|
||
AND UPPER (v_srtruimte_oms) = 'SOORTRUIMTE'
|
||
THEN
|
||
header_is_valid := 1;
|
||
END IF;
|
||
ELSE
|
||
v_count_tot := v_count_tot + 1;
|
||
-- Controleer alle veldwaarden
|
||
v_alg_locatie_oms := TRIM (v_alg_locatie_oms);
|
||
|
||
IF LENGTH (v_alg_locatie_oms) > 30
|
||
THEN
|
||
v_alg_locatie_oms := SUBSTR (v_alg_locatie_oms, 1, 30);
|
||
fac.imp_writelog (p_import_key,
|
||
'W',
|
||
v_aanduiding || 'Locatieomschrijving te lang',
|
||
'Aanduiding wordt afgebroken tot <'
|
||
|| v_alg_locatie_oms
|
||
|| '>'
|
||
);
|
||
END IF;
|
||
|
||
--
|
||
v_alg_gebouw_code := TRIM (v_alg_gebouw_code);
|
||
|
||
IF LENGTH (v_alg_gebouw_code) > 10
|
||
THEN
|
||
v_alg_gebouw_code := SUBSTR (v_alg_gebouw_code, 1, 10);
|
||
fac.imp_writelog (p_import_key,
|
||
'W',
|
||
v_aanduiding || 'Gebouwcode te lang',
|
||
'Aanduiding wordt afgebroken tot <'
|
||
|| v_alg_gebouw_code
|
||
|| '>'
|
||
);
|
||
END IF;
|
||
|
||
--
|
||
v_errormsg :=
|
||
'Fout inlezen verdiepingnummer ['
|
||
|| v_alg_verdieping_volgnr
|
||
|| ']';
|
||
v_errorhint := 'Geef een geheel getal niet groter dan 3 posities';
|
||
|
||
BEGIN
|
||
v_alg_verdieping_volgnr_n :=
|
||
ROUND (fac.safe_to_number (v_alg_verdieping_volgnr));
|
||
|
||
IF v_alg_verdieping_volgnr_n NOT BETWEEN -999 AND 999
|
||
THEN
|
||
fac.imp_writelog (p_import_key,
|
||
'E',
|
||
v_aanduiding || v_errormsg,
|
||
v_errorhint
|
||
);
|
||
v_ongeldig := 1;
|
||
END IF;
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
oracle_err_num := SQLCODE;
|
||
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
|
||
v_errormsg :=
|
||
v_errormsg
|
||
|| ' ORACLE (error '
|
||
|| oracle_err_num
|
||
|| '/'
|
||
|| oracle_err_mes
|
||
|| ')';
|
||
fac.imp_writelog (p_import_key,
|
||
'E',
|
||
v_aanduiding || v_errormsg,
|
||
v_errorhint
|
||
);
|
||
END;
|
||
|
||
--
|
||
v_alg_ruimte_nr := TRIM (v_alg_ruimte_nr);
|
||
|
||
IF LENGTH (v_alg_ruimte_nr) > 10
|
||
THEN
|
||
v_alg_ruimte_nr := SUBSTR (v_alg_ruimte_nr, 1, 10);
|
||
fac.imp_writelog (p_import_key,
|
||
'W',
|
||
v_aanduiding || 'Ruimtenummer te lang',
|
||
'Aanduiding wordt afgebroken tot <'
|
||
|| v_alg_ruimte_nr
|
||
|| '>'
|
||
);
|
||
END IF;
|
||
|
||
--
|
||
v_errormsg := 'Fout inlezen bezetting [' || v_bezetting || ']';
|
||
v_errorhint := 'Geef een geheel getal tussen 0 en 100';
|
||
|
||
BEGIN
|
||
v_bezetting_n :=
|
||
ROUND (fac.safe_to_number (REPLACE (v_bezetting, ',', '.')));
|
||
|
||
IF v_bezetting_n NOT BETWEEN 0 AND 100
|
||
THEN
|
||
fac.imp_writelog (p_import_key,
|
||
'E',
|
||
v_aanduiding || v_errormsg,
|
||
v_errorhint
|
||
);
|
||
v_ongeldig := 1;
|
||
END IF;
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
oracle_err_num := SQLCODE;
|
||
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
|
||
v_errormsg :=
|
||
v_errormsg
|
||
|| ' ORACLE (error '
|
||
|| oracle_err_num
|
||
|| '/'
|
||
|| oracle_err_mes
|
||
|| ')';
|
||
fac.imp_writelog (p_import_key,
|
||
'E',
|
||
v_aanduiding || v_errormsg,
|
||
v_errorhint
|
||
);
|
||
END;
|
||
|
||
--
|
||
v_errormsg := 'Fout inlezen kamer opp. [' || v_m2kamers || ']';
|
||
v_errorhint := 'Maximale oppervlakte is 999999.99';
|
||
|
||
BEGIN
|
||
v_m2kamers_n :=
|
||
fac.safe_to_number (REPLACE (v_m2kamers, ',', '.'));
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
oracle_err_num := SQLCODE;
|
||
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
|
||
v_errormsg :=
|
||
v_errormsg
|
||
|| ' ORACLE (error '
|
||
|| oracle_err_num
|
||
|| '/'
|
||
|| oracle_err_mes
|
||
|| ')';
|
||
fac.imp_writelog (p_import_key,
|
||
'E',
|
||
v_aanduiding || v_errormsg,
|
||
v_errorhint
|
||
);
|
||
END;
|
||
|
||
--
|
||
v_errormsg :=
|
||
'Fout inlezen aantal open wp [' || v_aantalopenwp || ']';
|
||
v_errorhint := 'Geef een geheel getal tussen 0 en 100';
|
||
|
||
BEGIN
|
||
v_aantalopenwp_n :=
|
||
ROUND (fac.safe_to_number (REPLACE (v_aantalopenwp, ',',
|
||
'.')
|
||
)
|
||
);
|
||
|
||
IF v_aantalopenwp_n NOT BETWEEN 0 AND 100
|
||
THEN
|
||
fac.imp_writelog (p_import_key,
|
||
'E',
|
||
v_aanduiding || v_errormsg,
|
||
v_errorhint
|
||
);
|
||
v_ongeldig := 1;
|
||
END IF;
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
oracle_err_num := SQLCODE;
|
||
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
|
||
v_errormsg :=
|
||
v_errormsg
|
||
|| ' ORACLE (error '
|
||
|| oracle_err_num
|
||
|| '/'
|
||
|| oracle_err_mes
|
||
|| ')';
|
||
fac.imp_writelog (p_import_key,
|
||
'E',
|
||
v_aanduiding || v_errormsg,
|
||
v_errorhint
|
||
);
|
||
END;
|
||
|
||
--
|
||
v_errormsg := 'Fout inlezen open opp. [' || v_m2open || ']';
|
||
v_errorhint := 'Voor open oppervlakte geldt: #wp x 8(m2)';
|
||
|
||
BEGIN
|
||
v_m2open_n :=
|
||
fac.safe_to_number (REPLACE (v_m2open, ',', '.'));
|
||
|
||
IF v_m2open_n <> (v_aantalopenwp_n * 8)
|
||
THEN
|
||
fac.imp_writelog (p_import_key,
|
||
'W',
|
||
v_aanduiding || v_errormsg,
|
||
v_errorhint
|
||
);
|
||
END IF;
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
oracle_err_num := SQLCODE;
|
||
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
|
||
v_errormsg :=
|
||
v_errormsg
|
||
|| ' ORACLE (error '
|
||
|| oracle_err_num
|
||
|| '/'
|
||
|| oracle_err_mes
|
||
|| ')';
|
||
fac.imp_writelog (p_import_key,
|
||
'E',
|
||
v_aanduiding || v_errormsg,
|
||
v_errorhint
|
||
);
|
||
END;
|
||
|
||
--
|
||
v_afdeling_naam := TRIM (v_afdeling_naam);
|
||
|
||
IF LENGTH (v_afdeling_naam) > 10
|
||
THEN
|
||
v_afdeling_naam := SUBSTR (v_afdeling_naam, 1, 10);
|
||
fac.imp_writelog (p_import_key,
|
||
'W',
|
||
v_aanduiding,
|
||
'Costcenternummer wordt afgebroken tot ['
|
||
|| v_afdeling_naam
|
||
|| ']'
|
||
);
|
||
END IF;
|
||
|
||
--
|
||
v_afdeling_oms := TRIM (v_afdeling_oms);
|
||
|
||
IF LENGTH (v_afdeling_oms) > 60
|
||
THEN
|
||
v_afdeling_naam := SUBSTR (v_afdeling_oms, 1, 60);
|
||
fac.imp_writelog (p_import_key,
|
||
'W',
|
||
v_aanduiding,
|
||
'Costcenternaam wordt afgebroken tot ['
|
||
|| v_afdeling_oms
|
||
|| ']'
|
||
);
|
||
END IF;
|
||
|
||
--
|
||
v_srtruimte_oms := TRIM (v_srtruimte_oms);
|
||
|
||
IF LENGTH (v_srtruimte_oms) > 30
|
||
THEN
|
||
v_srtruimte_oms := SUBSTR (v_srtruimte_oms, 1, 30);
|
||
fac.imp_writelog (p_import_key,
|
||
'W',
|
||
v_aanduiding,
|
||
'Soortruimte wordt afgebroken tot ['
|
||
|| v_srtruimte_oms
|
||
|| ']'
|
||
);
|
||
END IF;
|
||
|
||
-- Insert geformatteerde import record
|
||
IF v_ongeldig = 0
|
||
THEN
|
||
BEGIN
|
||
INSERT INTO aonl_imp_ruimtegeg
|
||
(alg_locatie_oms, alg_gebouw_code,
|
||
alg_verdieping_volgnr, alg_ruimte_nr,
|
||
prs_ruimteafdeling_bezetting, alg_ruimte_opp,
|
||
alg_ruimte_capaciteit, prs_afdeling_naam,
|
||
prs_afdeling_omschrijving,
|
||
alg_srtruimte_omschrijving
|
||
)
|
||
VALUES (v_alg_locatie_oms, v_alg_gebouw_code,
|
||
v_alg_verdieping_volgnr_n, v_alg_ruimte_nr,
|
||
v_bezetting_n, v_m2kamers_n,
|
||
v_aantalopenwp_n, v_afdeling_naam,
|
||
v_afdeling_oms,
|
||
v_srtruimte_oms
|
||
);
|
||
|
||
v_count_import := v_count_import + 1;
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
oracle_err_num := SQLCODE;
|
||
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
|
||
v_errormsg :=
|
||
'ORACLE (error '
|
||
|| oracle_err_num
|
||
|| '/'
|
||
|| oracle_err_mes
|
||
|| ')';
|
||
fac.imp_writelog
|
||
(p_import_key,
|
||
'E',
|
||
v_aanduiding || v_errormsg,
|
||
'Ingelezen regel kan niet worden weggeschreven; fout bij toevoegen regel aan importtabel AONL_IMP_RUIMTEGEG.'
|
||
);
|
||
END;
|
||
END IF;
|
||
END IF;
|
||
END;
|
||
END LOOP;
|
||
|
||
IF (header_is_valid = 0)
|
||
THEN
|
||
fac.imp_writelog (p_import_key,
|
||
'E',
|
||
'Ongeldig importbestand',
|
||
'Geen header of header niet volgens specificatie!'
|
||
);
|
||
ELSE
|
||
fac.imp_writelog (p_import_key,
|
||
'S',
|
||
'Ruimtegegevens: aantal ingelezen importregels: '
|
||
|| TO_CHAR (v_count_tot),
|
||
''
|
||
);
|
||
fac.imp_writelog
|
||
(p_import_key,
|
||
'S',
|
||
'Ruimtegegevens: aantal ongeldige niet ingelezen importregels: '
|
||
|| TO_CHAR (v_count_tot - v_count_import),
|
||
''
|
||
);
|
||
END IF;
|
||
|
||
COMMIT;
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
oracle_err_num := SQLCODE;
|
||
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
|
||
v_errormsg :=
|
||
'ORACLE (error ' || oracle_err_num || '/' || oracle_err_mes || ')';
|
||
fac.imp_writelog (p_import_key,
|
||
'E',
|
||
v_errormsg,
|
||
'Inleesproces ruimtegegevens afgebroken!'
|
||
);
|
||
END aonl_import_ruimtegeg;
|
||
/
|
||
|
||
/* Formatted on 2008/11/11 15:52 (Formatter Plus v4.8.7) */
|
||
CREATE OR REPLACE PROCEDURE aonl_update_ruimtegeg (
|
||
p_import_key IN NUMBER
|
||
)
|
||
AS
|
||
v_errormsg VARCHAR2 (1000);
|
||
oracle_err_num NUMBER;
|
||
oracle_err_mes VARCHAR2 (200);
|
||
|
||
-- SUBPROC
|
||
PROCEDURE insupd_afdelingen (p_import_key IN NUMBER)
|
||
AS
|
||
CURSOR c1
|
||
IS
|
||
SELECT DISTINCT UPPER (i.prs_afdeling_naam) afd_upper,
|
||
i.prs_afdeling_naam afd_naam,
|
||
i.prs_afdeling_omschrijving afd_oms
|
||
FROM aonl_imp_ruimtegeg i;
|
||
|
||
v_errormsg VARCHAR2 (1000);
|
||
ccount NUMBER (10);
|
||
oracle_err_num NUMBER;
|
||
oracle_err_mes VARCHAR2 (200);
|
||
v_count_insert NUMBER (10);
|
||
BEGIN
|
||
v_count_insert := 0;
|
||
|
||
FOR rec IN c1
|
||
LOOP
|
||
BEGIN
|
||
SELECT COUNT (*)
|
||
INTO ccount
|
||
FROM prs_v_aanwezigafdeling a
|
||
WHERE a.prs_afdeling_upper = UPPER (rec.afd_naam);
|
||
|
||
IF ccount = 0
|
||
THEN
|
||
v_errormsg :=
|
||
'Fout bij toevoegen afdeling ['
|
||
|| rec.afd_naam
|
||
|| '-'
|
||
|| rec.afd_oms
|
||
|| ']';
|
||
|
||
INSERT INTO prs_afdeling a
|
||
(a.prs_bedrijf_key, a.prs_afdeling_naam,
|
||
a.prs_afdeling_omschrijving
|
||
)
|
||
VALUES (21, rec.afd_naam, -- HARD 21=Atos Origin!
|
||
rec.afd_oms
|
||
);
|
||
|
||
v_count_insert := v_count_insert + 1;
|
||
ELSE
|
||
v_errormsg :=
|
||
'Fout bij bijwerken afdeling ['
|
||
|| rec.afd_naam
|
||
|| '-'
|
||
|| rec.afd_oms
|
||
|| ']';
|
||
|
||
UPDATE prs_afdeling a
|
||
SET a.prs_afdeling_omschrijving = rec.afd_oms
|
||
WHERE a.prs_afdeling_upper = UPPER (rec.afd_naam);
|
||
END IF;
|
||
|
||
COMMIT;
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
oracle_err_num := SQLCODE;
|
||
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
|
||
v_errormsg :=
|
||
v_errormsg
|
||
|| ' ORACLE (error '
|
||
|| oracle_err_num
|
||
|| '/'
|
||
|| oracle_err_mes
|
||
|| ')';
|
||
fac.imp_writelog (p_import_key, 'E', v_errormsg, '');
|
||
COMMIT; -- tbv logging
|
||
END;
|
||
END LOOP;
|
||
|
||
fac.imp_writelog (p_import_key,
|
||
'S',
|
||
'Afdelingen: aantal toegevoegd: '
|
||
|| TO_CHAR (v_count_insert),
|
||
''
|
||
);
|
||
COMMIT;
|
||
END;
|
||
|
||
-- SUBPROC
|
||
PROCEDURE insupd_ruimtesoorten (
|
||
p_import_key IN NUMBER
|
||
)
|
||
AS
|
||
CURSOR c1
|
||
IS
|
||
SELECT x.sr_upper, x.sr_oms
|
||
FROM (SELECT DISTINCT UPPER (i.alg_srtruimte_omschrijving)
|
||
sr_upper,
|
||
i.alg_srtruimte_omschrijving sr_oms
|
||
FROM aonl_imp_ruimtegeg i) x
|
||
LEFT JOIN
|
||
(SELECT sr.alg_srtruimte_upper sr_upper,
|
||
sr.alg_srtruimte_key sr_key
|
||
FROM alg_srtruimte sr) y ON x.sr_upper = y.sr_upper
|
||
WHERE y.sr_key IS NULL;
|
||
|
||
v_errormsg VARCHAR2 (1000);
|
||
oracle_err_num NUMBER;
|
||
oracle_err_mes VARCHAR2 (200);
|
||
v_count_insert NUMBER (10);
|
||
BEGIN
|
||
v_count_insert := 0;
|
||
|
||
FOR rec IN c1
|
||
LOOP
|
||
BEGIN
|
||
v_errormsg :=
|
||
'Fout bij toevoegen ruimtesoort [' || rec.sr_oms || ']';
|
||
|
||
INSERT INTO alg_srtruimte sr
|
||
(sr.alg_srtruimte_omschrijving
|
||
)
|
||
VALUES (rec.sr_oms
|
||
);
|
||
|
||
v_count_insert := v_count_insert + 1;
|
||
COMMIT;
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
oracle_err_num := SQLCODE;
|
||
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
|
||
v_errormsg :=
|
||
v_errormsg
|
||
|| ' ORACLE (error '
|
||
|| oracle_err_num
|
||
|| '/'
|
||
|| oracle_err_mes
|
||
|| ')';
|
||
fac.imp_writelog (p_import_key, 'E', v_errormsg, '');
|
||
COMMIT; -- tbv logging
|
||
END;
|
||
END LOOP;
|
||
|
||
fac.imp_writelog (p_import_key,
|
||
'S',
|
||
'Ruimtesoorten: aantal toegevoegd: '
|
||
|| TO_CHAR (v_count_insert),
|
||
''
|
||
);
|
||
COMMIT;
|
||
END;
|
||
|
||
-- SUBPROC
|
||
PROCEDURE insupd_ruimten1 (p_import_key IN NUMBER)
|
||
AS
|
||
CURSOR c1
|
||
IS
|
||
SELECT DISTINCT i.alg_locatie_oms loc_oms,
|
||
i.alg_gebouw_code geb_code,
|
||
i.alg_verdieping_volgnr ver_nr,
|
||
i.alg_ruimte_nr rui_nr,
|
||
i.alg_srtruimte_omschrijving sr_oms
|
||
FROM aonl_imp_ruimtegeg i;
|
||
|
||
v_errormsg VARCHAR2 (1000);
|
||
v_locatie_key NUMBER (10);
|
||
v_gebouw_key NUMBER (10);
|
||
v_verdieping_key NUMBER (10);
|
||
v_ruimte_key NUMBER (10);
|
||
v_osrtruimte_key NUMBER (10);
|
||
v_nsrtruimte_key NUMBER (10);
|
||
ccount NUMBER (10);
|
||
oracle_err_num NUMBER;
|
||
oracle_err_mes VARCHAR2 (100);
|
||
v_count_loc NUMBER (10);
|
||
v_count_geb NUMBER (10);
|
||
v_count_ver NUMBER (10);
|
||
v_count_rui NUMBER (10);
|
||
BEGIN
|
||
v_count_loc := 0;
|
||
v_count_geb := 0;
|
||
v_count_ver := 0;
|
||
v_count_rui := 0;
|
||
|
||
FOR rec IN c1
|
||
LOOP
|
||
BEGIN
|
||
SELECT COUNT (*)
|
||
INTO ccount
|
||
FROM alg_v_aanweziglocatie l
|
||
WHERE UPPER (l.alg_locatie_code) =
|
||
UPPER (SUBSTR (rec.loc_oms, 1, 3));
|
||
|
||
IF ccount = 0
|
||
THEN
|
||
v_errormsg :=
|
||
'Fout bij toevoegen locatie ['
|
||
|| UPPER (SUBSTR (rec.loc_oms, 1, 3))
|
||
|| '-'
|
||
|| rec.loc_oms
|
||
|| ']';
|
||
|
||
INSERT INTO alg_locatie
|
||
(alg_district_key, alg_locatie_code,
|
||
alg_locatie_omschrijving
|
||
)
|
||
VALUES (21, UPPER (SUBSTR (rec.loc_oms, 1, 3)),
|
||
-- HARD 21=Nederland!
|
||
rec.loc_oms
|
||
);
|
||
|
||
COMMIT;
|
||
v_count_loc := v_count_loc + 1;
|
||
END IF;
|
||
|
||
v_errormsg :=
|
||
'Fout bij bepalen locatie ['
|
||
|| UPPER (SUBSTR (rec.loc_oms, 1, 3))
|
||
|| '-'
|
||
|| rec.loc_oms
|
||
|| ']';
|
||
|
||
SELECT alg_locatie_key
|
||
INTO v_locatie_key
|
||
FROM alg_v_aanweziglocatie l
|
||
WHERE UPPER (l.alg_locatie_code) =
|
||
UPPER (SUBSTR (rec.loc_oms, 1, 3));
|
||
|
||
SELECT COUNT (*)
|
||
INTO ccount
|
||
FROM alg_v_aanweziggebouw g
|
||
WHERE g.alg_locatie_key = v_locatie_key
|
||
AND UPPER (g.alg_gebouw_code) = UPPER (rec.geb_code);
|
||
|
||
IF ccount = 0
|
||
THEN
|
||
v_errormsg :=
|
||
'Fout bij toevoegen gebouw ['
|
||
|| UPPER (SUBSTR (rec.loc_oms, 1, 3))
|
||
|| '-'
|
||
|| rec.loc_oms
|
||
|| '-'
|
||
|| rec.geb_code
|
||
|| ']';
|
||
|
||
INSERT INTO alg_gebouw
|
||
(alg_locatie_key, alg_gebouw_naam,
|
||
alg_gebouw_code, alg_gebouw_omschrijving
|
||
)
|
||
VALUES (v_locatie_key, rec.geb_code,
|
||
rec.geb_code, rec.geb_code
|
||
);
|
||
|
||
COMMIT;
|
||
v_count_geb := v_count_geb + 1;
|
||
END IF;
|
||
|
||
v_errormsg :=
|
||
'Fout bij bepalen gebouw ['
|
||
|| UPPER (SUBSTR (rec.loc_oms, 1, 3))
|
||
|| '-'
|
||
|| rec.loc_oms
|
||
|| '-'
|
||
|| rec.geb_code
|
||
|| ']';
|
||
|
||
SELECT alg_gebouw_key
|
||
INTO v_gebouw_key
|
||
FROM alg_v_aanweziggebouw g
|
||
WHERE g.alg_locatie_key = v_locatie_key
|
||
AND UPPER (g.alg_gebouw_code) = UPPER (rec.geb_code);
|
||
|
||
SELECT COUNT (*)
|
||
INTO ccount
|
||
FROM alg_v_aanwezigverdieping v
|
||
WHERE v.alg_gebouw_key = v_gebouw_key
|
||
AND v.alg_verdieping_volgnr = rec.ver_nr;
|
||
|
||
IF ccount = 0
|
||
THEN
|
||
v_errormsg :=
|
||
'Fout bij toevoegen verdieping ['
|
||
|| UPPER (SUBSTR (rec.loc_oms, 1, 3))
|
||
|| '-'
|
||
|| rec.loc_oms
|
||
|| '-'
|
||
|| rec.geb_code
|
||
|| '-'
|
||
|| rec.ver_nr
|
||
|| ']';
|
||
|
||
INSERT INTO alg_verdieping
|
||
(alg_gebouw_key, alg_verdieping_omschrijving,
|
||
alg_verdieping_volgnr, alg_verdieping_code
|
||
)
|
||
VALUES (v_gebouw_key, 'Verdieping ' || rec.ver_nr,
|
||
rec.ver_nr, rec.ver_nr
|
||
);
|
||
|
||
COMMIT;
|
||
v_count_ver := v_count_ver + 1;
|
||
END IF;
|
||
|
||
v_errormsg :=
|
||
'Fout bij bepalen verdieping ['
|
||
|| UPPER (SUBSTR (rec.loc_oms, 1, 3))
|
||
|| '-'
|
||
|| rec.loc_oms
|
||
|| '-'
|
||
|| rec.geb_code
|
||
|| '-'
|
||
|| rec.ver_nr
|
||
|| ']';
|
||
|
||
SELECT alg_verdieping_key
|
||
INTO v_verdieping_key
|
||
FROM alg_v_aanwezigverdieping v
|
||
WHERE v.alg_gebouw_key = v_gebouw_key
|
||
AND v.alg_verdieping_volgnr = rec.ver_nr;
|
||
|
||
SELECT COUNT (*)
|
||
INTO ccount
|
||
FROM alg_v_aanwezigruimte r
|
||
WHERE r.alg_verdieping_key = v_verdieping_key
|
||
AND r.alg_ruimte_nr = rec.rui_nr;
|
||
|
||
IF ccount = 0
|
||
THEN
|
||
v_errormsg :=
|
||
'Fout bij toevoegen ruimte ['
|
||
|| UPPER (SUBSTR (rec.loc_oms, 1, 3))
|
||
|| '-'
|
||
|| rec.loc_oms
|
||
|| '-'
|
||
|| rec.geb_code
|
||
|| '-'
|
||
|| rec.ver_nr
|
||
|| '-'
|
||
|| rec.rui_nr
|
||
|| ']';
|
||
|
||
INSERT INTO alg_ruimte
|
||
(alg_verdieping_key, alg_ruimte_nr
|
||
)
|
||
VALUES (v_verdieping_key, rec.rui_nr
|
||
);
|
||
|
||
COMMIT;
|
||
v_count_rui := v_count_rui + 1;
|
||
END IF;
|
||
|
||
v_errormsg :=
|
||
'Fout bij bepalen ruimte ['
|
||
|| UPPER (SUBSTR (rec.loc_oms, 1, 3))
|
||
|| '-'
|
||
|| rec.loc_oms
|
||
|| '-'
|
||
|| rec.geb_code
|
||
|| '-'
|
||
|| rec.ver_nr
|
||
|| '-'
|
||
|| rec.rui_nr
|
||
|| ']';
|
||
|
||
SELECT alg_ruimte_key
|
||
INTO v_ruimte_key
|
||
FROM alg_v_aanwezigruimte r
|
||
WHERE r.alg_verdieping_key = v_verdieping_key
|
||
AND r.alg_ruimte_nr = rec.rui_nr;
|
||
|
||
-- Bepaal srtruimte_key
|
||
v_errormsg :=
|
||
'Fout bij bepalen ruimtesoort [' || rec.sr_oms || ']';
|
||
|
||
SELECT alg_srtruimte_key
|
||
INTO v_nsrtruimte_key
|
||
FROM alg_srtruimte sr
|
||
WHERE sr.alg_srtruimte_upper = UPPER (rec.sr_oms);
|
||
|
||
SELECT COALESCE (alg_srtruimte_key, v_nsrtruimte_key)
|
||
INTO v_osrtruimte_key
|
||
FROM alg_ruimte r
|
||
WHERE r.alg_ruimte_key = v_ruimte_key;
|
||
|
||
-- Update ruimte: srtruimte_key
|
||
v_errormsg :=
|
||
'Fout bij bijwerken ruimte ['
|
||
|| UPPER (SUBSTR (rec.loc_oms, 1, 3))
|
||
|| '-'
|
||
|| rec.loc_oms
|
||
|| '-'
|
||
|| rec.geb_code
|
||
|| '-'
|
||
|| rec.ver_nr
|
||
|| '-'
|
||
|| rec.rui_nr
|
||
|| ']';
|
||
|
||
UPDATE alg_ruimte r
|
||
SET r.alg_srtruimte_key = v_nsrtruimte_key
|
||
WHERE r.alg_ruimte_key = v_ruimte_key;
|
||
|
||
IF v_nsrtruimte_key <> v_osrtruimte_key
|
||
THEN
|
||
v_errormsg :=
|
||
'Bestaande ruimtesoort gewijzigd ['
|
||
|| UPPER (SUBSTR (rec.loc_oms, 1, 3))
|
||
|| '-'
|
||
|| rec.loc_oms
|
||
|| '-'
|
||
|| rec.geb_code
|
||
|| '-'
|
||
|| rec.ver_nr
|
||
|| '-'
|
||
|| rec.rui_nr
|
||
|| ']';
|
||
fac.imp_writelog (p_import_key, 'I', v_errormsg, '');
|
||
END IF;
|
||
|
||
COMMIT;
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
oracle_err_num := SQLCODE;
|
||
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
|
||
v_errormsg :=
|
||
v_errormsg
|
||
|| ' ORACLE (error '
|
||
|| oracle_err_num
|
||
|| '/'
|
||
|| oracle_err_mes
|
||
|| ')';
|
||
fac.imp_writelog (p_import_key, 'E', v_errormsg, '');
|
||
COMMIT; -- tbv logging
|
||
END;
|
||
END LOOP;
|
||
|
||
fac.imp_writelog (p_import_key,
|
||
'S',
|
||
'Locaties: aantal toegevoegd: '
|
||
|| TO_CHAR (v_count_loc),
|
||
''
|
||
);
|
||
fac.imp_writelog (p_import_key,
|
||
'S',
|
||
'Gebouwen: aantal toegevoegd: '
|
||
|| TO_CHAR (v_count_geb),
|
||
''
|
||
);
|
||
fac.imp_writelog (p_import_key,
|
||
'S',
|
||
'Verdiepingen: aantal toegevoegd: '
|
||
|| TO_CHAR (v_count_ver),
|
||
''
|
||
);
|
||
fac.imp_writelog (p_import_key,
|
||
'S',
|
||
'Ruimten: aantal toegevoegd: '
|
||
|| TO_CHAR (v_count_rui),
|
||
''
|
||
);
|
||
COMMIT;
|
||
END;
|
||
|
||
-- SUBPROC
|
||
PROCEDURE insupd_ruimten2 (p_import_key IN NUMBER)
|
||
AS
|
||
CURSOR c1
|
||
IS
|
||
SELECT i.alg_locatie_oms loc_oms, i.alg_gebouw_code geb_code,
|
||
i.alg_verdieping_volgnr ver_nr, i.alg_ruimte_nr rui_nr,
|
||
SUM (i.alg_ruimte_capaciteit) rui_cap,
|
||
SUM (i.alg_ruimte_opp) rui_opp
|
||
FROM aonl_imp_ruimtegeg i
|
||
GROUP BY i.alg_locatie_oms,
|
||
i.alg_gebouw_code,
|
||
i.alg_verdieping_volgnr,
|
||
i.alg_ruimte_nr;
|
||
|
||
v_errormsg VARCHAR2 (1000);
|
||
v_locatie_key NUMBER (10);
|
||
v_gebouw_key NUMBER (10);
|
||
v_verdieping_key NUMBER (10);
|
||
v_ruimte_key NUMBER (10);
|
||
ccount NUMBER (10);
|
||
oracle_err_num NUMBER;
|
||
oracle_err_mes VARCHAR2 (100);
|
||
v_count_tot NUMBER (10);
|
||
BEGIN
|
||
v_count_tot := 0;
|
||
|
||
FOR rec IN c1
|
||
LOOP
|
||
BEGIN
|
||
v_errormsg :=
|
||
'Fout bij bepalen locatie ['
|
||
|| UPPER (SUBSTR (rec.loc_oms, 1, 3))
|
||
|| '-'
|
||
|| rec.loc_oms
|
||
|| ']';
|
||
|
||
SELECT alg_locatie_key
|
||
INTO v_locatie_key
|
||
FROM alg_v_aanweziglocatie l
|
||
WHERE UPPER (l.alg_locatie_code) =
|
||
UPPER (SUBSTR (rec.loc_oms, 1, 3));
|
||
|
||
v_errormsg :=
|
||
'Fout bij bepalen gebouw ['
|
||
|| UPPER (SUBSTR (rec.loc_oms, 1, 3))
|
||
|| '-'
|
||
|| rec.loc_oms
|
||
|| '-'
|
||
|| rec.geb_code
|
||
|| ']';
|
||
|
||
SELECT alg_gebouw_key
|
||
INTO v_gebouw_key
|
||
FROM alg_v_aanweziggebouw g
|
||
WHERE g.alg_locatie_key = v_locatie_key
|
||
AND UPPER (g.alg_gebouw_code) = UPPER (rec.geb_code);
|
||
|
||
v_errormsg :=
|
||
'Fout bij bepalen verdieping ['
|
||
|| UPPER (SUBSTR (rec.loc_oms, 1, 3))
|
||
|| '-'
|
||
|| rec.loc_oms
|
||
|| '-'
|
||
|| rec.geb_code
|
||
|| '-'
|
||
|| rec.ver_nr
|
||
|| ']';
|
||
|
||
SELECT alg_verdieping_key
|
||
INTO v_verdieping_key
|
||
FROM alg_v_aanwezigverdieping v
|
||
WHERE v.alg_gebouw_key = v_gebouw_key
|
||
AND v.alg_verdieping_volgnr = rec.ver_nr;
|
||
|
||
v_errormsg :=
|
||
'Fout bij bepalen ruimte ['
|
||
|| UPPER (SUBSTR (rec.loc_oms, 1, 3))
|
||
|| '-'
|
||
|| rec.loc_oms
|
||
|| '-'
|
||
|| rec.geb_code
|
||
|| '-'
|
||
|| rec.ver_nr
|
||
|| '-'
|
||
|| rec.rui_nr
|
||
|| ']';
|
||
|
||
SELECT alg_ruimte_key
|
||
INTO v_ruimte_key
|
||
FROM alg_v_aanwezigruimte r
|
||
WHERE r.alg_verdieping_key = v_verdieping_key
|
||
AND r.alg_ruimte_nr = rec.rui_nr;
|
||
|
||
-- Update ruimte: ruimte_opp_alt1
|
||
v_errormsg :=
|
||
'Fout bij bijwerken ruimte ['
|
||
|| UPPER (SUBSTR (rec.loc_oms, 1, 3))
|
||
|| '-'
|
||
|| rec.loc_oms
|
||
|| '-'
|
||
|| rec.geb_code
|
||
|| '-'
|
||
|| rec.ver_nr
|
||
|| '-'
|
||
|| rec.rui_nr
|
||
|| ']';
|
||
|
||
UPDATE alg_ruimte r
|
||
SET r.alg_ruimte_opp_alt1 = rec.rui_opp
|
||
WHERE r.alg_ruimte_key = v_ruimte_key;
|
||
|
||
-- Delete eventueel bestaande ruimte-kenmerken '#werkplekken'+'NOR-opp.'(HARD)
|
||
v_errormsg :=
|
||
'Fout bij verwijderen ruimte-kenmerken <#wp/opp> ['
|
||
|| UPPER (SUBSTR (rec.loc_oms, 1, 3))
|
||
|| '-'
|
||
|| rec.loc_oms
|
||
|| '-'
|
||
|| rec.geb_code
|
||
|| '-'
|
||
|| rec.ver_nr
|
||
|| '-'
|
||
|| rec.rui_nr
|
||
|| ']';
|
||
|
||
DELETE FROM alg_onrgoedkenmerk ok
|
||
WHERE ok.alg_kenmerk_key IN (1020, 1081) -- #wp
|
||
AND ok.alg_onrgoed_key = v_ruimte_key
|
||
AND ok.alg_onrgoed_niveau = 'R';
|
||
|
||
-- Insert eventueel ingelezen ruimte-kenmerk '#werkplekken'
|
||
IF rec.rui_cap IS NOT NULL
|
||
THEN
|
||
v_errormsg :=
|
||
'Fout bij toevoegen ruimte-kenmerk <#wp> ['
|
||
|| UPPER (SUBSTR (rec.loc_oms, 1, 3))
|
||
|| '-'
|
||
|| rec.loc_oms
|
||
|| '-'
|
||
|| rec.geb_code
|
||
|| '-'
|
||
|| rec.ver_nr
|
||
|| '-'
|
||
|| rec.rui_nr
|
||
|| ']';
|
||
|
||
INSERT INTO alg_onrgoedkenmerk ok
|
||
(ok.alg_kenmerk_key, ok.alg_onrgoed_key,
|
||
ok.alg_onrgoed_niveau,
|
||
ok.alg_onrgoedkenmerk_waarde
|
||
)
|
||
VALUES (1020, v_ruimte_key,
|
||
'R',
|
||
rec.rui_cap
|
||
);
|
||
END IF;
|
||
|
||
-- Insert eventueel ingelezen ruimte-kenmerk 'NOR-oppervlakte'
|
||
IF rec.rui_opp IS NOT NULL
|
||
THEN
|
||
v_errormsg :=
|
||
'Fout bij toevoegen ruimte-kenmerk <opp> ['
|
||
|| UPPER (SUBSTR (rec.loc_oms, 1, 3))
|
||
|| '-'
|
||
|| rec.loc_oms
|
||
|| '-'
|
||
|| rec.geb_code
|
||
|| '-'
|
||
|| rec.ver_nr
|
||
|| '-'
|
||
|| rec.rui_nr
|
||
|| ']';
|
||
|
||
INSERT INTO alg_onrgoedkenmerk ok
|
||
(ok.alg_kenmerk_key, ok.alg_onrgoed_key,
|
||
ok.alg_onrgoed_niveau,
|
||
ok.alg_onrgoedkenmerk_waarde
|
||
)
|
||
VALUES (1081, v_ruimte_key,
|
||
'R',
|
||
rec.rui_opp
|
||
);
|
||
END IF;
|
||
|
||
COMMIT;
|
||
v_count_tot := v_count_tot + 1;
|
||
-- Delete eventuele bestaande ruimte-afdeling-koppelingen (HARD)
|
||
v_errormsg :=
|
||
'Fout bij verwijderen ruimte-afdeling(en) ['
|
||
|| UPPER (SUBSTR (rec.loc_oms, 1, 3))
|
||
|| '-'
|
||
|| rec.loc_oms
|
||
|| '-'
|
||
|| rec.geb_code
|
||
|| '-'
|
||
|| rec.ver_nr
|
||
|| '-'
|
||
|| rec.rui_nr
|
||
|| ']';
|
||
|
||
DELETE FROM prs_ruimteafdeling ra
|
||
WHERE ra.alg_ruimte_key = v_ruimte_key;
|
||
|
||
COMMIT;
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
oracle_err_num := SQLCODE;
|
||
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
|
||
v_errormsg :=
|
||
v_errormsg
|
||
|| ' ORACLE (error '
|
||
|| oracle_err_num
|
||
|| '/'
|
||
|| oracle_err_mes
|
||
|| ')';
|
||
fac.imp_writelog (p_import_key, 'E', v_errormsg, '');
|
||
COMMIT; -- tbv logging
|
||
END;
|
||
END LOOP;
|
||
|
||
fac.imp_writelog (p_import_key,
|
||
'S',
|
||
'Ruimten: aantal bijgewerkt: '
|
||
|| TO_CHAR (v_count_tot),
|
||
''
|
||
);
|
||
COMMIT;
|
||
END;
|
||
|
||
-- SUBPROC
|
||
PROCEDURE insupd_ruimte_afd (p_import_key IN NUMBER)
|
||
AS
|
||
CURSOR c1
|
||
IS
|
||
SELECT UPPER (SUBSTR (i.alg_locatie_oms, 1, 3)) loc_code,
|
||
UPPER (i.alg_gebouw_code) geb_code,
|
||
i.alg_verdieping_volgnr ver_nr, i.alg_ruimte_nr rui_nr,
|
||
i.prs_afdeling_naam afd_naam,
|
||
i.prs_afdeling_omschrijving afd_oms,
|
||
i.prs_ruimteafdeling_bezetting rui_bezet
|
||
FROM aonl_imp_ruimtegeg i;
|
||
|
||
v_errormsg VARCHAR2 (1000);
|
||
v_locatie_key NUMBER (10);
|
||
v_gebouw_key NUMBER (10);
|
||
v_verdieping_key NUMBER (10);
|
||
v_ruimte_key NUMBER (10);
|
||
v_werkplek_key NUMBER (10);
|
||
v_afdeling_key NUMBER (10);
|
||
v_wp_key NUMBER (10);
|
||
ccount NUMBER (10);
|
||
oracle_err_num NUMBER;
|
||
oracle_err_mes VARCHAR2 (100);
|
||
v_count_tot NUMBER (10);
|
||
v_count_update NUMBER (10);
|
||
BEGIN
|
||
v_count_tot := 0;
|
||
|
||
FOR rec IN c1
|
||
LOOP
|
||
BEGIN
|
||
v_errormsg := 'Fout bij bepalen locatie [' || rec.loc_code || ']';
|
||
|
||
SELECT alg_locatie_key
|
||
INTO v_locatie_key
|
||
FROM alg_v_aanweziglocatie l
|
||
WHERE UPPER (l.alg_locatie_code) =
|
||
UPPER (SUBSTR (rec.loc_code, 1, 3));
|
||
|
||
v_errormsg :=
|
||
'Fout bij bepalen gebouw ['
|
||
|| rec.loc_code
|
||
|| '-'
|
||
|| rec.geb_code
|
||
|| ']';
|
||
|
||
SELECT alg_gebouw_key
|
||
INTO v_gebouw_key
|
||
FROM alg_v_aanweziggebouw g
|
||
WHERE g.alg_locatie_key = v_locatie_key
|
||
AND UPPER (g.alg_gebouw_code) = UPPER (rec.geb_code);
|
||
|
||
v_errormsg :=
|
||
'Fout bij bepalen verdieping ['
|
||
|| rec.loc_code
|
||
|| '-'
|
||
|| rec.geb_code
|
||
|| '-'
|
||
|| rec.ver_nr
|
||
|| ']';
|
||
|
||
SELECT alg_verdieping_key
|
||
INTO v_verdieping_key
|
||
FROM alg_v_aanwezigverdieping v
|
||
WHERE v.alg_gebouw_key = v_gebouw_key
|
||
AND v.alg_verdieping_volgnr = rec.ver_nr;
|
||
|
||
v_errormsg :=
|
||
'Fout bij bepalen ruimte ['
|
||
|| rec.loc_code
|
||
|| '-'
|
||
|| rec.geb_code
|
||
|| '-'
|
||
|| rec.ver_nr
|
||
|| '-'
|
||
|| rec.rui_nr
|
||
|| ']';
|
||
|
||
SELECT alg_ruimte_key
|
||
INTO v_ruimte_key
|
||
FROM alg_v_aanwezigruimte r
|
||
WHERE r.alg_verdieping_key = v_verdieping_key
|
||
AND r.alg_ruimte_nr = rec.rui_nr;
|
||
|
||
-- Bepaal afdeling_key
|
||
v_errormsg :=
|
||
'Fout bij bepalen afdeling ['
|
||
|| rec.afd_naam
|
||
|| '-'
|
||
|| rec.afd_oms
|
||
|| ']';
|
||
|
||
SELECT prs_afdeling_key
|
||
INTO v_afdeling_key
|
||
FROM prs_v_aanwezigafdeling a
|
||
WHERE a.prs_afdeling_upper = UPPER (rec.afd_naam);
|
||
|
||
-- Update ruimte-afdeling-koppeling
|
||
IF UPPER (rec.afd_naam) <> 'NL22591102' -- Leegstand!
|
||
THEN
|
||
v_errormsg :=
|
||
'Fout bij toevoegen ruimte-afdeling ['
|
||
|| rec.afd_naam
|
||
|| '-'
|
||
|| rec.afd_oms
|
||
|| ']';
|
||
|
||
INSERT INTO prs_ruimteafdeling ra
|
||
(ra.alg_ruimte_key, ra.prs_afdeling_key,
|
||
ra.prs_ruimteafdeling_bezetting
|
||
)
|
||
VALUES (v_ruimte_key, v_afdeling_key,
|
||
rec.rui_bezet
|
||
);
|
||
|
||
COMMIT;
|
||
v_count_tot := v_count_tot + 1;
|
||
END IF;
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
oracle_err_num := SQLCODE;
|
||
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
|
||
v_errormsg :=
|
||
v_errormsg
|
||
|| ' ORACLE (error '
|
||
|| oracle_err_num
|
||
|| '/'
|
||
|| oracle_err_mes
|
||
|| ')';
|
||
fac.imp_writelog (p_import_key, 'E', v_errormsg, '');
|
||
COMMIT; -- tbv logging
|
||
END;
|
||
END LOOP;
|
||
|
||
fac.imp_writelog (p_import_key,
|
||
'S',
|
||
'Ruimte-afdeling: aantal toegevoegd: '
|
||
|| TO_CHAR (v_count_tot),
|
||
''
|
||
);
|
||
COMMIT;
|
||
END;
|
||
-- MAIN
|
||
BEGIN
|
||
insupd_afdelingen (p_import_key);
|
||
insupd_ruimtesoorten (p_import_key);
|
||
insupd_ruimten1 (p_import_key);
|
||
insupd_ruimten2 (p_import_key);
|
||
insupd_ruimte_afd (p_import_key);
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
oracle_err_num := SQLCODE;
|
||
oracle_err_mes := SUBSTR (SQLERRM, 1, 150);
|
||
v_errormsg :=
|
||
v_errormsg
|
||
|| 'ORACLE (error '
|
||
|| oracle_err_num
|
||
|| '/'
|
||
|| oracle_err_mes
|
||
|| ')';
|
||
fac.imp_writelog (p_import_key,
|
||
'E',
|
||
'Importproces ruimtegegevens afgebroken!',
|
||
v_errormsg
|
||
);
|
||
END aonl_update_ruimtegeg;
|
||
/
|
||
|
||
---- Pseudo-export HV_FREEZE; doel is om de actuele doorbelastingsregels
|
||
---- (1x per maand) te bevriezen in AONL_HV_FREEZE!
|
||
----
|
||
/* Formatted on 2008/11/14 09:50 (Formatter Plus v4.8.7) */
|
||
CREATE OR REPLACE VIEW aonl_v_export_hv_freeze (RESULT, result_order)
|
||
AS
|
||
SELECT '', 0
|
||
FROM DUAL
|
||
WHERE 1 = 0
|
||
/
|
||
|
||
/* Formatted on 2008/11/14 09:51 (Formatter Plus v4.8.7) */
|
||
CREATE OR REPLACE PROCEDURE aonl_select_hv_freeze (
|
||
p_applname IN VARCHAR2,
|
||
p_applrun IN VARCHAR2
|
||
)
|
||
AS
|
||
BEGIN
|
||
NULL;
|
||
END;
|
||
/
|
||
|
||
/* Formatted on 2008/11/21 11:56 (Formatter Plus v4.8.7) */
|
||
CREATE OR REPLACE PROCEDURE aonl_export_hv_freeze (
|
||
p_applname IN VARCHAR2,
|
||
p_applrun IN VARCHAR2
|
||
)
|
||
AS
|
||
-- Cursor over alle regels voor doorbelasting!
|
||
CURSOR c1
|
||
IS
|
||
SELECT hv.dis_oms, hv.loc_code, hv.geb_code, hv.ver_code,
|
||
hv.ruimte_nr, hv.ruimtesoort, hv.wp_cap, hv.teken_opp,
|
||
hv.sp_nummer, hv.sp_naam, hv.bezetting, hv.m2_wpnorm,
|
||
hv.m2_tarief
|
||
FROM aonl_v_hv_actual hv
|
||
ORDER BY hv.dis_oms,
|
||
hv.loc_code,
|
||
hv.geb_code,
|
||
hv.ver_code,
|
||
hv.ruimte_nr,
|
||
hv.sp_nummer;
|
||
|
||
v_errormsg VARCHAR2 (1000);
|
||
oracle_err_num NUMBER;
|
||
oracle_err_mes VARCHAR2 (200);
|
||
v_count_tot NUMBER (10);
|
||
freeze_date DATE;
|
||
BEGIN
|
||
v_count_tot := 0;
|
||
freeze_date := SYSDATE;
|
||
|
||
FOR rec IN c1
|
||
LOOP
|
||
INSERT INTO aonl_hv_freeze
|
||
(dis_oms, loc_code, geb_code, ver_code,
|
||
ruimte_nr, ruimtesoort, wp_cap,
|
||
teken_opp, sp_nummer, sp_naam, bezetting,
|
||
m2_wpnorm, m2_tarief, freeze_datum, freeze_state
|
||
)
|
||
VALUES (rec.dis_oms, rec.loc_code, rec.geb_code, rec.ver_code,
|
||
rec.ruimte_nr, rec.ruimtesoort, rec.wp_cap,
|
||
rec.teken_opp, rec.sp_nummer, rec.sp_naam, rec.bezetting,
|
||
rec.m2_wpnorm, rec.m2_tarief, freeze_date, 'F'
|
||
);
|
||
|
||
v_count_tot := v_count_tot + 1;
|
||
END LOOP;
|
||
|
||
fac.writelog (p_applname,
|
||
'S',
|
||
'Aantal doorbelastingsregels bevroren: '
|
||
|| TO_CHAR (v_count_tot),
|
||
''
|
||
);
|
||
COMMIT;
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
oracle_err_num := SQLCODE;
|
||
oracle_err_mes := SUBSTR (SQLERRM, 1, 150);
|
||
v_errormsg :=
|
||
'ORACLE (error ' || oracle_err_num || '/' || oracle_err_mes || ')';
|
||
fac.writelog (p_applname,
|
||
'E',
|
||
'Proces HV_FREEZE afgebroken!',
|
||
v_errormsg
|
||
);
|
||
END;
|
||
/
|
||
|
||
-- Bevat notificaties naar Nathalie van Hofwegen (CUST01) of Facilitor (CUST02) nav.
|
||
-- HV-wijzigingverzoeken (2x daags voor meldingen die AM danwel PM zijn ingediend)!
|
||
/* Formatted on 16-3-2010 11:38:12 (QP5 v5.115.810.9015) */
|
||
CREATE OR REPLACE FORCE VIEW AONL_V_NOTI_HV_REMINDER
|
||
(
|
||
CODE,
|
||
SENDER,
|
||
RECEIVER,
|
||
TEXT,
|
||
KEY,
|
||
PAR1,
|
||
PAR2,
|
||
XKEY
|
||
)
|
||
AS
|
||
SELECT 'CUST01',
|
||
prs_perslid_key,
|
||
242, -- Nathalie van Hofwegen
|
||
'Reminder tekeningenbeheer: Verzoek '
|
||
|| mld_melding_key
|
||
|| ' ingediend ter acceptatie.',
|
||
mld_melding_key,
|
||
mm.mld_stdmelding_key,
|
||
mld_melding_omschrijving,
|
||
NULL
|
||
FROM mld_melding mm,
|
||
mld_stdmelding msm
|
||
WHERE mm.mld_stdmelding_key = msm.mld_stdmelding_key
|
||
AND mld_ins_discipline_key = 61
|
||
AND mld_melding_status IN (2, 3)
|
||
AND TRUNC (mld_melding_datum + 0.5) = TRUNC (SYSDATE) -- AM/PM
|
||
UNION ALL
|
||
SELECT 'CUST02',
|
||
prs_perslid_key,
|
||
4, -- _Facilitor
|
||
'Reminder tekeningenbeheer: Verzoek '
|
||
|| mld_melding_key
|
||
|| ' ingediend ter uitvoering.',
|
||
mld_melding_key,
|
||
mm.mld_stdmelding_key,
|
||
mld_melding_omschrijving,
|
||
NULL
|
||
FROM mld_melding mm,
|
||
mld_stdmelding msm
|
||
WHERE mm.mld_stdmelding_key = msm.mld_stdmelding_key
|
||
AND mld_ins_discipline_key = 61 AND mld_melding_status IN (4)
|
||
AND TRUNC (fac.gettrackingdate ('MLDACP', mld_melding_key) + 0.5) =
|
||
TRUNC (SYSDATE) -- AM/PM;
|
||
/
|
||
|
||
BEGIN fac.registercustversion('AONL', 5); END;
|
||
/
|
||
BEGIN adm.systrackscriptId('$Id$', 0); END;
|
||
/
|
||
commit;
|
||
|
||
spool off
|