418 lines
14 KiB
SQL
418 lines
14 KiB
SQL
-- Script containing customer specific configuration sql statements for PRIS
|
|
-- (c) 2010 SG|facilitor bv
|
|
-- $Revision$
|
|
-- $Id$
|
|
--
|
|
-- Support: +31 53 4800700
|
|
|
|
set echo on
|
|
|
|
spool xpris.lst
|
|
|
|
CREATE OR REPLACE VIEW pris_v_label_ruimteafd (
|
|
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 afd. 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 pris_v_label_ruimteafd_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 afd. 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 pris_v_label_ruimteafd_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 afd. binnen bestaat
|
|
SELECT ra.alg_ruimte_key
|
|
FROM prs_v_aanwezigruimteafdeling ra
|
|
WHERE ra.alg_ruimte_key = r.alg_ruimte_key)
|
|
/
|
|
|
|
/* Formatted on 17-2-2010 10:00:36 (QP5 v5.115.810.9015) */
|
|
CREATE OR REPLACE FORCE VIEW pris_v_thema_ruimteafd
|
|
(
|
|
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 afdeling!'),
|
|
DECODE (y.aantal, NULL, -1, 1, y.sp_key, NULL)
|
|
FROM (SELECT r.alg_ruimte_key
|
|
FROM alg_v_aanwezigruimte r,
|
|
alg_v_aanwezigverdieping v,
|
|
alg_v_aanweziggebouw g,
|
|
alg_v_aanweziglocatie l,
|
|
alg_v_aanwezigdistrict 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
|
|
AND d.alg_regio_key = 1) x -- SDU
|
|
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, a.prs_afdeling_naam1, a.prs_afdeling_key
|
|
FROM prs_v_aanwezigafdeling a
|
|
WHERE a.prs_bedrijf_key = 5 -- SDU
|
|
AND NOT EXISTS
|
|
(SELECT 1
|
|
FROM prs_v_aanwezigruimteafdeling ra
|
|
WHERE ra.prs_afdeling_key = a.prs_afdeling_key)
|
|
UNION ALL
|
|
SELECT DISTINCT NULL, '[Leegstand]', -1
|
|
FROM (SELECT COUNT ( * ) aantal
|
|
FROM alg_v_aanwezigruimte r,
|
|
alg_v_aanwezigverdieping v,
|
|
alg_v_aanweziggebouw g,
|
|
alg_v_aanweziglocatie l,
|
|
alg_v_aanwezigdistrict 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
|
|
AND d.alg_regio_key = 1 -- SDU
|
|
AND EXISTS
|
|
(SELECT 1
|
|
FROM prs_v_aanwezigruimteafdeling ra
|
|
WHERE ra.alg_ruimte_key = r.alg_ruimte_key))
|
|
WHERE aantal = 0
|
|
/
|
|
|
|
CREATE OR REPLACE TRIGGER pris_t_thema_ruimte_sp_i_iu
|
|
INSTEAD OF INSERT OR UPDATE
|
|
ON pris_v_thema_ruimteafd
|
|
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 22-9-2010 16:16:16 (QP5 v5.115.810.9015) */
|
|
CREATE OR REPLACE FUNCTION pris_mld_notities (p_mldkey IN NUMBER)
|
|
RETURN VARCHAR2
|
|
IS
|
|
CURSOR c1
|
|
IS
|
|
SELECT mn.mld_melding_note_key,
|
|
'--- '
|
|
|| TO_CHAR (mld_melding_note_aanmaak, 'dd-mm-yyyy')
|
|
|| ' / '
|
|
|| p.prs_perslid_naam_full
|
|
|| ' ---'
|
|
|| CHR (13)
|
|
|| CHR (10)
|
|
|| SUBSTR (mn.mld_melding_note_omschrijving, 1, 3800)
|
|
|| CHR (13)
|
|
|| CHR (10)
|
|
|| CHR (13)
|
|
|| CHR (10)
|
|
notitie
|
|
FROM mld_melding_note mn, prs_v_perslid_fullnames p
|
|
WHERE mld_melding_key = p_mldkey
|
|
AND mn.prs_perslid_key = p.prs_perslid_key
|
|
ORDER BY 1;
|
|
|
|
v_flexcontent VARCHAR2 (4000);
|
|
v_count NUMBER;
|
|
BEGIN
|
|
v_flexcontent := '';
|
|
|
|
FOR rec IN c1
|
|
LOOP
|
|
BEGIN
|
|
v_count := LENGTH (rec.notitie) + 5; -- Beetje speling qua lengte!
|
|
|
|
v_flexcontent :=
|
|
rec.notitie || SUBSTR (v_flexcontent, 1, (4000 - v_count));
|
|
END;
|
|
END LOOP;
|
|
|
|
v_count := LENGTH (v_flexcontent) - 4;
|
|
|
|
RETURN SUBSTR (v_flexcontent, 1, v_count);
|
|
END;
|
|
/
|
|
|
|
/* Formatted on 23-9-2010 11:54:24 (QP5 v5.115.810.9015) */
|
|
CREATE OR REPLACE VIEW pris_v_rap_open_mldnotities
|
|
(
|
|
hide_f_key,
|
|
fclt_f_nummer,
|
|
fclt_f_vakgroep,
|
|
fclt_f_melding,
|
|
melder,
|
|
datum,
|
|
plaats,
|
|
omschrijving,
|
|
status,
|
|
notities,
|
|
fclt_3d_locatie_key
|
|
)
|
|
AS
|
|
SELECT m.mld_melding_key mld_key,
|
|
TO_CHAR (m.mld_melding_key) nummer,
|
|
td.ins_discipline_omschrijving vakgroep,
|
|
sm.mld_stdmelding_omschrijving melding,
|
|
p.prs_perslid_naam_full melder,
|
|
TO_CHAR (fac.gettrackingdate ('MLDNEW', m.mld_melding_key),
|
|
'dd-mm-yyyy')
|
|
datum,
|
|
l.alg_locatie_code
|
|
|| DECODE (og.alg_gebouw_key,
|
|
NULL, NULL,
|
|
'-' || og.alg_gebouw_code)
|
|
|| DECODE (og.alg_verdieping_key,
|
|
NULL, NULL,
|
|
'-' || og.alg_verdieping_code)
|
|
|| DECODE (og.alg_ruimte_key,
|
|
NULL, NULL,
|
|
'-' || og.alg_ruimte_nr)
|
|
plaats,
|
|
m.mld_melding_omschrijving mld_oms,
|
|
s.mld_statuses_omschrijving status,
|
|
pris_mld_notities (m.mld_melding_key) notities,
|
|
l.alg_locatie_key
|
|
FROM mld_melding m,
|
|
mld_stdmelding sm,
|
|
ins_tab_discipline td,
|
|
prs_v_perslid_fullnames_all p,
|
|
alg_v_allonrgoed_gegevens og,
|
|
alg_locatie l,
|
|
mld_statuses s
|
|
WHERE m.mld_melding_status IN (2, 3, 4, 7)
|
|
AND m.mld_stdmelding_key = sm.mld_stdmelding_key
|
|
AND sm.mld_ins_discipline_key = td.ins_discipline_key
|
|
AND p.prs_perslid_key =
|
|
fac.gettrackinguserkey ('MLDNEW', m.mld_melding_key)
|
|
AND m.mld_alg_onroerendgoed_keys = og.alg_onroerendgoed_keys
|
|
AND og.alg_locatie_key = l.alg_locatie_key
|
|
AND m.mld_melding_status = s.mld_statuses_key;
|
|
|
|
CREATE OR REPLACE VIEW pris_v_rap_mld_tracking
|
|
(
|
|
fclt_f_meldingnr,
|
|
fclt_d_datum,
|
|
tijdstip,
|
|
fclt_f_code,
|
|
actie,
|
|
fclt_f_door
|
|
)
|
|
AS
|
|
SELECT TO_CHAR (t.fac_tracking_refkey) meldingnr,
|
|
TO_CHAR (t.fac_tracking_datum, 'dd-mm-yyyy') datum,
|
|
TO_CHAR (t.fac_tracking_datum, 'hh24:mi:ss') tijdstip,
|
|
sn.fac_srtnotificatie_code code,
|
|
COALESCE (t.fac_tracking_oms, sn.fac_srtnotificatie_oms) actie,
|
|
pf.prs_perslid_naam_full door
|
|
FROM fac_tracking t,
|
|
fac_srtnotificatie sn,
|
|
prs_v_perslid_fullnames_all pf
|
|
WHERE t.fac_srtnotificatie_key = sn.fac_srtnotificatie_key
|
|
AND sn.fac_srtnotificatie_code LIKE 'MLD%'
|
|
AND t.prs_perslid_key = pf.prs_perslid_key;
|
|
|
|
CREATE OR REPLACE VIEW pris_v_rap_ord_tracking
|
|
(
|
|
fclt_f_opdrachtnr,
|
|
fclt_d_datum,
|
|
tijdstip,
|
|
fclt_f_code,
|
|
actie,
|
|
fclt_f_door
|
|
)
|
|
AS
|
|
SELECT TO_CHAR (o.mld_melding_key)
|
|
|| '/'
|
|
|| TO_CHAR (o.mld_opdr_bedrijfopdr_volgnr)
|
|
opdrachtnr,
|
|
TO_CHAR (t.fac_tracking_datum, 'dd-mm-yyyy') datum,
|
|
TO_CHAR (t.fac_tracking_datum, 'hh24:mi:ss') tijdstip,
|
|
sn.fac_srtnotificatie_code code,
|
|
COALESCE (t.fac_tracking_oms, sn.fac_srtnotificatie_oms) actie,
|
|
pf.prs_perslid_naam_full door
|
|
FROM fac_tracking t,
|
|
fac_srtnotificatie sn,
|
|
prs_v_perslid_fullnames_all pf,
|
|
mld_opdr o
|
|
WHERE t.fac_srtnotificatie_key = sn.fac_srtnotificatie_key
|
|
AND sn.fac_srtnotificatie_code LIKE 'ORD%'
|
|
AND t.prs_perslid_key = pf.prs_perslid_key
|
|
AND t.fac_tracking_refkey = o.mld_opdr_key;
|
|
|
|
|
|
-- Dummy export NACHTWERK!
|
|
CREATE OR REPLACE VIEW pris_v_export_nachtwerk (RESULT, result_order)
|
|
AS
|
|
SELECT '', 0
|
|
FROM DUAL
|
|
WHERE 1 = 0
|
|
/
|
|
|
|
/* Formatted on 15-11-2012 13:35:08 (QP5 v5.115.810.9015) */
|
|
CREATE OR REPLACE PROCEDURE pris_select_nachtwerk (p_applname IN VARCHAR2,
|
|
p_applrun IN VARCHAR2)
|
|
AS
|
|
-- Cursor loopt over alle Afgeronde opdrachten; deze worden "bevroren"
|
|
-- ofwel Administratief Verwerkt (AV)!
|
|
CURSOR c1
|
|
IS
|
|
SELECT o.mld_opdr_key
|
|
FROM mld_opdr o,
|
|
mld_melding m,
|
|
mld_stdmelding sm,
|
|
mld_discipline md
|
|
WHERE o.mld_statusopdr_key = 9 -- KV
|
|
AND o.mld_typeopdr_key = 261 -- Yask-opdracht
|
|
AND o.mld_melding_key = m.mld_melding_key
|
|
AND m.mld_stdmelding_key = sm.mld_stdmelding_key
|
|
AND md.ins_srtdiscipline_key = 21 -- Yask-melding
|
|
AND sm.mld_ins_discipline_key = md.ins_discipline_key;
|
|
|
|
-- Cursor loopt over alle Afgemelde meldingen waaronder geen opdrachten of
|
|
-- alleen opdrachten die gereed zijn (Afgewezen, Niet akkoord of Verwerkt);
|
|
-- deze worden "bevroren" ofwel AV!
|
|
CURSOR c2
|
|
IS
|
|
SELECT m.mld_melding_key
|
|
FROM mld_melding m, mld_stdmelding sm, mld_discipline md
|
|
WHERE m.mld_melding_status = 5 -- Afgemeld
|
|
AND m.mld_stdmelding_key = sm.mld_stdmelding_key
|
|
AND md.ins_srtdiscipline_key = 21 -- Yask-melding
|
|
AND sm.mld_ins_discipline_key = md.ins_discipline_key
|
|
AND (NOT EXISTS -- Geen opdrachten
|
|
(SELECT 1
|
|
FROM mld_opdr o
|
|
WHERE o.mld_melding_key = m.mld_melding_key)
|
|
OR NOT EXISTS -- Alleen opdrachten die gereed zijn
|
|
(SELECT 1
|
|
FROM mld_opdr o
|
|
WHERE o.mld_melding_key = m.mld_melding_key
|
|
AND o.mld_statusopdr_key NOT IN (1, 2, 7)));
|
|
|
|
v_errormsg VARCHAR2 (1000);
|
|
oracle_err_num NUMBER;
|
|
oracle_err_mes VARCHAR2 (200);
|
|
v_count NUMBER;
|
|
BEGIN
|
|
v_count := 0;
|
|
|
|
-- AV-verklaren Afgeronde opdrachten!
|
|
FOR rec IN c1
|
|
LOOP
|
|
MLD.setopdrachtstatus (rec.mld_opdr_key, 7, NULL);
|
|
|
|
v_count := v_count + 1;
|
|
|
|
COMMIT;
|
|
END LOOP;
|
|
|
|
fac.writelog (
|
|
p_applname,
|
|
'S',
|
|
'Proces: ' || TO_CHAR (v_count) || ' opdrachten AV/gearchiveerd',
|
|
''
|
|
);
|
|
|
|
COMMIT;
|
|
|
|
v_count := 0;
|
|
|
|
-- AV-verklaren Afgemelde meldingen waaronder geen opdrachten of
|
|
-- alleen Afgewezen/Verwerkte opdrachten!
|
|
FOR rec IN c2
|
|
LOOP
|
|
MLD.setmeldingstatus (rec.mld_melding_key, 6, NULL);
|
|
|
|
v_count := v_count + 1;
|
|
|
|
COMMIT;
|
|
END LOOP;
|
|
|
|
fac.writelog (
|
|
p_applname,
|
|
'S',
|
|
'Proces: ' || TO_CHAR (v_count) || ' meldingen AV/gearchiveerd',
|
|
''
|
|
);
|
|
|
|
COMMIT;
|
|
EXCEPTION
|
|
WHEN OTHERS
|
|
THEN
|
|
oracle_err_num := SQLCODE;
|
|
oracle_err_mes := SUBSTR (SQLERRM, 1, 200);
|
|
v_errormsg :=
|
|
'ORACLE (error ' || oracle_err_num || '/' || oracle_err_mes || ')';
|
|
fac.writelog (p_applname,
|
|
'E',
|
|
'Proces NACHTWERK afgebroken!',
|
|
v_errormsg);
|
|
COMMIT;
|
|
END;
|
|
/
|
|
|
|
BEGIN adm.systrackscriptId('$Id$', 0); END;
|
|
/
|
|
BEGIN fac.registercustversion('PRIS', 4); END;
|
|
/
|
|
COMMIT;
|
|
spool off
|