307 lines
11 KiB
SQL
307 lines
11 KiB
SQL
/* Anonymizer for Facilitor P-ATO (reverse OTAP) chain
|
|
*
|
|
* $Revision$
|
|
* $Id$
|
|
*
|
|
* Gradually improve over time, please
|
|
*/
|
|
|
|
column afcltlogfile new_value afcltlogfile NOPRINT;
|
|
select 'ANONYMIZED_' || UPPER(USER || '_' || sys_context('USERENV', 'SERVICE_NAME') || '_' || sys_context('USERENV', 'SERVER_HOST')) || '_' || to_char(sysdate,'YYYYMMDD_HH24MISS') || '.lst' as afcltlogfile from dual;
|
|
spool &afcltlogfile
|
|
|
|
SET FEEDBACK ON
|
|
SET ECHO ON
|
|
SET TIME ON
|
|
|
|
-- We draaien vaak vlak na een import, mooi moment om alles valid te maken
|
|
BEGIN
|
|
DBMS_UTILITY.COMPILE_SCHEMA(USER, FALSE);
|
|
END;
|
|
/
|
|
|
|
-- Destructive obstrufication of personal data.
|
|
UPDATE prs_perslid
|
|
SET prs_perslid_naam =
|
|
INITCAP (DBMS_RANDOM.string ('l', LENGTH (prs_perslid_naam)))
|
|
WHERE prs_perslid_naam NOT LIKE 'INACTIEF:%'
|
|
AND prs_perslid_naam NOT LIKE 'Facilitor'
|
|
AND (prs_perslid_oslogin IS NULL OR SUBSTR(prs_perslid_oslogin, 1, 1) <> '_');
|
|
|
|
UPDATE prs_perslid
|
|
SET prs_perslid_voornaam =
|
|
INITCAP (DBMS_RANDOM.string ('l', LENGTH (prs_perslid_voornaam)))
|
|
WHERE prs_perslid_voornaam IS NOT NULL
|
|
AND (prs_perslid_oslogin IS NULL OR SUBSTR(prs_perslid_oslogin, 1, 1) <> '_');
|
|
|
|
UPDATE prs_perslid
|
|
SET prs_perslid_voorletters =
|
|
UPPER (DBMS_RANDOM.string ('l', LENGTH (prs_perslid_voorletters)))
|
|
WHERE prs_perslid_voorletters IS NOT NULL;
|
|
|
|
UPDATE prs_perslid
|
|
SET prs_perslid_naam =
|
|
'INACTIEF:'
|
|
|| INITCAP (
|
|
DBMS_RANDOM.string ('l', LENGTH (prs_perslid_naam) - 9))
|
|
WHERE prs_perslid_naam LIKE 'INACTIEF:%';
|
|
|
|
UPDATE prs_perslid SET prs_perslid_email='E'||TO_CHAR(prs_perslid_key)||'@facilitor.nl'
|
|
WHERE prs_perslid_email IS NOT NULL;
|
|
|
|
UPDATE prs_perslid SET prs_perslid_oslogin2='O'||TO_CHAR(prs_perslid_key)
|
|
WHERE prs_perslid_oslogin2 IS NOT NULL;
|
|
|
|
UPDATE prs_perslid SET prs_perslid_wachtwoord_hash = null;
|
|
|
|
UPDATE prs_perslid SET prs_perslid_apikey = 'TEST_' || DBMS_RANDOM.string('a', 10)
|
|
WHERE prs_perslid_apikey IS NOT NULL;
|
|
|
|
DELETE FROM fac_imp_perslid;
|
|
|
|
UPDATE prs_contactpersoon
|
|
SET prs_contactpersoon_naam = INITCAP (DBMS_RANDOM.string ('l', LENGTH(prs_contactpersoon_naam)));
|
|
UPDATE prs_contactpersoon
|
|
SET prs_contactpersoon_voornaam = INITCAP (DBMS_RANDOM.string ('l', LENGTH(prs_contactpersoon_voornaam)))
|
|
WHERE prs_contactpersoon_voornaam IS NOT NULL;
|
|
UPDATE prs_contactpersoon
|
|
SET prs_contactpersoon_voorletters = SUBSTR(prs_contactpersoon_voornaam,1,1)|| SUBSTR(prs_contactpersoon_voorletters,2)
|
|
WHERE prs_contactpersoon_voorletters IS NOT NULL;
|
|
UPDATE prs_contactpersoon SET prs_contactpersoon_email='anonymous@facilitor.nl'
|
|
WHERE prs_contactpersoon_email IS NOT NULL;
|
|
|
|
ALTER TRIGGER bez_t_bez_afspraak_B_IU DISABLE;
|
|
UPDATE bez_afspraak
|
|
SET bez_afspraak_gastheer = (SELECT SUBSTR(prs_perslid_naam_full,1,50) FROM prs_v_perslid_fullnames_all WHERE prs_perslid_key=bez_afspraak_host_key)
|
|
WHERE bez_afspraak_host_key IS NOT NULL;
|
|
|
|
UPDATE bez_afspraak
|
|
SET bez_afspraak_gastheer = INITCAP (DBMS_RANDOM.string ('l', LENGTH (bez_afspraak_gastheer)))
|
|
WHERE bez_afspraak_host_key IS NULL;
|
|
ALTER TRIGGER bez_t_bez_afspraak_B_IU ENABLE;
|
|
|
|
UPDATE bez_bezoekers
|
|
SET bez_afspraak_naam = UPPER(SUBSTR(bez_afspraak_naam,1,1))||'. Bezoeker'
|
|
WHERE bez_afspraak_naam IS NOT NULL
|
|
AND bez_afspraak_naam <> 'Anoniem';
|
|
|
|
UPDATE bez_bezoekers
|
|
SET bez_afspraak_bedrijf = UPPER(SUBSTR(bez_afspraak_bedrijf,1,1))||'areon B.V.'
|
|
WHERE bez_afspraak_bedrijf IS NOT NULL
|
|
AND bez_afspraak_bedrijf <> 'Anoniem';
|
|
|
|
CREATE OR REPLACE PACKAGE anoniem
|
|
AS
|
|
FUNCTION postcode(postcode_veld IN VARCHAR2) RETURN VARCHAR2;
|
|
FUNCTION telefoon(telefoon_veld IN VARCHAR2) RETURN VARCHAR2;
|
|
FUNCTION adres(adres_veld IN VARCHAR2) RETURN VARCHAR2;
|
|
FUNCTION naam(naam_veld IN VARCHAR2) RETURN VARCHAR2;
|
|
FUNCTION email(email_veld IN VARCHAR2) RETURN VARCHAR2;
|
|
FUNCTION memo(memo_veld IN VARCHAR2) RETURN VARCHAR2;
|
|
END anoniem;
|
|
/
|
|
|
|
CREATE OR REPLACE PACKAGE BODY anoniem
|
|
AS
|
|
FUNCTION postcode(postcode_veld IN VARCHAR2) RETURN VARCHAR2
|
|
IS
|
|
c VARCHAR2(1);
|
|
code VARCHAR2(15) := '';
|
|
BEGIN
|
|
IF (postcode_veld IS NOT NULL)
|
|
THEN
|
|
FOR i IN 1..LENGTH(SUBSTR(postcode_veld,1,15))
|
|
LOOP
|
|
c := SUBSTR(postcode_veld,i,1);
|
|
BEGIN
|
|
c := TO_CHAR(TO_NUMBER(c));
|
|
c := TO_CHAR(TRUNC(DBMS_RANDOM.value(0,10)));
|
|
EXCEPTION
|
|
WHEN VALUE_ERROR THEN
|
|
IF (c NOT IN (' ','-')) THEN
|
|
c := DBMS_RANDOM.string('u',1);
|
|
END IF;
|
|
END;
|
|
code := code||c;
|
|
END LOOP;
|
|
END IF;
|
|
RETURN code;
|
|
END postcode;
|
|
|
|
FUNCTION telefoon(telefoon_veld IN VARCHAR2) RETURN VARCHAR2
|
|
IS
|
|
n NUMBER;
|
|
r NUMBER;
|
|
i NUMBER;
|
|
f VARCHAR2(5) := '+-_ *'; -- alleen deze laten we staan
|
|
tel VARCHAR2(30) := '';
|
|
c VARCHAR2(1);
|
|
BEGIN
|
|
IF (telefoon_veld IS NOT NULL)
|
|
THEN
|
|
n := DBMS_RANDOM.value(0,1);
|
|
tel := TO_CHAR(TRUNC(n * POWER(10,LENGTH(telefoon_veld))));
|
|
FOR r IN 0..3
|
|
LOOP
|
|
c := SUBSTR(f,r,1);
|
|
i := 1;
|
|
WHILE (INSTR(telefoon_veld, c, 1, i) > 0)
|
|
LOOP
|
|
tel := REGEXP_REPLACE(tel
|
|
,'(^.{'||(INSTR(telefoon_veld,c,1,i)-1)||'})(.{1})(.*)$'
|
|
,'\1'||c||'\3'
|
|
);
|
|
i := i + 1;
|
|
END LOOP;
|
|
END LOOP;
|
|
END IF;
|
|
RETURN tel;
|
|
END telefoon;
|
|
|
|
FUNCTION adres(adres_veld IN VARCHAR2) RETURN VARCHAR2
|
|
IS
|
|
c VARCHAR2(1);
|
|
adres VARCHAR2(100) := '';
|
|
BEGIN
|
|
IF (adres_veld IS NOT NULL)
|
|
THEN
|
|
FOR i IN 1..LENGTH(adres_veld)
|
|
LOOP
|
|
c := SUBSTR(adres_veld,i,1);
|
|
BEGIN
|
|
c := TO_CHAR(TO_NUMBER(c));
|
|
EXCEPTION
|
|
WHEN VALUE_ERROR THEN
|
|
IF (c <> ' ') THEN
|
|
c := DBMS_RANDOM.string('l',1);
|
|
END IF;
|
|
END;
|
|
adres := adres||c;
|
|
END LOOP;
|
|
END IF;
|
|
RETURN INITCAP(adres);
|
|
END adres;
|
|
|
|
FUNCTION email(email_veld IN VARCHAR2) RETURN VARCHAR2
|
|
IS
|
|
s NUMBER;
|
|
c VARCHAR2(1);
|
|
p VARCHAR2(9) := '';
|
|
z VARCHAR2(3) := '';
|
|
email VARCHAR2(500) := '';
|
|
BEGIN
|
|
IF (email_veld IS NOT NULL)
|
|
THEN
|
|
s := 1+INSTR(email_veld,':',1);
|
|
IF (s > 1)
|
|
THEN
|
|
p := SUBSTR(email_veld,1,s-1);
|
|
IF (SUBSTR(email_veld,s,2) = '//')
|
|
THEN
|
|
s := s+2;
|
|
p := p||'//';
|
|
END IF;
|
|
END IF;
|
|
IF (SUBSTR(email_veld,LENGTH(email_veld)-2,1) = '.') THEN
|
|
z := SUBSTR(email_veld, -3);
|
|
END IF;
|
|
FOR i IN s..(LENGTH(email_veld)-NVL(LENGTH(z),0))
|
|
LOOP
|
|
c := SUBSTR(email_veld,i,1);
|
|
IF (c NOT IN ('.','@')) THEN
|
|
c := DBMS_RANDOM.string('l',1);
|
|
END IF;
|
|
email := email||c;
|
|
END LOOP;
|
|
email := p||email||z;
|
|
END IF;
|
|
RETURN email;
|
|
END email;
|
|
|
|
FUNCTION naam(naam_veld IN VARCHAR2) RETURN VARCHAR2
|
|
IS
|
|
a NUMBER;
|
|
i VARCHAR2(1);
|
|
v VARCHAR2(55) := '';
|
|
naam VARCHAR2(200) := '';
|
|
BEGIN
|
|
IF (naam_veld IS NOT NULL)
|
|
THEN
|
|
a := LENGTH(naam_veld)-1;
|
|
IF (SUBSTR(naam_veld,LENGTH(naam_veld),1) = ')' AND INSTR(naam_veld,'(',-1) > 0) THEN
|
|
v := DBMS_RANDOM.string('l',LENGTH(naam_veld) - INSTR(naam_veld,'(',-1) -1);
|
|
v := ' ('||SUBSTR(v,1,50)||')';
|
|
a := LENGTH(naam_veld) - LENGTH(v) -1;
|
|
END IF;
|
|
i := SUBSTR(naam_veld,1,1);
|
|
naam := UPPER(i)||DBMS_RANDOM.string('l', a)||v;
|
|
END IF;
|
|
RETURN naam;
|
|
END naam;
|
|
|
|
FUNCTION memo(memo_veld IN VARCHAR2) RETURN VARCHAR2
|
|
IS
|
|
memo VARCHAR2(4000) := '';
|
|
c VARCHAR2(1) := '';
|
|
r VARCHAR2(1);
|
|
BEGIN
|
|
IF (memo_veld IS NOT NULL)
|
|
THEN
|
|
FOR i IN 1..LENGTH(memo_veld)
|
|
LOOP
|
|
r := SUBSTR(memo_veld,i,1);
|
|
IF (r NOT IN (' ','.') )
|
|
THEN
|
|
c := DBMS_RANDOM.string('l',1);
|
|
IF (r = UPPER(r))
|
|
THEN
|
|
c := UPPER(c);
|
|
END IF;
|
|
ELSE
|
|
c := r;
|
|
END IF;
|
|
memo := memo||c;
|
|
END LOOP;
|
|
END IF;
|
|
RETURN memo;
|
|
END memo;
|
|
END anoniem;
|
|
/
|
|
|
|
UPDATE prs_bedrijf
|
|
SET prs_bedrijf_naam = anoniem.naam(prs_bedrijf_naam)
|
|
, prs_bedrijf_post_adres = anoniem.adres(prs_bedrijf_post_adres)
|
|
, prs_bedrijf_post_postcode = anoniem.postcode(prs_bedrijf_post_postcode)
|
|
, prs_bedrijf_bezoek_adres = anoniem.adres(prs_bedrijf_bezoek_adres)
|
|
, prs_bedrijf_bezoek_postcode = anoniem.postcode(prs_bedrijf_bezoek_postcode)
|
|
, prs_bedrijf_telefoon = anoniem.telefoon(prs_bedrijf_telefoon)
|
|
, prs_bedrijf_telefoon2 = anoniem.telefoon(prs_bedrijf_telefoon2)
|
|
, prs_bedrijf_fax = anoniem.telefoon(prs_bedrijf_fax)
|
|
, prs_bedrijf_email = anoniem.email(prs_bedrijf_email)
|
|
, prs_bedrijf_contact_persoon = anoniem.naam(prs_bedrijf_contact_persoon)
|
|
, prs_bedrijf_contact_telefoon = anoniem.telefoon(prs_bedrijf_contact_telefoon)
|
|
, prs_bedrijf_contact_fax = anoniem.telefoon(prs_bedrijf_contact_fax);
|
|
|
|
UPDATE prs_bedrijfadres
|
|
SET prs_bedrijfadres_url = anoniem.email(prs_bedrijfadres_url)
|
|
, prs_bedrijfadres_username = anoniem.naam(prs_bedrijfadres_username)
|
|
, prs_bedrijfadres_password = NULL;
|
|
|
|
DROP PACKAGE anoniem;
|
|
|
|
UPDATE aut_idp
|
|
SET aut_idp_secret = 'TEST_' || DBMS_RANDOM.string('a', 10)
|
|
WHERE aut_idp_secret IS NOT NULL
|
|
AND aut_idp_internal = 0;
|
|
|
|
UPDATE aut_sp
|
|
SET aut_sp_secret = 'TEST_' || DBMS_RANDOM.string('a', 10)
|
|
WHERE aut_sp_secret IS NOT NULL
|
|
AND aut_sp_internal = 0;
|
|
|
|
BEGIN adm.systrackscriptid('$Id$'); END;
|
|
/
|
|
|
|
exit
|
|
SPOOL OFF
|