678 lines
29 KiB
Plaintext
678 lines
29 KiB
Plaintext
/* $Revision$
|
|
* $Id$
|
|
*/
|
|
|
|
/* Purge (definitief echt verijderen) van data >7 jaar zoals met UWVA#61083
|
|
* gerealiseerd voor UWV en met MNNL#78302 voor MN.
|
|
* Proces heeft te maken met het irrelevant raken van data en een wettelijke
|
|
* bewaarplicht (voor bv belastingdienst) en daarmee impliciet een opruimvrijheid
|
|
* na die periode, naast emotionele en praktische voordelen, zoals kleinere backupfiles
|
|
* minder data bij datalekken en de mogelijkheid om nog meer op te ruimen.
|
|
*
|
|
* Gebruik: BEGIN del.fac_purge(1); END;
|
|
*
|
|
* Kan en mag herhaaldelijk worden aangeroepen en verwijdert wat verstreken is
|
|
* en geen latere afhankelijkheden heeft. Er is een lichte volgorde-afhankelijkheid
|
|
* (de gekozen volgorde is bewust) wat automatisch door herhaling wordt gecompenseerd.
|
|
*
|
|
* Praktisch bezien zou een jaarlijkse aanroep best volstaan, maar met een dagelijkse
|
|
* aanroep blijf je zeer strikt binnen het regime en blijft de (performance) impact
|
|
* zeer bescheiden.
|
|
* Er zijn wettelijke termijnen van 7 jaren (84 maanden), maar zoals iedere constante
|
|
* in de core kan die te overrulen worden met setting datapurge_period (years).
|
|
*
|
|
* -- TODO: Misschien ook nog schonen vastgoed, personen, objecten en nog meer?
|
|
* -- TODO: Periodieke bestelaanvragen/opdrachten niet beschouwen?
|
|
*/
|
|
/* NOTE: since views and package are tighly related, the views are contained here instead of FAC_VIE.SRC */
|
|
|
|
CREATE_VIEW(fac_v_2purge_bes,0)
|
|
(
|
|
jaar,
|
|
bes_bestelling_key
|
|
)
|
|
AS
|
|
WITH b
|
|
AS (SELECT bes_bestelling_key,
|
|
bes_bestelling_datum,
|
|
bes_bestelling_retourvan_key,
|
|
COALESCE (
|
|
fac.gettrackingdate ('BESREJ', bes_bestelling_key),
|
|
fac.gettrackingdate ('BESOTV', bes_bestelling_key))
|
|
gesloten
|
|
FROM bes_bestelling
|
|
WHERE bes_bestelling_status IN (1, 6, 7, 8, 9) -- Gesloten bestelling
|
|
AND bes_bestelling_datum < TRUNC (ADD_MONTHS (TRUNC (ADD_MONTHS (SYSDATE, -1), 'yyyy'), -fac.getsetting ('datapurge_period') * 12)))
|
|
SELECT TO_CHAR (b.bes_bestelling_datum, 'yyyy') jaar, bes_bestelling_key
|
|
FROM b
|
|
WHERE bes_bestelling_retourvan_key IS NULL -- Alleen bron-bestelling (dus zonder de retouren)
|
|
AND NOT EXISTS -- Geen later gewijzigde child-bestelopdrachten!
|
|
(SELECT 1
|
|
FROM fac_tracking t, fac_srtnotificatie sn, bes_bestelopdr_item boi, bes_bestelling_item bbi
|
|
WHERE t.fac_tracking_datum > TRUNC (ADD_MONTHS (TRUNC (ADD_MONTHS (SYSDATE, -1), 'yyyy'), -fac.getsetting ('datapurge_period') * 12))
|
|
AND t.fac_srtnotificatie_key = sn.fac_srtnotificatie_key
|
|
AND sn.fac_srtnotificatie_xmlnode = 'bestelopdracht'
|
|
AND sn.fac_srtnotificatie_code <> 'BES2AN'
|
|
AND t.fac_tracking_refkey = boi.bes_bestelopdr_key
|
|
AND boi.bes_bestelopdr_item_key = bbi.bes_bestelopdr_item_key
|
|
AND bbi.bes_bestelling_key = b.bes_bestelling_key)
|
|
AND NOT EXISTS -- Geen lopende facturen op child-bestelopdrachten!
|
|
(SELECT 1
|
|
FROM fin_factuur f, bes_bestelopdr_item boi, bes_bestelling_item bbi
|
|
WHERE f.fin_factuur_verwijder IS NULL
|
|
AND f.fin_factuur_statuses_key IN (2, 3, 5, 6) -- Lopende factuur
|
|
AND f.bes_bestelopdr_key = boi.bes_bestelopdr_key
|
|
AND boi.bes_bestelopdr_item_key = bbi.bes_bestelopdr_item_key
|
|
AND bbi.bes_bestelling_key = b.bes_bestelling_key);
|
|
|
|
CREATE_VIEW(fac_v_2purge_bez,0)
|
|
(
|
|
jaar,
|
|
bez_afspraak_key,
|
|
bezoekers
|
|
)
|
|
AS
|
|
WITH a
|
|
AS ( SELECT a.bez_afspraak_key,
|
|
a.bez_afspraak_datum,
|
|
COUNT (*) bezoekers
|
|
FROM bez_afspraak a, bez_bezoekers b
|
|
WHERE a.bez_afspraak_datum < TRUNC (ADD_MONTHS (TRUNC (ADD_MONTHS (SYSDATE, -1), 'yyyy'), -fac.getsetting ('datapurge_period') * 12))
|
|
AND a.bez_afspraak_key = b.bez_afspraak_key
|
|
GROUP BY a.bez_afspraak_key, a.bez_afspraak_datum)
|
|
SELECT TO_CHAR (a.bez_afspraak_datum, 'yyyy') jaar, bez_afspraak_key, bezoekers
|
|
FROM a;
|
|
|
|
CREATE_VIEW(fac_v_2purge_res,0)
|
|
(
|
|
jaar,
|
|
verwijderd,
|
|
res_rsv_ruimte_key
|
|
)
|
|
AS
|
|
WITH r
|
|
AS (SELECT res_rsv_ruimte_key,
|
|
res_reservering_key,
|
|
res_rsv_ruimte_volgnr,
|
|
res_rsv_ruimte_tot,
|
|
res_rsv_ruimte_verwijder
|
|
FROM res_rsv_ruimte
|
|
WHERE res_rsv_ruimte_tot < TRUNC (ADD_MONTHS (TRUNC (ADD_MONTHS (SYSDATE, -1), 'yyyy'), -fac.getsetting ('datapurge_period') * 12)))
|
|
SELECT TO_CHAR (res_rsv_ruimte_tot, 'yyyy') jaar, DECODE (res_rsv_ruimte_verwijder, NULL, 'J', 'N') verwijderd, res_rsv_ruimte_key
|
|
FROM r
|
|
WHERE NOT EXISTS -- Geen latere child-reserveringen!
|
|
(SELECT 1
|
|
FROM res_rsv_ruimte cr -- Child-reserveringen!
|
|
WHERE cr.res_rsv_ruimte_tot > TRUNC (ADD_MONTHS (TRUNC (ADD_MONTHS (SYSDATE, -1), 'yyyy'), -fac.getsetting ('datapurge_period') * 12))
|
|
AND cr.res_reservering_key = r.res_reservering_key);
|
|
|
|
-- TODO: Periodieke meldingen/opdrachten niet beschouwen? => Bij MN niet gebruikt!
|
|
CREATE_VIEW(fac_v_2purge_mld,0)
|
|
(
|
|
jaar,
|
|
datum,
|
|
mld_melding_key
|
|
)
|
|
AS
|
|
WITH m
|
|
AS (SELECT mld_melding_key,
|
|
mld_melding_datum,
|
|
mld_melding_start_key,
|
|
mld_melding_parentkey,
|
|
COALESCE (
|
|
fac.gettrackingdate ('MLDREJ', mld_melding_key),
|
|
fac.gettrackingdate ('MLDAFM', mld_melding_key), -- Soms niet Afgemeld?
|
|
fac.gettrackingdate ('MLDVER', mld_melding_key))
|
|
gesloten
|
|
FROM mld_melding
|
|
WHERE mld_melding_status IN (1, 5, 6) -- Gesloten
|
|
AND mld_melding_datum < TRUNC (ADD_MONTHS (TRUNC (ADD_MONTHS (SYSDATE, -1), 'yyyy'), -fac.getsetting ('datapurge_period') * 12)))
|
|
SELECT TO_CHAR (m.mld_melding_datum, 'yyyy') jaar, m.mld_melding_datum datum, mld_melding_key
|
|
FROM m
|
|
WHERE m.gesloten < TRUNC (ADD_MONTHS (TRUNC (ADD_MONTHS (SYSDATE, -1), 'yyyy'), -fac.getsetting ('datapurge_period') * 12))
|
|
AND (m.mld_melding_start_key IS NULL OR m.mld_melding_key = m.mld_melding_start_key) -- Alleen bron-melding
|
|
AND m.mld_melding_parentkey IS NULL -- Alleen bron-melding
|
|
AND NOT EXISTS -- Geen later gewijzigde child-opdrachten!
|
|
(SELECT 1
|
|
FROM fac_tracking t, fac_srtnotificatie sn, mld_opdr o
|
|
WHERE t.fac_tracking_datum > TRUNC (ADD_MONTHS (TRUNC (ADD_MONTHS (SYSDATE, -1), 'yyyy'), -fac.getsetting ('datapurge_period') * 12))
|
|
AND t.fac_srtnotificatie_key = sn.fac_srtnotificatie_key
|
|
AND sn.fac_srtnotificatie_xmlnode = 'opdracht'
|
|
AND sn.fac_srtnotificatie_code <> 'ORDANO'
|
|
AND t.fac_tracking_refkey = o.mld_opdr_key
|
|
AND o.mld_melding_key = m.mld_melding_key)
|
|
AND EXISTS -- Eventuele start-melding ook > 7 jaar gesloten!
|
|
(SELECT 1
|
|
FROM m sm -- Start-meldingen!
|
|
WHERE sm.mld_melding_key = COALESCE (m.mld_melding_start_key, m.mld_melding_key))
|
|
AND EXISTS -- Eventuele parent-melding ook > 7 jaar gesloten!
|
|
(SELECT 1
|
|
FROM m pm -- Parent-meldingen!
|
|
WHERE pm.mld_melding_key = COALESCE (m.mld_melding_parentkey, m.mld_melding_key))
|
|
AND NOT EXISTS -- Eventuele vervolg-melding ook > 7 jaar gesloten!
|
|
(SELECT 1
|
|
FROM mld_melding vm, -- Vervolg-meldingen!
|
|
fac_tracking t,
|
|
fac_srtnotificatie sn
|
|
WHERE vm.mld_melding_start_key = m.mld_melding_key
|
|
AND vm.mld_melding_key = t.fac_tracking_refkey
|
|
AND t.fac_srtnotificatie_key = sn.fac_srtnotificatie_key
|
|
AND sn.fac_srtnotificatie_xmlnode = 'melding'
|
|
AND sn.fac_srtnotificatie_code <> 'MLDANO'
|
|
AND (vm.mld_melding_status NOT IN (1, 5, 6) -- Lopend
|
|
OR (EXISTS (SELECT 1 FROM mld_melding vvm where vvm.mld_melding_start_key = vm.mld_melding_key)) -- Geneste vervolgmeldingen. Te ingewikkeld
|
|
OR t.fac_tracking_datum > TRUNC (ADD_MONTHS (TRUNC (ADD_MONTHS (SYSDATE, -1), 'yyyy'), -fac.getsetting ('datapurge_period') * 12)))) -- Geraakt < 7 jaar geleden
|
|
AND NOT EXISTS -- Eventuele child-melding ook > 7 jaar gesloten!
|
|
(SELECT 1
|
|
FROM mld_melding cm, -- Child-meldingen!
|
|
fac_tracking t,
|
|
fac_srtnotificatie sn
|
|
WHERE cm.mld_melding_parentkey = m.mld_melding_key
|
|
AND cm.mld_melding_key = t.fac_tracking_refkey
|
|
AND t.fac_srtnotificatie_key = sn.fac_srtnotificatie_key
|
|
AND sn.fac_srtnotificatie_xmlnode = 'melding'
|
|
AND sn.fac_srtnotificatie_code <> 'MLDANO'
|
|
AND (cm.mld_melding_status NOT IN (1, 5, 6) -- Lopend
|
|
OR t.fac_tracking_datum > TRUNC (ADD_MONTHS (TRUNC (ADD_MONTHS (SYSDATE, -1), 'yyyy'), -fac.getsetting ('datapurge_period') * 12)))) -- Geraakt < 7 jaar geleden
|
|
AND NOT EXISTS -- Geen lopende facturen op child-opdrachten!
|
|
(SELECT 1
|
|
FROM fin_factuur f, mld_opdr o
|
|
WHERE f.fin_factuur_verwijder IS NULL
|
|
AND f.fin_factuur_statuses_key IN (2, 3, 5, 6) -- Lopende factuur
|
|
AND f.mld_opdr_key = o.mld_opdr_key
|
|
AND o.mld_melding_key = m.mld_melding_key);
|
|
|
|
CREATE_VIEW(fac_v_2purge_cnt,0)
|
|
(
|
|
ins_discipline_key,
|
|
contractsoort,
|
|
cnt_contract_key,
|
|
contractnr,
|
|
cnt_contract_omschrijving,
|
|
cnt_contract_looptijd_tot,
|
|
cnt_contract_status
|
|
)
|
|
AS
|
|
SELECT DISTINCT
|
|
c.ins_discipline_key,
|
|
cd.ins_discipline_omschrijving,
|
|
c.cnt_contract_key,
|
|
c.cnt_contract_nummer_intern || DECODE (c.cnt_contract_versie, NULL, '', '.' || c.cnt_contract_versie)
|
|
contractnr,
|
|
c.cnt_contract_omschrijving,
|
|
c.cnt_contract_looptijd_tot,
|
|
c.cnt_contract_status
|
|
FROM cnt_contract c, cnt_discipline cd
|
|
WHERE c.cnt_contract_looptijd_tot < TRUNC (ADD_MONTHS (TRUNC (ADD_MONTHS (SYSDATE, -1), 'yyyy'), -fac.getsetting ('datapurge_period') * 12)) -- Verlopen > 7 jaar geleden
|
|
AND c.ins_discipline_key = cd.ins_discipline_key
|
|
AND NOT EXISTS -- Geen dossier-contract onder dezelfde mantel <= 7 jaar geleden
|
|
(SELECT 1
|
|
FROM cnt_contract dc
|
|
WHERE dc.cnt_contract_verwijder IS NULL
|
|
AND dc.cnt_contract_looptijd_tot >= TRUNC (ADD_MONTHS (TRUNC (ADD_MONTHS (SYSDATE, -1), 'yyyy'), -fac.getsetting ('datapurge_period') * 12))
|
|
AND dc.cnt_contract_mantel_key = c.cnt_contract_key)
|
|
AND NOT EXISTS -- Geen lopende facturen op contract!
|
|
(SELECT 1
|
|
FROM fin_factuur
|
|
WHERE fin_factuur_verwijder IS NULL
|
|
AND fin_factuur_statuses_key IN (2, 3, 5, 6) -- Lopende factuur
|
|
AND cnt_contract_key = c.cnt_contract_key);
|
|
|
|
/* candidate rootview for a fac_v_rap_2purge_all report */
|
|
CREATE_VIEW(fac_v_2purge_all,0)
|
|
(
|
|
module,
|
|
jaar,
|
|
aantal,
|
|
subaantal
|
|
)
|
|
AS
|
|
SELECT 'BES', jaar, COUNT (*) aantal, NULL subaantal
|
|
FROM fac_v_2purge_bes
|
|
GROUP BY 'BES', jaar
|
|
UNION ALL
|
|
SELECT 'BEZ', jaar, COUNT (*) aantal, SUM (bezoekers) subaantal
|
|
FROM fac_v_2purge_bez
|
|
GROUP BY 'BEZ', jaar
|
|
UNION ALL
|
|
SELECT 'RES', jaar, COUNT (*) aantal, NULL subaantal
|
|
FROM fac_v_2purge_res
|
|
GROUP BY 'RES', jaar
|
|
UNION ALL
|
|
SELECT 'MLD', jaar, COUNT (*) aantal, NULL subaantal
|
|
FROM fac_v_2purge_mld
|
|
GROUP BY 'MLD', jaar
|
|
UNION ALL
|
|
SELECT 'CNT', TO_CHAR (cnt_contract_looptijd_tot, 'yyyy') jaar, COUNT ( * ) aantal, NULL subaantal
|
|
FROM fac_v_2purge_cnt
|
|
GROUP BY 'CNT', TO_CHAR (cnt_contract_looptijd_tot, 'yyyy');
|
|
|
|
|
|
|
|
/* THE PACKAGE (that does the job using the views above) */
|
|
|
|
CREATE OR REPLACE PACKAGE del
|
|
AS
|
|
-- If you are verysure, call this procedure with parameter 1
|
|
-- If you need extended logging, add 2 (so use 3)
|
|
PROCEDURE fac_purge (iamverysure IN NUMBER DEFAULT 0);
|
|
END del;
|
|
/
|
|
|
|
CREATE OR REPLACE PACKAGE BODY del
|
|
AS
|
|
PROCEDURE fac_purge(iamverysure IN NUMBER DEFAULT 0)
|
|
AS
|
|
-- BES per jaar
|
|
CURSOR cbes (p_jaar VARCHAR2)
|
|
IS
|
|
SELECT bes_bestelling_key
|
|
FROM fac_v_2purge_bes
|
|
WHERE jaar <= p_jaar
|
|
ORDER BY 1;
|
|
|
|
-- BEZ per jaar (samen met RES)
|
|
CURSOR cbez (p_jaar VARCHAR2)
|
|
IS
|
|
SELECT bez_afspraak_key
|
|
FROM fac_v_2purge_bez
|
|
WHERE jaar <= p_jaar
|
|
ORDER BY 1;
|
|
|
|
-- RES per jaar (samen met BEZ)
|
|
CURSOR cres (p_jaar VARCHAR2)
|
|
IS
|
|
SELECT res_rsv_ruimte_key
|
|
FROM fac_v_2purge_res
|
|
WHERE jaar <= p_jaar
|
|
ORDER BY 1;
|
|
|
|
-- MLD per jaar (of maand)
|
|
CURSOR cmld (p_datum DATE)
|
|
IS
|
|
SELECT mld_melding_key
|
|
FROM fac_v_2purge_mld
|
|
WHERE TRUNC (datum) <= p_datum
|
|
ORDER BY 1;
|
|
|
|
-- CNT allemaal tegelijk, hoeft niet per jaar
|
|
CURSOR ccnt
|
|
IS
|
|
SELECT ins_discipline_key, cnt_contract_key
|
|
FROM fac_v_2purge_cnt
|
|
ORDER BY 1, 2;
|
|
|
|
v_errormsg VARCHAR2 (1000);
|
|
oracle_err_num NUMBER;
|
|
oracle_err_mes VARCHAR2 (200);
|
|
v_count NUMBER (10);
|
|
v_jaar1 VARCHAR2 (4);
|
|
v_jaar2 VARCHAR2 (4);
|
|
v_datum DATE;
|
|
v_purgeblock_start DATE; -- voor logging-timing
|
|
v_purgeblock_end DATE; -- voor logging-timing
|
|
v_genesisdatum DATE; -- de nieuwe datum van het begin der aarde, alles voor deze datum mag weg.
|
|
BEGIN
|
|
|
|
-- Early Exit
|
|
IF fac.getsetting ('datapurge_period') = 99
|
|
THEN
|
|
fac.writelog ('$PURGE$','S','No purge of data, purge is disabled', 'Configuration of datapurge_period 99 (default) means disabled');
|
|
RETURN;
|
|
END IF;
|
|
|
|
-- Bepalen we obv vandaag en de setting datapurge_period (in jaren, default 99)
|
|
-- We vinden januari een uitloopmaand, vandaar de -1. Als iemand anders dat zwaarwegend anders gaat vinden
|
|
-- dan moet dat een datapurge_gracemonths worden. Dezelfde berekening zit ook in alle views hierboven
|
|
-- > Dit is dus 1 januari van het jaar dat bewaard moet blijven <
|
|
-- (niet onlogisch om deze datum als parameter aan de purge mee te kunnen geven?)
|
|
v_genesisdatum := TRUNC (ADD_MONTHS (TRUNC (ADD_MONTHS (SYSDATE, -1), 'yyyy'), -fac.getsetting ('datapurge_period') * 12));
|
|
DBMS_OUTPUT.put_line('About to (re)purge anything before '||TO_CHAR(v_genesisdatum,'DD-MM-YYYY'));
|
|
IF BITAND(iamverysure,1) = 1
|
|
THEN
|
|
fac.writelog ('$PURGE$','I','Purge anything before '||TO_CHAR(v_genesisdatum,'DD-MM-YYYY'), '');
|
|
ELSE
|
|
fac.writelog ('$PURGE$','I','Purge SIMULATION OF anything before '||TO_CHAR(v_genesisdatum,'DD-MM-YYYY'), '');
|
|
END IF;
|
|
|
|
SELECT COALESCE(SUM (aantal),0) INTO v_count FROM fac_v_2purge_all;
|
|
fac.writelog ('$PURGE$','S','There is a grand total of '||TO_CHAR (v_count, '999G999G999', 'NLS_NUMERIC_CHARACTERS = '',.''')||' items to possibly purge.', '');
|
|
DBMS_OUTPUT.put_line('There is a grand total of '||TO_CHAR(v_count)||' items to purge.');
|
|
IF v_count = 0
|
|
THEN
|
|
DBMS_OUTPUT.put_line('So nothing to purge, bye.');
|
|
fac.writelog ('$PURGE$','S','So nothing to purge, done.', '');
|
|
RETURN;
|
|
END IF;
|
|
|
|
DBMS_OUTPUT.put_line('Starting bestellingen');
|
|
-- Telkens een jaartje schonen totdat achterstand ingelopen
|
|
v_count := 0;
|
|
v_purgeblock_start := SYSDATE;
|
|
|
|
SELECT MIN (jaar), MAX (jaar)
|
|
INTO v_jaar1, v_jaar2
|
|
FROM fac_v_2purge_bes
|
|
WHERE jaar > '1990';
|
|
DBMS_OUTPUT.put_line('Range is '||v_jaar1||'-'||v_jaar2);
|
|
|
|
FOR r IN cbes (v_jaar2)
|
|
LOOP
|
|
BEGIN
|
|
v_errormsg := 'Error purging bestelling: ' || TO_CHAR (r.bes_bestelling_key);
|
|
IF BITAND(iamverysure,1) = 1
|
|
THEN
|
|
bes.remove (r.bes_bestelling_key);
|
|
END IF;
|
|
IF BITAND(iamverysure,2) = 2
|
|
THEN
|
|
fac.writelog ('$PURGE$','I','Purged '||TO_CHAR(r.bes_bestelling_key)||'.', '');
|
|
END IF;
|
|
v_count := v_count + 1;
|
|
|
|
-- Elke 1000 BES een COMMIT
|
|
IF MOD (v_count, 1000) = 0
|
|
THEN
|
|
COMMIT;
|
|
END IF;
|
|
EXCEPTION
|
|
WHEN OTHERS
|
|
THEN
|
|
v_errormsg := v_errormsg || '/'|| SUBSTR (SQLERRM, 1, 200);
|
|
fac.writelog ('$PURGE$','E', v_errormsg, 'BES-loop');
|
|
END;
|
|
END LOOP;
|
|
|
|
v_purgeblock_end := SYSDATE;
|
|
|
|
IF v_jaar1 = v_jaar2
|
|
THEN
|
|
fac.writelog (
|
|
'$PURGE$',
|
|
'S',
|
|
'Step 1/5 #Bestellingen purged (year=' || v_jaar2 || '): ' || TO_CHAR (v_count, '999G999G999', 'NLS_NUMERIC_CHARACTERS = '',.'''),
|
|
TO_CHAR (ROUND ((v_purgeblock_end - v_purgeblock_start) * 24 * 60), 'FM990') || 'm');
|
|
ELSE
|
|
fac.writelog (
|
|
'$PURGE$',
|
|
'S',
|
|
'Step 1/5 #Bestellingen purged (years='
|
|
|| v_jaar1
|
|
|| '-'
|
|
|| v_jaar2
|
|
|| '): '
|
|
|| TO_CHAR (v_count, '999G999G999', 'NLS_NUMERIC_CHARACTERS = '',.'''),
|
|
TO_CHAR (ROUND ((v_purgeblock_end - v_purgeblock_start) * 24 * 60), 'FM990') || 'm');
|
|
END IF;
|
|
DBMS_OUTPUT.put_line('Bestellingen done.');
|
|
COMMIT;
|
|
|
|
DBMS_OUTPUT.put_line('Starting bezoekers');
|
|
v_count := 0;
|
|
v_purgeblock_start := SYSDATE;
|
|
|
|
SELECT MIN (jaar), MAX (jaar)
|
|
INTO v_jaar1, v_jaar2
|
|
FROM fac_v_2purge_bez
|
|
WHERE jaar > '1990';
|
|
DBMS_OUTPUT.put_line('Range is '||v_jaar1||'-'||v_jaar2);
|
|
|
|
FOR r IN cbez (v_jaar2)
|
|
LOOP
|
|
BEGIN
|
|
v_errormsg := 'Error purging afspraak: ' || TO_CHAR (r.bez_afspraak_key);
|
|
IF BITAND(iamverysure,1) = 1
|
|
THEN
|
|
bez.remove (r.bez_afspraak_key);
|
|
END IF;
|
|
IF BITAND(iamverysure,2) = 2
|
|
THEN
|
|
fac.writelog ('$PURGE$','I','Purged '||TO_CHAR(r.bez_afspraak_key)||'.', '');
|
|
END IF;
|
|
v_count := v_count + 1;
|
|
|
|
-- Elke 1000 BEZ een COMMIT
|
|
IF MOD (v_count, 1000) = 0
|
|
THEN
|
|
COMMIT;
|
|
END IF;
|
|
EXCEPTION
|
|
WHEN OTHERS
|
|
THEN
|
|
v_errormsg := v_errormsg || '/'|| SUBSTR (SQLERRM, 1, 200);
|
|
fac.writelog ('$PURGE$','E', v_errormsg, 'BEZ-loop');
|
|
END;
|
|
END LOOP;
|
|
|
|
v_purgeblock_end := SYSDATE;
|
|
|
|
IF v_jaar1 = v_jaar2
|
|
THEN
|
|
fac.writelog (
|
|
'$PURGE$',
|
|
'S',
|
|
'Step 2/5 #Afspraken purged (year=' || v_jaar2 || '): ' || TO_CHAR (v_count, '999G999G999', 'NLS_NUMERIC_CHARACTERS = '',.'''),
|
|
TO_CHAR (ROUND ((v_purgeblock_end - v_purgeblock_start) * 24 * 60), 'FM990') || 'm');
|
|
ELSE
|
|
fac.writelog (
|
|
'$PURGE$',
|
|
'S',
|
|
'Step 2/5 #Afspraken purged (years='
|
|
|| v_jaar1
|
|
|| '-'
|
|
|| v_jaar2
|
|
|| '): '
|
|
|| TO_CHAR (v_count, '999G999G999', 'NLS_NUMERIC_CHARACTERS = '',.'''),
|
|
TO_CHAR (ROUND ((v_purgeblock_end - v_purgeblock_start) * 24 * 60), 'FM990') || 'm');
|
|
END IF;
|
|
|
|
COMMIT;
|
|
DBMS_OUTPUT.put_line('Bezoekers done.');
|
|
|
|
DBMS_OUTPUT.put_line('Starting reserveringen');
|
|
v_count := 0;
|
|
v_purgeblock_start := SYSDATE;
|
|
-- jaren kennelijk als BEZ
|
|
|
|
FOR r IN cres (v_jaar2)
|
|
LOOP
|
|
BEGIN
|
|
v_errormsg := 'Error purging reservering: ' || TO_CHAR (r.res_rsv_ruimte_key);
|
|
IF BITAND(iamverysure,1) = 1
|
|
THEN
|
|
res.remove (r.res_rsv_ruimte_key);
|
|
END IF;
|
|
IF BITAND(iamverysure,2) = 2
|
|
THEN
|
|
fac.writelog ('$PURGE$','I','Purged '||TO_CHAR(r.res_rsv_ruimte_key)||'.', '');
|
|
END IF;
|
|
v_count := v_count + 1;
|
|
|
|
-- Elke 1000 RES een COMMIT
|
|
IF MOD (v_count, 1000) = 0
|
|
THEN
|
|
COMMIT;
|
|
END IF;
|
|
EXCEPTION
|
|
WHEN OTHERS
|
|
THEN
|
|
v_errormsg := v_errormsg || '/'|| SUBSTR (SQLERRM, 1, 200);
|
|
fac.writelog ('$PURGE$','E', v_errormsg, 'RES-loop');
|
|
END;
|
|
END LOOP;
|
|
|
|
v_purgeblock_end := SYSDATE;
|
|
|
|
IF v_jaar1 = v_jaar2
|
|
THEN
|
|
fac.writelog (
|
|
'$PURGE$',
|
|
'S',
|
|
'Step 3/5 #Reserveringen purged (year=' || v_jaar1 || '): ' || TO_CHAR (v_count, '999G999G999', 'NLS_NUMERIC_CHARACTERS = '',.'''),
|
|
TO_CHAR (ROUND ((v_purgeblock_end - v_purgeblock_start) * 24 * 60), 'FM990') || 'm');
|
|
ELSE
|
|
fac.writelog (
|
|
'$PURGE$',
|
|
'S',
|
|
'Step 3/5 #Reserveringen purged (years='
|
|
|| v_jaar1
|
|
|| '-'
|
|
|| v_jaar2
|
|
|| '): '
|
|
|| TO_CHAR (v_count, '999G999G999', 'NLS_NUMERIC_CHARACTERS = '',.'''),
|
|
TO_CHAR (ROUND ((v_purgeblock_end - v_purgeblock_start) * 24 * 60), 'FM990') || 'm');
|
|
END IF;
|
|
|
|
DBMS_OUTPUT.put_line('Reserveringen done.');
|
|
COMMIT;
|
|
|
|
DBMS_OUTPUT.put_line('Starting meldingen');
|
|
v_count := 0;
|
|
v_purgeblock_start := SYSDATE;
|
|
|
|
SELECT MIN (jaar), MAX (jaar)
|
|
INTO v_jaar1, v_jaar2
|
|
FROM fac_v_2purge_mld
|
|
WHERE jaar > '1990';
|
|
DBMS_OUTPUT.put_line('Range is '||v_jaar1||'-'||v_jaar2);
|
|
|
|
v_errormsg := 'Fout bepalen oudste datum';
|
|
v_datum := fac.safe_to_date ('31-12-' || v_jaar2, 'dd-mm-yyyy');
|
|
|
|
FOR r IN cmld (v_datum)
|
|
LOOP
|
|
BEGIN
|
|
v_errormsg := 'Error purging melding: ' || TO_CHAR (r.mld_melding_key);
|
|
IF BITAND(iamverysure,1) = 1
|
|
THEN
|
|
mld.remove (r.mld_melding_key);
|
|
END IF;
|
|
IF BITAND(iamverysure,2) = 2
|
|
THEN
|
|
fac.writelog ('$PURGE$','I','Purged '||TO_CHAR(r.mld_melding_key)||'.', '');
|
|
END IF;
|
|
v_count := v_count + 1;
|
|
|
|
-- Elke 1000 MLD een COMMIT
|
|
IF MOD (v_count, 1000) = 0
|
|
THEN
|
|
COMMIT;
|
|
END IF;
|
|
EXCEPTION
|
|
WHEN OTHERS
|
|
THEN
|
|
v_errormsg := v_errormsg || '/'|| SUBSTR (SQLERRM, 1, 200);
|
|
fac.writelog ('$PURGE$','E', v_errormsg, 'MLD-loop');
|
|
END;
|
|
END LOOP;
|
|
|
|
v_purgeblock_end := SYSDATE;
|
|
|
|
--fac.writelog ('$PURGE$', 'S', '#Meldingen purged (maand=' || TO_CHAR (v_datum - 1, 'yyyy-mm') || '): ' || TO_CHAR (v_count), TO_CHAR (ROUND ((v_purgeblock_end - v_purgeblock_start) * 24 * 60), 'FM990') || 'm');
|
|
--fac.writelog ('$PURGE$', 'S', '#Meldingen purged (year=' || TO_CHAR (v_datum - 1, 'yyyy') || '): ' || TO_CHAR (v_count), TO_CHAR (ROUND ((v_purgeblock_end - v_purgeblock_start) * 24 * 60), 'FM990') || 'm');
|
|
IF v_jaar1 = v_jaar2
|
|
THEN
|
|
fac.writelog (
|
|
'$PURGE$',
|
|
'S',
|
|
'Step 4/5 #Meldingen purged (year=' || v_jaar1 || '): ' || TO_CHAR (v_count, '999G999G999', 'NLS_NUMERIC_CHARACTERS = '',.'''),
|
|
TO_CHAR (ROUND ((v_purgeblock_end - v_purgeblock_start) * 24 * 60), 'FM990') || 'm');
|
|
ELSE
|
|
fac.writelog (
|
|
'$PURGE$',
|
|
'S',
|
|
'Step 4/5 #Meldingen purged (years='
|
|
|| v_jaar1
|
|
|| '-'
|
|
|| v_jaar2
|
|
|| '): '
|
|
|| TO_CHAR (v_count, '999G999G999', 'NLS_NUMERIC_CHARACTERS = '',.'''),
|
|
TO_CHAR (ROUND ((v_purgeblock_end - v_purgeblock_start) * 24 * 60), 'FM990') || 'm');
|
|
END IF;
|
|
|
|
COMMIT;
|
|
DBMS_OUTPUT.put_line('Meldingen done.');
|
|
|
|
DBMS_OUTPUT.put_line('Starting contracten');
|
|
v_count := 0;
|
|
v_purgeblock_start := SYSDATE;
|
|
|
|
--v_errormsg := 'Fout bepalen oudste datum';
|
|
--SELECT MIN (cnt_contract_looptijd_tot)
|
|
-- INTO v_datum
|
|
-- FROM fac_v_2purge_cnt
|
|
-- WHERE cnt_contract_looptijd_tot > TO_DATE ( '01-01-1999', 'dd-mm-yyyy');
|
|
--v_datum := TRUNC (ADD_MONTHS (v_datum, 12), 'yyyy');
|
|
|
|
SELECT TO_CHAR(MIN (cnt_contract_looptijd_tot), 'YYYY'), TO_CHAR (MAX (cnt_contract_looptijd_tot), 'YYYY')
|
|
INTO v_jaar1, v_jaar2
|
|
FROM fac_v_2purge_cnt;
|
|
DBMS_OUTPUT.put_line('Range is '||v_jaar1||'-'||v_jaar2);
|
|
|
|
-- Alle te schonen contracten(-dossiers) in 1x
|
|
FOR r IN ccnt
|
|
LOOP
|
|
BEGIN
|
|
v_errormsg := 'Error purging contract: ' || TO_CHAR (r.cnt_contract_key);
|
|
IF BITAND(iamverysure,1) = 1
|
|
THEN
|
|
cnt.remove (r.cnt_contract_key);
|
|
END IF;
|
|
IF BITAND(iamverysure,2) = 2
|
|
THEN
|
|
fac.writelog ('$PURGE$','I','Purged '||TO_CHAR(r.cnt_contract_key)||'.', '');
|
|
END IF;
|
|
v_count := v_count + 1;
|
|
|
|
-- Elke 1000 CNT een COMMIT!
|
|
IF MOD (v_count, 1000) = 0
|
|
THEN
|
|
COMMIT;
|
|
END IF;
|
|
EXCEPTION
|
|
WHEN OTHERS
|
|
THEN
|
|
v_errormsg := v_errormsg || '/'|| SUBSTR (SQLERRM, 1, 200);
|
|
fac.writelog ('$PURGE$','E', v_errormsg, 'CNT-loop');
|
|
END;
|
|
END LOOP;
|
|
|
|
v_purgeblock_end := SYSDATE;
|
|
|
|
--fac.writelog ('$PURGE$', 'S', '#Contracten purged (year=' || TO_CHAR (v_datum - 1, 'yyyy') || '): ' || TO_CHAR (v_count), TO_CHAR (ROUND ((v_purgeblock_end - v_purgeblock_start) * 24 * 60), 'FM990') || 'm');
|
|
IF v_jaar1 = v_jaar2
|
|
THEN
|
|
fac.writelog (
|
|
'$PURGE$',
|
|
'S',
|
|
'Step 5/5 #Contracten purged (year=' || v_jaar1 || '): ' || TO_CHAR (v_count, '999G999G999', 'NLS_NUMERIC_CHARACTERS = '',.'''),
|
|
TO_CHAR (ROUND ((v_purgeblock_end - v_purgeblock_start) * 24 * 60), 'FM990') || 'm');
|
|
ELSE
|
|
fac.writelog (
|
|
'$PURGE$',
|
|
'S',
|
|
'Step 5/5 #Contracten purged (years='
|
|
|| v_jaar1
|
|
|| '-'
|
|
|| v_jaar2
|
|
|| '): '
|
|
|| TO_CHAR (v_count, '999G999G999', 'NLS_NUMERIC_CHARACTERS = '',.'''),
|
|
TO_CHAR (ROUND ((v_purgeblock_end - v_purgeblock_start) * 24 * 60), 'FM990') || 'm');
|
|
END IF;
|
|
|
|
COMMIT;
|
|
DBMS_OUTPUT.put_line('Contracten done.');
|
|
|
|
-- Na afloop checken of nog restjes zijn
|
|
SELECT COALESCE(SUM (aantal),0) INTO v_count FROM fac_v_2purge_all;
|
|
fac.writelog ('$PURGE$','I','There is a grand total of '||TO_CHAR (v_count, '999G999G999', 'NLS_NUMERIC_CHARACTERS = '',.''')||' items left to purge.', '');
|
|
|
|
EXCEPTION
|
|
WHEN OTHERS
|
|
THEN
|
|
v_errormsg := v_errormsg || '/'|| SUBSTR (SQLERRM, 1, 200);
|
|
fac.writelog ('$PURGE$','E', 'Purge aborted!', v_errormsg);
|
|
COMMIT;
|
|
END;
|
|
END del;
|
|
/ |