390 lines
19 KiB
Plaintext
390 lines
19 KiB
Plaintext
#ifdef CTR
|
|
/*
|
|
* $Revision$
|
|
* $Id$
|
|
*/
|
|
|
|
CREATE OR REPLACE PACKAGE ctr AS
|
|
PROCEDURE taak_naar_ter_uitvoering(pmld_stdmelding_key IN NUMBER,
|
|
pmld_subject IN VARCHAR2,
|
|
pins_srtcontrole_info IN VARCHAR2,
|
|
pprs_kostenplaats_key IN NUMBER,
|
|
pprs_perslid_key IN NUMBER,
|
|
pmld_stdmelding_default_disc IN NUMBER,
|
|
palg_locatie_key IN NUMBER,
|
|
palg_onroerendgoed_keys IN NUMBER,
|
|
pins_deel_key IN NUMBER,
|
|
pdeelsrtcontrole_key IN NUMBER);
|
|
RETURN NUMBER;
|
|
|
|
PROCEDURE melding_voor_geplande_taken_maken;
|
|
END ctr;
|
|
/
|
|
|
|
CREATE OR REPLACE PACKAGE BODY ctr AS
|
|
PROCEDURE taak_naar_ter_uitvoering(pmld_stdmelding_key IN NUMBER,
|
|
pmld_subject IN VARCHAR2,
|
|
pins_srtcontrole_info IN VARCHAR2,
|
|
pprs_kostenplaats_key IN NUMBER,
|
|
pprs_perslid_key IN NUMBER,
|
|
pmld_stdmelding_default_disc IN NUMBER,
|
|
palg_locatie_key IN NUMBER,
|
|
palg_onroerendgoed_keys IN NUMBER,
|
|
pins_deel_key IN NUMBER,
|
|
pdeelsrtcontrole_key IN NUMBER)
|
|
AS
|
|
c_applname VARCHAR2 (50) := 'AFMELDEN_ORD';
|
|
v_errormsg VARCHAR2 (1000);
|
|
oracle_err_num NUMBER;
|
|
oracle_err_mes VARCHAR2 (200);
|
|
v_aanduiding VARCHAR2 (200);
|
|
|
|
l_new_melding_key mld_melding.mld_melding_key%TYPE;
|
|
l_new_melding_object_key mld_melding_object.mld_melding_object_key%TYPE;
|
|
BEGIN
|
|
SELECT mld_s_mld_melding_key.NEXTVAL INTO l_new_melding_key FROM DUAL;
|
|
|
|
INSERT INTO mld_melding(prs_perslid_key,
|
|
prs_perslid_key_voor,
|
|
mld_melding_datum,
|
|
mld_ins_discipline_key,
|
|
mld_stdmelding_key,
|
|
mld_melding_omschrijving,
|
|
mld_melding_onderwerp,
|
|
mld_meldbron_key,
|
|
prs_kostenplaats_key,
|
|
mld_alg_locatie_key,
|
|
mld_melding_spoed,
|
|
mld_alg_onroerendgoed_keys,
|
|
mld_melding_module,
|
|
mld_melding_key)
|
|
VALUES (pprs_perslid_key,
|
|
pprs_perslid_key,
|
|
SYSDATE,
|
|
pmld_stdmelding_default_disc,
|
|
pmld_stdmelding_key,
|
|
pins_srtcontrole_info,
|
|
pmld_subject,
|
|
10,
|
|
pprs_kostenplaats_key,
|
|
palg_locatie_key,
|
|
3, -- Default prioriteit 3.
|
|
palg_onroerendgoed_keys,
|
|
'MLD',
|
|
l_new_melding_key);
|
|
|
|
SELECT mld_s_mld_object_key.NEXTVAL INTO l_new_melding_object_key FROM DUAL;
|
|
|
|
INSERT INTO mld_melding_object(ins_deel_key,
|
|
mld_melding_key,
|
|
ins_deelsrtcontrole_key,
|
|
mld_melding_object_key)
|
|
VALUES (pins_deel_key,
|
|
l_new_melding_key,
|
|
pdeelsrtcontrole_key,
|
|
l_new_melding_object_key);
|
|
|
|
mld.setmeldingstatus(l_new_melding_key, 2, NULL, 1);
|
|
|
|
IF pmld_stdmelding_default_disc IS NOT NULL -- mldbhg notificatie.
|
|
THEN
|
|
mld.notifybackoffice (l_new_melding_key, 'MLDBHG', 2);
|
|
END IF;
|
|
|
|
mld.mld_nextworkflowstep (l_new_melding_key, -1);
|
|
|
|
mld.mld_addautoorder(l_new_melding_key);
|
|
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 (c_applname, 'E', v_aanduiding || v_errormsg, 'Taak afgebroken!');
|
|
END;
|
|
|
|
-- Automatische starten en ter uitvoering zetten van taken die voor vandaag of eerder zijn gepland (via plandatum of berekend).
|
|
-- Er wordt bij de taak ook direct een melding aangemaakt.
|
|
-- voorwaarden: 1) Er is een stdmelding gedefinieerd bij de periodieke taak.
|
|
-- 2) Alleen periodieke taken, GEEN mjob taken.
|
|
PROCEDURE melding_voor_geplande_taken_maken
|
|
AS
|
|
c_applname VARCHAR2 (50) := 'MELDING_VOOR_GEPLANDE_TAKEN_MAKEN';
|
|
v_errormsg VARCHAR2 (1000);
|
|
oracle_err_num NUMBER;
|
|
oracle_err_mes VARCHAR2 (200);
|
|
v_aanduiding VARCHAR2 (200);
|
|
v_count_tot NUMBER (10);
|
|
|
|
l_prs_perslid_key prs_perslid.prs_perslid_key%TYPE;
|
|
l_new_deelsrtcontrole_key ins_deelsrtcontrole.ins_deelsrtcontrole_key%TYPE;
|
|
l_deelsrtcontrole_key ins_deelsrtcontrole.ins_deelsrtcontrole_key%TYPE;
|
|
mjb_approvedmld_desc fac_setting.fac_setting_default%TYPE;
|
|
mld_subject VARCHAR2 (200);
|
|
|
|
CURSOR c_taak_naar_ter_uitvoering
|
|
IS
|
|
-- Ingeplande taken.
|
|
SELECT idsc.ins_deelsrtcontrole_key,
|
|
idsc.ins_deel_key,
|
|
idsc.ins_srtcontrole_key,
|
|
idsc.ins_scenario_key,
|
|
xcp.mld_stdmelding_key,
|
|
sm.mld_stdmelding_default_disc,
|
|
CASE
|
|
WHEN d.ins_alg_ruimte_type IN ('T', 'R')
|
|
THEN
|
|
COALESCE(xcp.prs_kostenplaats_key,
|
|
(SELECT prs_kostenplaats_key
|
|
FROM alg_gebouw
|
|
WHERE alg_gebouw_key = (SELECT alg.alg_gebouw_key FROM alg_v_allonroerendgoed alg WHERE alg.alg_onroerendgoed_keys = d.ins_alg_ruimte_key)))
|
|
WHEN d.ins_alg_ruimte_type IN ('W')
|
|
THEN
|
|
COALESCE(xcp.prs_kostenplaats_key,
|
|
(SELECT prs_kostenplaats_key
|
|
FROM alg_gebouw
|
|
WHERE alg_gebouw_key = (SELECT wpg.alg_gebouw_key FROM prs_v_werkplek_gegevens wpg WHERE wpg.prs_werkplek_key = d.ins_alg_ruimte_key)))
|
|
ELSE
|
|
NULL
|
|
END prs_kostenplaats_key,
|
|
xcp.ins_srtcontrole_omschrijving,
|
|
xcp.ins_srtcontrole_info,
|
|
isd.ins_srtdeel_omschrijving,
|
|
CASE
|
|
WHEN d.ins_alg_ruimte_type IN ('T', 'R')
|
|
THEN
|
|
(SELECT alg.alg_locatie_key FROM alg_v_allonroerendgoed alg WHERE alg.alg_onroerendgoed_keys = d.ins_alg_ruimte_key)
|
|
WHEN d.ins_alg_ruimte_type IN ('W')
|
|
THEN
|
|
(SELECT wpg.alg_locatie_key FROM prs_v_werkplek_gegevens wpg WHERE wpg.prs_werkplek_key = d.ins_alg_ruimte_key)
|
|
WHEN d.ins_alg_ruimte_type IN ('P', 'A')
|
|
THEN
|
|
NULL
|
|
END alg_locatie_key,
|
|
CASE
|
|
WHEN d.ins_alg_ruimte_type IN ('T', 'R')
|
|
THEN
|
|
(SELECT alg.alg_onroerendgoed_keys FROM alg_v_allonroerendgoed alg WHERE alg.alg_onroerendgoed_keys = d.ins_alg_ruimte_key)
|
|
WHEN d.ins_alg_ruimte_type IN ('W')
|
|
THEN
|
|
(SELECT wpg.alg_ruimte_key FROM prs_v_werkplek_gegevens wpg WHERE wpg.prs_werkplek_key = d.ins_alg_ruimte_key)
|
|
WHEN d.ins_alg_ruimte_type IN ('P', 'A')
|
|
THEN
|
|
NULL
|
|
END alg_onroerendgoed_keys,
|
|
CASE
|
|
WHEN (SELECT COUNT(ins_deelsrtcontrole_key)
|
|
FROM ins_deelsrtcontrole idsc2
|
|
WHERE idsc2.ins_deel_key = idsc.ins_deel_key
|
|
AND idsc2.ins_srtcontrole_key = idsc.ins_srtcontrole_key
|
|
AND idsc2.ins_scenario_key = idsc.ins_scenario_key
|
|
AND idsc2.ins_deelsrtcontrole_status = 6) >= 1
|
|
THEN
|
|
ins.nextcyclusdate(idsc.ins_deel_key, idsc.ins_srtcontrole_key, 1, 1)
|
|
ELSE NULL
|
|
END nextdate
|
|
FROM ins_deelsrtcontrole idsc,
|
|
ins_v_defined_inspect_xcp xcp,
|
|
ins_v_deelenonderdeel d,
|
|
ins_srtdeel isd,
|
|
mld_stdmelding sm
|
|
WHERE xcp.ins_srtcontrole_key = idsc.ins_srtcontrole_key
|
|
AND xcp.ins_deel_key = idsc.ins_deel_key
|
|
AND xcp.ins_scenario_key = idsc.ins_scenario_key
|
|
AND xcp.mld_stdmelding_key = sm.mld_stdmelding_key
|
|
AND d.ins_deel_key = idsc.ins_deel_key
|
|
AND d.ins_srtdeel_key = isd.ins_srtdeel_key
|
|
AND d.ins_alg_ruimte_type IN ('T', 'R', 'P', 'W', 'A')
|
|
AND TRUNC(idsc.ins_deelsrtcontrole_plandatum, 'dd') <= TRUNC(SYSDATE, 'dd')
|
|
AND (xcp.ins_srtcontrole_eind IS NULL OR xcp.ins_srtcontrole_eind > SYSDATE)
|
|
AND d.ins_deel_verwijder IS NULL
|
|
AND (d.ins_deel_vervaldatum IS NULL OR d.ins_deel_vervaldatum > SYSDATE)
|
|
AND idsc.ins_scenario_key = 1
|
|
AND idsc.ins_deelsrtcontrole_status = 0
|
|
AND xcp.ctr_ismjob = 0
|
|
AND xcp.mld_stdmelding_key IS NOT NULL
|
|
UNION
|
|
-- Berekende taken t.o.v. de laatste inspectie (met historie).
|
|
SELECT NULL ins_deelsrtcontrole_key,
|
|
idsc.ins_deel_key,
|
|
idsc.ins_srtcontrole_key,
|
|
idsc.ins_scenario_key,
|
|
xcp.mld_stdmelding_key,
|
|
sm.mld_stdmelding_default_disc,
|
|
CASE
|
|
WHEN d.ins_alg_ruimte_type IN ('T', 'R')
|
|
THEN
|
|
COALESCE(xcp.prs_kostenplaats_key,
|
|
(SELECT prs_kostenplaats_key
|
|
FROM alg_gebouw
|
|
WHERE alg_gebouw_key = (SELECT alg.alg_gebouw_key FROM alg_v_allonroerendgoed alg WHERE alg.alg_onroerendgoed_keys = d.ins_alg_ruimte_key)))
|
|
WHEN d.ins_alg_ruimte_type IN ('W')
|
|
THEN
|
|
COALESCE(xcp.prs_kostenplaats_key,
|
|
(SELECT prs_kostenplaats_key
|
|
FROM alg_gebouw
|
|
WHERE alg_gebouw_key = (SELECT wpg.alg_gebouw_key FROM prs_v_werkplek_gegevens wpg WHERE wpg.prs_werkplek_key = d.ins_alg_ruimte_key)))
|
|
ELSE
|
|
NULL
|
|
END prs_kostenplaats_key,
|
|
xcp.ins_srtcontrole_omschrijving,
|
|
xcp.ins_srtcontrole_info,
|
|
isd.ins_srtdeel_omschrijving,
|
|
CASE
|
|
WHEN d.ins_alg_ruimte_type IN ('T', 'R')
|
|
THEN
|
|
(SELECT alg.alg_locatie_key FROM alg_v_allonroerendgoed alg WHERE alg.alg_onroerendgoed_keys = d.ins_alg_ruimte_key)
|
|
WHEN d.ins_alg_ruimte_type IN ('W')
|
|
THEN
|
|
(SELECT wpg.alg_locatie_key FROM prs_v_werkplek_gegevens wpg WHERE wpg.prs_werkplek_key = d.ins_alg_ruimte_key)
|
|
WHEN d.ins_alg_ruimte_type IN ('P', 'A')
|
|
THEN
|
|
NULL
|
|
END alg_locatie_key,
|
|
CASE
|
|
WHEN d.ins_alg_ruimte_type IN ('T', 'R')
|
|
THEN
|
|
(SELECT alg.alg_onroerendgoed_keys FROM alg_v_allonroerendgoed alg WHERE alg.alg_onroerendgoed_keys = d.ins_alg_ruimte_key)
|
|
WHEN d.ins_alg_ruimte_type IN ('W')
|
|
THEN
|
|
(SELECT wpg.alg_ruimte_key FROM prs_v_werkplek_gegevens wpg WHERE wpg.prs_werkplek_key = d.ins_alg_ruimte_key)
|
|
WHEN d.ins_alg_ruimte_type IN ('P', 'A')
|
|
THEN
|
|
NULL
|
|
END alg_onroerendgoed_keys,
|
|
CASE
|
|
WHEN (SELECT COUNT(ins_deelsrtcontrole_key)
|
|
FROM ins_deelsrtcontrole idsc2
|
|
WHERE idsc2.ins_deel_key = idsc.ins_deel_key
|
|
AND idsc2.ins_srtcontrole_key = idsc.ins_srtcontrole_key
|
|
AND idsc2.ins_scenario_key = idsc.ins_scenario_key
|
|
AND idsc2.ins_deelsrtcontrole_status = 6) >= 1
|
|
THEN
|
|
ins.nextcyclusdate(idsc.ins_deel_key, idsc.ins_srtcontrole_key, 1, 1)
|
|
ELSE NULL
|
|
END nextdate
|
|
FROM ins_deelsrtcontrole idsc,
|
|
ins_v_defined_inspect_xcp xcp,
|
|
ins_v_deelenonderdeel d,
|
|
ins_srtdeel isd,
|
|
mld_stdmelding sm
|
|
WHERE xcp.ins_srtcontrole_key = idsc.ins_srtcontrole_key
|
|
AND xcp.ins_deel_key = idsc.ins_deel_key
|
|
AND xcp.ins_scenario_key = idsc.ins_scenario_key
|
|
AND xcp.mld_stdmelding_key = sm.mld_stdmelding_key
|
|
AND d.ins_deel_key = idsc.ins_deel_key
|
|
AND d.ins_srtdeel_key = isd.ins_srtdeel_key
|
|
AND d.ins_alg_ruimte_type IN ('T', 'R', 'P', 'W', 'A')
|
|
AND TRUNC(ins.nextcyclusdate(idsc.ins_deel_key, idsc.ins_srtcontrole_key, 1, 1), 'dd') <= TRUNC(SYSDATE, 'dd')
|
|
AND (xcp.ins_srtcontrole_eind IS NULL OR xcp.ins_srtcontrole_eind > SYSDATE)
|
|
AND d.ins_deel_verwijder IS NULL
|
|
AND (d.ins_deel_vervaldatum IS NULL OR d.ins_deel_vervaldatum > SYSDATE)
|
|
AND idsc.ins_scenario_key = 1
|
|
AND idsc.ins_deelsrtcontrole_key = (SELECT MAX(ins_deelsrtcontrole_key)
|
|
FROM ins_deelsrtcontrole idsc2
|
|
WHERE idsc2.ins_deel_key = idsc.ins_deel_key
|
|
AND idsc2.ins_srtcontrole_key = idsc.ins_srtcontrole_key
|
|
AND idsc2.ins_scenario_key = idsc.ins_scenario_key
|
|
AND idsc2.ins_deelsrtcontrole_status = 6)
|
|
AND (SELECT MAX(ins_deelsrtcontrole_key)
|
|
FROM ins_deelsrtcontrole idsc2
|
|
WHERE idsc2.ins_deel_key = idsc.ins_deel_key
|
|
AND idsc2.ins_srtcontrole_key = idsc.ins_srtcontrole_key
|
|
AND idsc2.ins_scenario_key = idsc.ins_scenario_key
|
|
AND idsc2.ins_deelsrtcontrole_status != 6) IS NULL -- Er mag geen lopende taak aanwezig zijn.
|
|
AND xcp.ctr_ismjob = 0
|
|
AND xcp.mld_stdmelding_key IS NOT NULL;
|
|
BEGIN
|
|
v_count_tot := 0;
|
|
FOR rec IN c_taak_naar_ter_uitvoering
|
|
LOOP
|
|
BEGIN
|
|
v_errormsg := 'Fout starten taak';
|
|
v_aanduiding := '[' || TO_CHAR (rec.ins_deel_key) || '/' || TO_CHAR (rec.ins_srtcontrole_key) || '] ';
|
|
|
|
BEGIN
|
|
SELECT prs_perslid_key
|
|
INTO l_prs_perslid_key
|
|
FROM prs_perslid
|
|
WHERE prs_perslid_oslogin = '_SYSTEEM' AND prs_perslid_verwijder IS NULL;
|
|
EXCEPTION
|
|
WHEN NO_DATA_FOUND
|
|
THEN
|
|
fac.putsystemnotification ('Invalid configuration: missing _SYSTEEM user', 1);
|
|
END;
|
|
|
|
-- Stap 1 is de taak starten.
|
|
IF rec.ins_deelsrtcontrole_key IS NULL
|
|
THEN
|
|
SELECT ins_s_ins_deelsrtcontrole_key.NEXTVAL INTO l_new_deelsrtcontrole_key FROM DUAL;
|
|
|
|
INSERT INTO ins_deelsrtcontrole (ins_deelsrtcontrole_key,
|
|
ins_deel_key,
|
|
ins_srtcontrole_key,
|
|
ins_deelsrtcontrole_status,
|
|
prs_perslid_key,
|
|
ins_deelsrtcontrole_datum_org)
|
|
VALUES (l_new_deelsrtcontrole_key,
|
|
rec.ins_deel_key,
|
|
rec.ins_srtcontrole_key,
|
|
2,
|
|
l_prs_perslid_key,
|
|
rec.nextdate);
|
|
l_deelsrtcontrole_key := l_new_deelsrtcontrole_key;
|
|
ELSE
|
|
l_deelsrtcontrole_key := rec.ins_deelsrtcontrole_key;
|
|
-- Het ins_deelsrtcontrole record bestaat al omdat de taak al is ingepland.
|
|
END IF;
|
|
|
|
ins.setinspectstatus(l_deelsrtcontrole_key, 2, NULL);
|
|
|
|
-- Stap 2 is de taak ter uitvoering brengen door een melding aan te maken en deze te koppelen aan de gestarte taak.
|
|
mjb_approvedmld_desc := fac.getsetting('mjb_approvedmelding_description');
|
|
|
|
IF mjb_approvedmld_desc = 2
|
|
THEN
|
|
mld_subject := rec.ins_srtcontrole_omschrijving;
|
|
ELSIF mjb_approvedmld_desc = 3
|
|
THEN
|
|
mld_subject := rec.ins_srtcontrole_omschrijving || ' (' || rec.ins_srtdeel_omschrijving || ')';
|
|
ELSE -- mjb_approvedmelding_description = 1
|
|
mld_subject := rec.ins_srtdeel_omschrijving;
|
|
END IF;
|
|
|
|
-- Melding aangmaken en koppelen.
|
|
ctr.taak_naar_ter_uitvoering(rec.mld_stdmelding_key,
|
|
mld_subject,
|
|
rec.ins_srtcontrole_info,
|
|
rec.prs_kostenplaats_key,
|
|
l_prs_perslid_key,
|
|
rec.mld_stdmelding_default_disc,
|
|
rec.alg_locatie_key,
|
|
rec.alg_onroerendgoed_keys,
|
|
rec.ins_deel_key,
|
|
l_deelsrtcontrole_key);
|
|
|
|
ins.setinspectstatus(l_deelsrtcontrole_key, 3, NULL);
|
|
|
|
v_count_tot := v_count_tot + 1;
|
|
IF MOD (v_count_tot, 500) = 0 THEN COMMIT; END IF;
|
|
END;
|
|
END LOOP;
|
|
|
|
fac.writelog (c_applname, 'S', '#Taken gestart: ' || TO_CHAR (v_count_tot), '');
|
|
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 (c_applname, 'E', v_aanduiding || v_errormsg, 'Taak afgebroken!');
|
|
END;
|
|
END ctr;
|
|
/
|
|
|
|
REGISTERRUN('$Id$')
|
|
|
|
#endif // CTR
|