CVGZ#76333 -- Anonimisering medewerkergegevens op dagelijkse basis
svn path=/Customer/trunk/; revision=59878
This commit is contained in:
141
AA/CVGZ/cvgz.sql
141
AA/CVGZ/cvgz.sql
@@ -31,6 +31,12 @@ AS
|
||||
|
||||
PROCEDURE update_organisatie (p_import_key IN NUMBER);
|
||||
|
||||
PROCEDURE anonimiseer_prs;
|
||||
|
||||
PROCEDURE anonimiseer_bezoeker;
|
||||
|
||||
PROCEDURE anonimiseer_mld;
|
||||
|
||||
END;
|
||||
/
|
||||
|
||||
@@ -428,13 +434,118 @@ AS
|
||||
|
||||
END;
|
||||
|
||||
PROCEDURE anonimiseer_prs
|
||||
AS
|
||||
v_van DATE;
|
||||
v_tot DATE;
|
||||
BEGIN
|
||||
-- Als een persoon minimaal een jaar geleden verwijderd is anonimiseren we de gegevens
|
||||
SELECT datum_van
|
||||
INTO v_van
|
||||
FROM (SELECT MIN (p.prs_perslid_verwijder) datum_van
|
||||
FROM prs_perslid p, fac_setting s
|
||||
WHERE s.fac_setting_key = 1041
|
||||
AND p.prs_perslid_verwijder <
|
||||
TRUNC (SYSDATE)
|
||||
- COALESCE (s.fac_setting_pvalue,
|
||||
s.fac_setting_default));
|
||||
|
||||
SELECT TRUNC (
|
||||
SYSDATE
|
||||
- COALESCE (s.fac_setting_pvalue, s.fac_setting_default))
|
||||
INTO v_tot
|
||||
FROM fac_setting s
|
||||
WHERE s.fac_setting_key = 1041;
|
||||
|
||||
IF v_van IS NOT NULL
|
||||
THEN
|
||||
ano.anonymizeprs (v_van, v_tot);
|
||||
END IF;
|
||||
|
||||
END;
|
||||
|
||||
PROCEDURE anonimiseer_mld
|
||||
AS
|
||||
v_van DATE;
|
||||
v_tot DATE;
|
||||
BEGIN
|
||||
SELECT datum_van
|
||||
INTO v_van
|
||||
FROM (SELECT MIN (TRUNC (m.mld_melding_einddatum)) datum_van
|
||||
FROM fac_setting s, mld_melding m
|
||||
WHERE m.mld_melding_status IN (1, 5, 6) -- melding is afgewezen, afgemeld of historisch
|
||||
AND s.fac_setting_key = 1041
|
||||
AND m.mld_melding_einddatum <
|
||||
( TRUNC (SYSDATE)
|
||||
- COALESCE (s.fac_setting_pvalue,
|
||||
s.fac_setting_default)) -- de melding was gereed voor de anonimiseer periode
|
||||
AND NOT EXISTS --- nog niet geanonimiseerd
|
||||
(SELECT ft.fac_tracking_key
|
||||
FROM fac_tracking ft
|
||||
WHERE ft.fac_tracking_refkey =
|
||||
m.mld_melding_key
|
||||
AND ft.fac_srtnotificatie_key =
|
||||
(SELECT fac_srtnotificatie_key
|
||||
FROM fac_srtnotificatie
|
||||
WHERE fac_srtnotificatie_code =
|
||||
'MLDANO')));
|
||||
|
||||
SELECT TRUNC (
|
||||
SYSDATE
|
||||
- COALESCE (s.fac_setting_pvalue, s.fac_setting_default))
|
||||
INTO v_tot
|
||||
FROM fac_setting s
|
||||
WHERE s.fac_setting_key = 1041;
|
||||
|
||||
IF v_van IS NOT NULL
|
||||
THEN
|
||||
ano.anonymizemld (v_van, v_tot);
|
||||
END IF;
|
||||
|
||||
END;
|
||||
|
||||
PROCEDURE anonimiseer_bezoeker
|
||||
AS
|
||||
v_van DATE;
|
||||
v_tot DATE;
|
||||
BEGIN
|
||||
SELECT datum_van
|
||||
INTO v_van
|
||||
FROM (SELECT MIN (TRUNC (a.bez_afspraak_datum)) datum_van
|
||||
FROM fac_setting s, bez_afspraak a
|
||||
WHERE s.fac_setting_key = 1041
|
||||
AND a.bez_afspraak_datum <
|
||||
( TRUNC (SYSDATE)
|
||||
- COALESCE (s.fac_setting_pvalue,
|
||||
s.fac_setting_default)) -- de afspraak vindt plaats voor de anonimiseer periode
|
||||
AND NOT EXISTS --- nog niet geanonimiseerd
|
||||
(SELECT ft.fac_tracking_key
|
||||
FROM fac_tracking ft
|
||||
WHERE ft.fac_tracking_refkey =
|
||||
a.bez_afspraak_key
|
||||
AND ft.fac_srtnotificatie_key =
|
||||
(SELECT fac_srtnotificatie_key
|
||||
FROM fac_srtnotificatie
|
||||
WHERE fac_srtnotificatie_code =
|
||||
'BEZANO')));
|
||||
|
||||
SELECT TRUNC (
|
||||
SYSDATE
|
||||
- COALESCE (s.fac_setting_pvalue, s.fac_setting_default))
|
||||
INTO v_tot
|
||||
FROM fac_setting s
|
||||
WHERE s.fac_setting_key = 1041;
|
||||
|
||||
IF v_van IS NOT NULL
|
||||
THEN
|
||||
ano.anonymizebez (v_van, v_tot);
|
||||
END IF;
|
||||
|
||||
END;
|
||||
|
||||
END;
|
||||
/
|
||||
|
||||
|
||||
-- Organisatie import
|
||||
-- Aangeleverde structuur en mapping
|
||||
-- Bedrijfsnaam --> wordt niet gebruikt
|
||||
@@ -1174,6 +1285,34 @@ AS
|
||||
FROM bez_bezoekers b, bez_afspraak a
|
||||
WHERE b.bez_afspraak_key = a.bez_afspraak_key;
|
||||
|
||||
|
||||
--de daily task draait elke ochtend om 5 uur.
|
||||
CREATE OR REPLACE PROCEDURE cvgz_daily
|
||||
AS
|
||||
v_errormsg VARCHAR2 (1000);
|
||||
oracle_err_num NUMBER;
|
||||
oracle_err_mes VARCHAR2 (200);
|
||||
BEGIN
|
||||
|
||||
-- anonimiseer personen
|
||||
cvgz.anonimiseer_prs ();
|
||||
|
||||
-- anonimiseer bezoekers
|
||||
cvgz.anonimiseer_bezoeker ();
|
||||
|
||||
-- anonimiseer meldingen
|
||||
cvgz.anonimiseer_mld ();
|
||||
|
||||
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 ('DAILY', 'E', 'Proces afgebroken!', v_errormsg);
|
||||
END cvgz_daily;
|
||||
/
|
||||
|
||||
------ payload end ------
|
||||
|
||||
SET DEFINE OFF
|
||||
|
||||
Reference in New Issue
Block a user