496 lines
24 KiB
Plaintext
496 lines
24 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_scenario 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);
|
|
PROCEDURE ins_daily(today IN DATE DEFAULT SYSDATE);
|
|
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 huidige 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).
|
|
-- De einddatum van het object (xcp.ins_srtcontroledl_xcp_eind) wordt niet meegenomen. De volgende inspectiedatum wordt gewoon teruggeven.
|
|
FUNCTION nextcyclusdate (p_insdeel IN NUMBER,
|
|
p_srtcontrole IN NUMBER,
|
|
p_scenario IN NUMBER,
|
|
p_steps IN NUMBER DEFAULT 0)
|
|
RETURN DATE
|
|
IS
|
|
inspdate DATE;
|
|
BEGIN
|
|
SELECT fac.nextcyclusdate (COALESCE ( (SELECT CASE xcp.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 = xcp.ins_srtcontrole_key
|
|
AND idsc.ins_deelsrtcontrole_status IN (5,6)
|
|
AND idsc.ins_scenario_key = 1
|
|
AND idsc.ins_deel_key = xcp.ins_deel_key
|
|
-- Voor mjob moeten de NIET succesvolle inspecties niet worden meegenomen.
|
|
-- Voor periodieke inspectie laten we het vooralsnog hetzelfde.
|
|
AND idsc.ins_deelsrtcontrole_key = (SELECT MAX(ins_deelsrtcontrole_key)
|
|
FROM (SELECT idsc2.ins_deelsrtcontrole_key
|
|
, idsc2.ins_deel_key
|
|
, idsc2.ins_srtcontrole_key
|
|
, 0 ctr_ismjob
|
|
FROM ins_deelsrtcontrole idsc2
|
|
WHERE idsc2.ins_deelsrtcontrole_status IN (5,6)
|
|
AND idsc2.ins_scenario_key = 1
|
|
UNION
|
|
SELECT idsc2.ins_deelsrtcontrole_key
|
|
, idsc2.ins_deel_key
|
|
, idsc2.ins_srtcontrole_key
|
|
, 1 ctr_ismjob
|
|
FROM ins_deelsrtcontrole idsc2,
|
|
ins_controlemode cm
|
|
WHERE idsc2.ins_controlemode_key = cm.ins_controlemode_key
|
|
AND idsc2.ins_deelsrtcontrole_status IN (5,6)
|
|
AND idsc2.ins_scenario_key = 1
|
|
AND cm.ins_controlemode_success = 1) aa
|
|
WHERE aa.ins_deel_key = xcp.ins_deel_key
|
|
AND aa.ins_srtcontrole_key = xcp.ins_srtcontrole_key
|
|
AND aa.ctr_ismjob = xcp.ctr_ismjob)),
|
|
xcp.ins_srtcontroledl_xcp_startdat,
|
|
xcp.ins_deel_aanmaak),
|
|
xcp.ins_srtcontrole_mode,
|
|
xcp.ins_srtcontrole_eenheid,
|
|
xcp.ins_srtcontrole_periode,
|
|
xcp.ins_srtcontrole_bits,
|
|
p_steps,
|
|
xcp.ctr_ismjob
|
|
) inspectie_next
|
|
INTO inspdate
|
|
FROM ins_v_defined_inspect_xcp xcp
|
|
WHERE xcp.ins_deel_key = p_insdeel
|
|
AND xcp.ins_srtcontrole_key = p_srtcontrole
|
|
AND xcp.ins_scenario_key = p_scenario;
|
|
|
|
RETURN inspdate;
|
|
END;
|
|
|
|
-- De einddatum van het object (xcp.ins_srtcontroledl_xcp_eind) wordt niet meegenomen. De volgende inspectiedatum wordt gewoon teruggeven.
|
|
-- Wordt alleen gebruikt voor Active Situatie (AS) soort controle's. Scenario wordt NULL verondersteld.
|
|
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 fac.nextcyclusdatesteps (COALESCE ( (SELECT COALESCE(idsc.ins_deelsrtcontrole_plandatum, idsc.ins_deelsrtcontrole_datum_org) ins_deelsrtcontrole_datum
|
|
FROM ins_deelsrtcontrole idsc
|
|
WHERE xcp.ins_srtcontrole_key = idsc.ins_srtcontrole_key
|
|
AND idsc.ins_deelsrtcontrole_status IN (5,6)
|
|
AND idsc.ins_scenario_key = 1
|
|
AND idsc.ins_deel_key = xcp.ins_deel_key
|
|
AND idsc.ins_deelsrtcontrole_key = (SELECT MAX(idsc2.ins_deelsrtcontrole_key)
|
|
FROM ins_deelsrtcontrole idsc2
|
|
WHERE idsc2.ins_deel_key = xcp.ins_deel_key
|
|
AND idsc2.ins_srtcontrole_key = xcp.ins_srtcontrole_key
|
|
AND idsc2.ins_deelsrtcontrole_status IN (5,6)
|
|
AND idsc2.ins_scenario_key = 1)),
|
|
xcp.ins_srtcontroledl_xcp_startdat,
|
|
ins_deel_aanmaak),
|
|
xcp.ins_srtcontrole_mode,
|
|
xcp.ins_srtcontrole_eenheid,
|
|
xcp.ins_srtcontrole_periode,
|
|
xcp.ins_srtcontrole_bits,
|
|
p_steps
|
|
) inspectie_steps
|
|
INTO lsteps
|
|
FROM ins_v_defined_inspect_xcp xcp
|
|
WHERE xcp.ins_deel_key = p_insdeel
|
|
AND xcp.ins_srtcontrole_key = p_srtcontrole
|
|
AND xcp.ins_scenario_key = 1;
|
|
|
|
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;
|
|
|
|
PROCEDURE ins_daily(today IN DATE DEFAULT SYSDATE)
|
|
AS
|
|
CURSOR c_days(eerste_dag IN DATE, laatste_dag IN DATE)
|
|
IS
|
|
SELECT DISTINCT TRUNC(h.ins_deel_statedate) uitvoer_dag
|
|
FROM ins_deel_state_history h
|
|
, ins_deel d
|
|
, ins_srtdeel s
|
|
WHERE h.ins_deel_key = d.ins_deel_key
|
|
AND d.ins_srtdeel_key = s.ins_srtdeel_key
|
|
AND BITAND(s.ins_srtdeel_sensortype, 1) = 1
|
|
AND h.ins_deel_statedate BETWEEN eerste_dag AND (laatste_dag + 1)
|
|
ORDER BY 1;
|
|
|
|
CURSOR c_sensors(dag IN DATE)
|
|
IS
|
|
SELECT DISTINCT h.ins_deel_key
|
|
FROM ins_deel_state_history h
|
|
, ins_deel d
|
|
, ins_srtdeel s
|
|
WHERE h.ins_deel_key = d.ins_deel_key
|
|
AND d.ins_srtdeel_key = s.ins_srtdeel_key
|
|
AND BITAND(s.ins_srtdeel_sensortype, 1) = 1
|
|
AND h.ins_deel_statedate BETWEEN (dag) AND (dag + 1);
|
|
|
|
-- Haal de statuswijzigingen van een dag op.
|
|
-- De laatste status loopt tot middernacht.
|
|
-- Ook de status van middernacht tot de eerste statuswijziging deze dag moet worden opgehaald.
|
|
-- Deze kan meerdere dagen voor deze dag voor het laatst gezet zijn!
|
|
CURSOR c_states ( deel_key IN NUMBER
|
|
, dag IN DATE)
|
|
IS
|
|
SELECT x.status
|
|
, SUM(x.eindtijd - x.starttijd) totaaltijd
|
|
FROM (
|
|
( SELECT a.ins_deel_state status
|
|
, dag starttijd
|
|
, min(c.ins_deel_statedate) eindtijd
|
|
, a.ins_deel_key
|
|
FROM ins_deel_state_history a
|
|
, ins_deel_state_history c
|
|
WHERE a.ins_deel_key = c.ins_deel_key
|
|
AND c.ins_deel_statedate BETWEEN dag AND dag+1
|
|
AND a.ins_deel_statedate = (SELECT MAX(b.ins_deel_statedate)
|
|
FROM ins_deel_state_history b
|
|
WHERE b.ins_deel_key = a.ins_deel_key
|
|
AND b.ins_deel_statedate < dag
|
|
)
|
|
GROUP BY a.ins_deel_key
|
|
, a.ins_deel_state
|
|
)
|
|
UNION
|
|
( SELECT a.ins_deel_state status
|
|
, a.ins_deel_statedate starttijd
|
|
, least(MIN(b.ins_deel_statedate), dag+1) eindtijd
|
|
, a.ins_deel_key
|
|
FROM ins_deel_state_history a
|
|
, ins_deel_state_history b
|
|
WHERE a.ins_deel_key = deel_key
|
|
AND a.ins_deel_statedate BETWEEN dag AND dag+1
|
|
AND a.ins_deel_key = b.ins_deel_key
|
|
AND a.ins_deel_state <> b.ins_deel_state
|
|
AND a.ins_deel_statedate < b.ins_deel_statedate
|
|
GROUP BY a.ins_deel_statedate
|
|
, a.ins_deel_state
|
|
, a.ins_deel_key
|
|
)
|
|
) x
|
|
WHERE x.ins_deel_key = deel_key
|
|
GROUP BY x.status;
|
|
|
|
keep_days NUMBER(3);
|
|
first_day_available DATE;
|
|
last_day_compressed DATE;
|
|
start_day_compress DATE;
|
|
end_day_compress DATE;
|
|
BEGIN
|
|
-- Setting aantal dagen history ophalen.
|
|
SELECT COALESCE(fac_setting_default, fac_setting_pvalue)
|
|
INTO keep_days
|
|
FROM fac_setting
|
|
WHERE fac_setting_name = 'ins_state_history';
|
|
|
|
-- dbms_output.put_line('today: '||to_char(today,'dd-mm-yyyy'));
|
|
-- Vandaag comprimeren mag niet want je weet niet of je alle meetwaarden al hebt.
|
|
end_day_compress := TRUNC(today);
|
|
IF (end_day_compress = TRUNC(sysdate))
|
|
THEN
|
|
end_day_compress := end_day_compress -1;
|
|
END IF;
|
|
|
|
-- Voor welke dagen moet ins_deel_state_history gecomprimeerd worden?
|
|
-- (voor het geval ins_daily een aantal dagen niet heeft gewerkt.)
|
|
SELECT TRUNC(COALESCE(MIN(ins_deel_statedate), end_day_compress))
|
|
INTO first_day_available
|
|
FROM ins_deel_state_history;
|
|
-- dbms_output.put_line('first_day_available: ' ||to_char(first_day_available,'dd-mm-yyyy'));
|
|
|
|
SELECT COALESCE(TRUNC(MAX(ins_deel_statedate)), first_day_available)
|
|
INTO last_day_compressed
|
|
FROM ins_deel_state_history_all;
|
|
-- dbms_output.put_line('last_day_compressed: ' ||to_char(last_day_compressed,'dd-mm-yyyy'));
|
|
|
|
SELECT GREATEST(first_day_available, (last_day_compressed + 1))
|
|
INTO start_day_compress
|
|
FROM DUAL;
|
|
-- dbms_output.put_line('Compress from '||to_char(start_day_compress,'dd-mm-yyyy')||' to '||to_char(end_day_compress,'dd-mm-yyyy'));
|
|
|
|
FOR r_day IN c_days(start_day_compress, end_day_compress)
|
|
LOOP
|
|
-- dbms_output.put_line('Compress '||to_char(r_day.uitvoer_dag,'dd-mm-yyyy'));
|
|
FOR r_sensor IN c_sensors(r_day.uitvoer_dag)
|
|
LOOP
|
|
-- dbms_output.put_line('sensor: '||r_sensor.ins_deel_key);
|
|
FOR r_state IN c_states(r_sensor.ins_deel_key, r_day.uitvoer_dag)
|
|
LOOP
|
|
-- dbms_output.put_line('- '||to_char(r_sensor.ins_deel_key)||' '||r_state.status||' '||to_char(r_state.totaaltijd));
|
|
INSERT INTO ins_deel_state_history_all
|
|
( ins_deel_key
|
|
, ins_deel_statedate
|
|
, ins_deel_state
|
|
, ins_deel_statetime
|
|
) VALUES
|
|
( r_sensor.ins_deel_key
|
|
, r_day.uitvoer_dag
|
|
, r_state.status
|
|
, r_state.totaaltijd
|
|
);
|
|
END LOOP;
|
|
END LOOP;
|
|
COMMIT;
|
|
END LOOP;
|
|
--
|
|
-- Verwijder alle records uit ins_deel_state_history ouder dan x dagen.
|
|
DELETE FROM ins_deel_state_history
|
|
WHERE TRUNC(ins_deel_statedate) <= TRUNC(SYSDATE - keep_days);
|
|
END;
|
|
|
|
END ins;
|
|
/
|
|
|
|
REGISTERRUN('$Id$')
|
|
|
|
#endif // INS
|