Files
Database/INS/INS_PAC.SRC
Maykel Geerdink d1e1cedaaf FSN#36182: Inspectie starten deed het niet. Daarna foutmelding (2016.1).
svn path=/Database/trunk/; revision=29217
2016-04-26 13:57:51 +00:00

379 lines
19 KiB
Plaintext

#ifdef INS
/*
* $Revision$
* $Id$
*/
CREATE OR REPLACE PACKAGE ins AS
FUNCTION delete_deelkoppeling( DeelKey IN NUMBER ) RETURN BOOLEAN;
FUNCTION get_description(LPNName IN VARCHAR2, CondKey IN NUMBER, Prefix IN VARCHAR2) RETURN VARCHAR2;
FUNCTION sprintf (ps IN varchar2, pins_deel_key IN number) RETURN varchar2;
FUNCTION contrsprintf (ps IN varchar2, pins_deelsrtcontr_key IN number) RETURN varchar2;
FUNCTION nextcyclusdate (p_insdeel IN NUMBER, p_srtcontrole IN NUMBER, p_steps IN NUMBER DEFAULT 0) RETURN DATE;
FUNCTION nextcyclusdatesteps (p_insdeel IN NUMBER, p_srtcontrole IN NUMBER, p_steps IN NUMBER DEFAULT 1) RETURN NUMBER;
PROCEDURE setinspectstatus (pdlsrtcontrkey IN NUMBER, pstatus IN NUMBER, puserkey IN NUMBER);
END ins;
/
CREATE OR REPLACE PACKAGE BODY ins AS
FUNCTION delete_deelkoppeling( DeelKey IN NUMBER )
RETURN BOOLEAN
AS
BEGIN
DELETE FROM ins_deelkoppeling
WHERE ins_deelkoppeling_van_key = DeelKey
OR ins_deelkoppeling_naar_key = DeelKey;
RETURN TRUE;
EXCEPTION
WHEN OTHERS THEN RETURN FALSE;
END;
-- Was: FAC_F_FAC_GET_DESCRIPTION
FUNCTION get_description(LPNName IN VARCHAR2
,CondKey IN NUMBER
,Prefix IN VARCHAR2) RETURN VARCHAR2 IS
NextVolgNr VARCHAR2(30);
DeelUpper ins_deel.ins_deel_omschrijving%TYPE;
ReturnString VARCHAR2(30);
BEGIN
-- From 4.40 on, CondKey is dummy for ins_deel (object): uniqueness is assumed over the entire database
-- From DB23 on, object uniqueness is forced by prefix only, last parameter PrefixKey was dropped
IF LPNName = 'LPN_INS_DEEL'
THEN
SELECT NVL(LPAD( TO_CHAR(MAX(TO_NUMBER(SUBSTR(ins_deel_upper, LENGTH(Prefix)+1,LENGTH(ins_deel_upper)-LENGTH(Prefix))))+1) , MAX(LENGTH(ins_deel_upper)-LENGTH(Prefix)),'0'),'001')
INTO NextVolgNr
FROM ins_deel
WHERE ins_deel_upper LIKE Prefix||'%'
AND fac.safe_to_integer(SUBSTR(ins_deel_upper, LENGTH(Prefix)+1,LENGTH(ins_deel_upper)-LENGTH(Prefix))) IS NOT NULL
AND LTRIM(SUBSTR (ins_deel_upper, LENGTH (Prefix) + 1), '0') = TO_CHAR(fac.safe_to_integer ((SUBSTR (ins_deel_upper, LENGTH (Prefix) + 1))))
AND ins_deel_parent_key IS NULL
AND ins_deel_verwijder IS NULL;
ELSIF LPNName = 'LPN_INS_ONDERDEEL'
THEN
SELECT NVL(LPAD( TO_CHAR(MAX(TO_NUMBER(SUBSTR(ins_deel_upper, LENGTH(Prefix)+1,LENGTH(ins_deel_upper)-LENGTH(Prefix))))+1) , MAX(LENGTH(ins_deel_upper)-LENGTH(Prefix)),'0'),'001')
INTO NextVolgNr
FROM INS_DEEL
WHERE ins_deel_upper LIKE Prefix||'%'
AND fac.safe_to_integer(SUBSTR(ins_deel_upper, LENGTH(Prefix)+1,LENGTH(ins_deel_upper)-LENGTH(Prefix))) IS NOT NULL
AND ins_deel_parent_key = CondKey
AND ins_deel_verwijder IS NULL;
ELSIF LPNName = 'LPN_ALG_TERREINSECTOR'
THEN
FOR i IN 3..10
LOOP
SELECT NVL(TO_CHAR(MAX(TO_NUMBER(SUBSTR(alg_terreinsector_code,LENGTH(alg_terreinsector_code)-(i-1),LENGTH(alg_terreinsector_code)))+1)), '***')
INTO NextVolgNr
FROM alg_v_aanwezigterreinsector
WHERE LTRIM(SUBSTR(alg_terreinsector_code, LENGTH(alg_terreinsector_code)-(i-1), LENGTH(alg_terreinsector_code))) BETWEEN '0' AND LPAD('9',i,'9')
AND alg_locatie_key = CondKey
AND LENGTH(alg_terreinsector_code) <= i;
IF NextVolgNr = '***'
THEN
IF i = 3
THEN
NextVolgNr := '001';
ELSE
NextVolgNr := POWER(10, (i-1));
END IF;
EXIT;
ELSE
IF LENGTH(NextVolgNr) <= i
THEN
NextVolgNr:= LPAD(NextVolgNr,i,'0');
EXIT;
END IF;
END IF;
END LOOP;
ELSIF LPNName = 'LPN_ALG_GEBOUW'
THEN
FOR i IN 3..10
LOOP
SELECT NVL(TO_CHAR(MAX(TO_NUMBER(SUBSTR(alg_gebouw_code, LENGTH(alg_gebouw_code)-(i-1), LENGTH(alg_gebouw_code)))+1)), '***')
INTO NextVolgNr
FROM alg_v_aanweziggebouw
WHERE LTRIM(SUBSTR(alg_gebouw_code, LENGTH(alg_gebouw_code)-(i-1), LENGTH(alg_gebouw_code))) BETWEEN '0' AND LPAD('9',i,'9')
AND alg_locatie_key = CondKey
AND LENGTH(alg_gebouw_code) <= i;
IF NextVolgNr = '***'
THEN
IF i = 3
THEN
NextVolgNr := '001';
ELSE
NextVolgNr := POWER(10, (i-1));
END IF;
EXIT;
ELSE
IF LENGTH(NextVolgNr) <= i
THEN
NextVolgNr:= LPAD(NextVolgNr,i,'0');
EXIT;
END IF;
END IF;
END LOOP;
ELSIF LPNName = 'LPN_ALG_RUIMTE'
THEN
FOR i IN 3..10
LOOP
SELECT NVL(TO_CHAR(MAX(TO_NUMBER(SUBSTR(alg_ruimte_nr, LENGTH(alg_ruimte_nr)-(i-1), LENGTH(alg_ruimte_nr)))+1)), '***')
INTO NextVolgNr
FROM alg_v_aanwezigruimte
WHERE LTRIM(SUBSTR(alg_ruimte_nr, LENGTH(alg_ruimte_nr)-(i-1), LENGTH(alg_ruimte_nr))) BETWEEN '0' AND LPAD('9',i,'9')
AND alg_verdieping_key = CondKey
AND LENGTH(alg_ruimte_nr) <= i;
IF NextVolgNr = '***'
THEN
IF i = 3
THEN
NextVolgNr := '001';
ELSE
NextVolgNr := POWER(10, (i-1));
END IF;
EXIT;
ELSE
IF LENGTH(NextVolgNr) <= i
THEN
NextVolgNr:= LPAD(NextVolgNr,i,'0');
EXIT;
END IF;
END IF;
END LOOP;
ELSIF LPNName = 'LPN_PRS_WERKPLEK'
THEN
BEGIN
SELECT TO_CHAR(NVL(MAX(prs_werkplek_volgnr),0) +1)
INTO NextVolgNr
FROM prs_werkplek
WHERE prs_alg_ruimte_key = CondKey;
EXCEPTION
WHEN NO_DATA_FOUND
THEN NextVolgNr := '1';
END;
/* Omschrijving */
BEGIN
SELECT alg_ruimte_nr ||' - '|| NextVolgNr
INTO NextVolgNr
FROM alg_ruimte
WHERE alg_ruimte_key = CondKey;
EXCEPTION
WHEN OTHERS
THEN NULL;
END;
END IF;
ReturnString := Prefix||NextVolgNr;
RETURN ReturnString;
END;
FUNCTION sprintf (ps IN varchar2, pins_deel_key IN number)
RETURN varchar2
IS
lins_deel_omschrijving ins_deel.ins_deel_omschrijving%TYPE;
s varchar2 (2048 CHAR);
BEGIN
s := ps;
-- We support substitution of placeholders in the messages
-- ##DESC## = ins_deel_omschrijving
IF INSTR2 (s, '#') > 0
THEN
SELECT ins_deel_omschrijving
INTO lins_deel_omschrijving
FROM ins_deel
WHERE ins_deel_key = pins_deel_key;
s := REPLACE (REPLACE (s, '##DESC##', lins_deel_omschrijving), '##KEY##', TO_CHAR (pins_deel_key));
END IF;
RETURN s;
END;
FUNCTION contrsprintf (ps IN varchar2, pins_deelsrtcontr_key IN number)
RETURN varchar2
IS
s varchar2 (2048 CHAR);
BEGIN
s := ps;
IF INSTR2 (s, '#') > 0
THEN
s := REPLACE (s, '##KEY##', TO_CHAR (pins_deelsrtcontr_key));
END IF;
RETURN s;
END;
-- Berekent de n-de (p_steps) controledatum na p_date.
-- Indien p_steps niet is meegegeven dan wordt de eerstvolgende controledatum na nu teruggegeven.
-- steps = 0, (NULL): 1-ste vandaag of in de toekomst (als meegegeven datum (p_date) de huidite datum is, dan deze weer teruggeven).
-- steps = n: n-volgende vanaf meegegeven datum (p_date). Als deze berekende datum in de toekomst ligt en steps is nog niet null, dan wordt NULL teruggegeven).
FUNCTION nextcyclusdate (p_insdeel IN NUMBER,
p_srtcontrole IN NUMBER,
p_steps IN NUMBER DEFAULT 0)
RETURN DATE
IS
inspdate DATE;
BEGIN
SELECT inspectie_next
INTO inspdate
FROM (WITH defined_inspect AS (SELECT isc.ins_srtcontrole_key,
isc.ins_srtcontrole_mode,
isc.ins_srtcontrole_eenheid,
isc.ins_srtcontrole_bits,
isc.ins_srtcontrole_periode,
id.ins_deel_key,
id.ins_deel_aanmaak
FROM ins_deel id,
ins_srtdeel s,
ins_srtcontrole isc
WHERE s.ins_srtdeel_key = id.ins_srtdeel_key
AND (isc.ins_srtcontrole_niveau = 'S'
AND isc.ins_srtinstallatie_key = id.ins_srtdeel_key
OR isc.ins_srtcontrole_niveau = 'G'
AND isc.ins_srtinstallatie_key = s.ins_srtgroep_key
OR isc.ins_srtcontrole_niveau = 'D'
AND isc.ins_srtinstallatie_key = id.ins_discipline_key)
AND id.ins_deel_key = p_insdeel)
SELECT fac.nextcyclusdate (COALESCE ( (SELECT GREATEST (COALESCE (idsc.ins_deelsrtcontrole_plandatum,
CASE di.ins_srtcontrole_mode
WHEN 0
THEN idsc.ins_deelsrtcontrole_datum_org
ELSE idsc.ins_deelsrtcontrole_datum END),
CASE di.ins_srtcontrole_mode
WHEN 0
THEN idsc.ins_deelsrtcontrole_datum_org
ELSE idsc.ins_deelsrtcontrole_datum
END)
ins_deelsrtcontrole_datum
FROM ins_deelsrtcontrole idsc
WHERE idsc.ins_srtcontrole_key = di.ins_srtcontrole_key
AND idsc.ins_deelsrtcontrole_status IN (5,6)
AND idsc.ins_deel_key = di.ins_deel_key
AND idsc.ins_deelsrtcontrole_key = (SELECT MAX(idsc2.ins_deelsrtcontrole_key)
FROM ins_deelsrtcontrole idsc2
WHERE idsc2.ins_deel_key = di.ins_deel_key
AND idsc2.ins_srtcontrole_key = di.ins_srtcontrole_key
AND idsc2.ins_deelsrtcontrole_status IN (5,6))),
di.ins_deel_aanmaak),
di.ins_srtcontrole_mode,
COALESCE(xcp.ins_srtcontroledl_xcp_eenheid, di.ins_srtcontrole_eenheid),
COALESCE(xcp.ins_srtcontroledl_xcp_periode, di.ins_srtcontrole_periode),
COALESCE(xcp.ins_srtcontroledl_xcp_bits, di.ins_srtcontrole_bits),
p_steps
) inspectie_next
FROM defined_inspect di,
ins_srtcontroledl_xcp xcp
WHERE di.ins_srtcontrole_key = xcp.ins_srtcontrole_key(+)
AND di.ins_deel_key = xcp.ins_deel_key(+)
AND di.ins_deel_key = p_insdeel
AND di.ins_srtcontrole_key = p_srtcontrole
AND (xcp.ins_srtcontroledl_xcp_eind(+) IS NULL OR xcp.ins_srtcontroledl_xcp_eind(+) > TRUNC(SYSDATE, 'DD')));
RETURN inspdate;
END;
FUNCTION nextcyclusdatesteps (p_insdeel IN NUMBER,
p_srtcontrole IN NUMBER,
p_steps IN NUMBER DEFAULT 1) -- Standaard beginnen te tellen bij 1.
RETURN NUMBER
IS
lsteps NUMBER;
BEGIN
SELECT inspectie_steps
INTO lsteps
FROM (WITH defined_inspect AS (SELECT isc.ins_srtcontrole_key,
isc.ins_srtcontrole_mode,
isc.ins_srtcontrole_eenheid,
isc.ins_srtcontrole_bits,
isc.ins_srtcontrole_periode,
id.ins_deel_key,
id.ins_deel_aanmaak
FROM ins_deel id,
ins_srtdeel s,
ins_srtcontrole isc
WHERE s.ins_srtdeel_key = id.ins_srtdeel_key
AND (isc.ins_srtcontrole_niveau = 'S'
AND isc.ins_srtinstallatie_key = id.ins_srtdeel_key
OR isc.ins_srtcontrole_niveau = 'G'
AND isc.ins_srtinstallatie_key = s.ins_srtgroep_key
OR isc.ins_srtcontrole_niveau = 'D'
AND isc.ins_srtinstallatie_key = id.ins_discipline_key)
AND id.ins_deel_key = p_insdeel)
SELECT fac.nextcyclusdatesteps (COALESCE ( (SELECT COALESCE(idsc.ins_deelsrtcontrole_plandatum, idsc.ins_deelsrtcontrole_datum_org) ins_deelsrtcontrole_datum
FROM ins_deelsrtcontrole idsc
WHERE di.ins_srtcontrole_key = idsc.ins_srtcontrole_key
AND idsc.ins_deelsrtcontrole_status IN (5,6)
AND idsc.ins_deel_key = di.ins_deel_key
AND idsc.ins_deelsrtcontrole_key = (SELECT MAX(idsc2.ins_deelsrtcontrole_key)
FROM ins_deelsrtcontrole idsc2
WHERE idsc2.ins_deel_key = p_insdeel
AND idsc2.ins_srtcontrole_key = p_srtcontrole
AND idsc2.ins_deelsrtcontrole_status IN (5,6))),
ins_deel_aanmaak),
di.ins_srtcontrole_mode,
COALESCE(xcp.ins_srtcontroledl_xcp_eenheid, di.ins_srtcontrole_eenheid),
COALESCE(xcp.ins_srtcontroledl_xcp_periode, di.ins_srtcontrole_periode),
COALESCE(xcp.ins_srtcontroledl_xcp_bits, di.ins_srtcontrole_bits),
p_steps
) inspectie_steps
FROM defined_inspect di,
ins_srtcontroledl_xcp xcp
WHERE di.ins_srtcontrole_key = xcp.ins_srtcontrole_key(+)
AND di.ins_deel_key = xcp.ins_deel_key(+)
AND di.ins_deel_key = p_insdeel
AND di.ins_srtcontrole_key = p_srtcontrole
AND (xcp.ins_srtcontroledl_xcp_eind(+) IS NULL OR xcp.ins_srtcontroledl_xcp_eind(+) > TRUNC(SYSDATE, 'DD')));
RETURN lsteps;
END;
-- Geef deelsrtcontrolekey, gewenste status en userkey, en de status wortdt
-- gezet, waarbij zonodig (indien verandering) een trackrecord wordt gemaakt
-- Als de status niet wijzigt, wordt ook geen trackrecord gemaakt
PROCEDURE setinspectstatus (pdlsrtcontrkey IN NUMBER, pstatus IN NUMBER, puserkey IN NUMBER)
AS
currentstatus ins_deelsrtcontrole.ins_deelsrtcontrole_status%TYPE;
newstatus ins_deelsrtcontrole.ins_deelsrtcontrole_status%TYPE;
eventcode fac_srtnotificatie.fac_srtnotificatie_code%TYPE;
BEGIN
SELECT ins_deelsrtcontrole_status
INTO currentstatus
FROM ins_deelsrtcontrole
WHERE ins_deelsrtcontrole_key = pdlsrtcontrkey;
CASE pstatus
WHEN 0 -- Gepland
THEN
newstatus := pstatus;
WHEN 2 -- In behandeling
THEN
newstatus := pstatus;
eventcode := 'INSCBE';
WHEN 5 -- Afgemeld
THEN
newstatus := pstatus;
eventcode := 'INSCAF';
WHEN 6 -- Verwerkt
THEN
newstatus := pstatus;
eventcode := 'INSCVE';
ELSE
-- Invalid statuschange or no change
newstatus := NULL;
END CASE;
IF newstatus IS NOT NULL
THEN
-- vooralsnog lopen de notificaties 1-op-1 met de tracking
-- noticode := eventcode;
UPDATE ins_deelsrtcontrole
SET ins_deelsrtcontrole_status = newstatus
WHERE ins_deelsrtcontrole_key = pdlsrtcontrkey;
-- We know that trackaction doesnt do tracking if eventcode is null
fac.trackaction (eventcode, pdlsrtcontrkey, puserkey, NULL, NULL);
END IF;
END;
END ins;
/
REGISTERRUN('$Id$')
#endif // INS