From 9d4c39ac22f639b9857c16fc20b8898e42300292 Mon Sep 17 00:00:00 2001 From: Sander Schepers Date: Tue, 6 Feb 2024 09:55:10 +0000 Subject: [PATCH] GDZW#79271 SSO via AzureAD (SCIM) svn path=/Customer/trunk/; revision=63473 --- GDZW/gdzw.sql | 100 ++++++++++++++++++++++++++++++++++++++++++++++++++ 1 file changed, 100 insertions(+) diff --git a/GDZW/gdzw.sql b/GDZW/gdzw.sql index b0cf596af..50d0ebf31 100644 --- a/GDZW/gdzw.sql +++ b/GDZW/gdzw.sql @@ -1885,7 +1885,107 @@ EXCEPTION || ')'); END; / + +CREATE OR REPLACE PACKAGE GDZW +AS + PROCEDURE schonen_accounts; +END; +/ +CREATE OR REPLACE PACKAGE BODY GDZW +AS + -- Verwijder via SCIM geinactiveerde personen! + PROCEDURE schonen_accounts + AS + c_prs_dummy_key NUMBER (10) := -1; -- DUMMY tbv overzetten verplichtingen verwijderde personen + v_errormsg VARCHAR2 (1000); + oracle_err_num NUMBER; + oracle_err_mes VARCHAR2 (200); + v_count_del NUMBER (10); + + CURSOR c1 + IS + SELECT '[' || TO_CHAR (p.prs_perslid_key) || '|' || p.prs_perslid_email || '|' || pf.prs_perslid_naam_full || '] ' + aanduiding, + p.prs_perslid_key, + COUNT (vp.prs_perslid_key) aant + FROM prs_v_aanwezigperslid p, prs_v_verplichting_keys vp, prs_v_perslid_fullnames pf + WHERE p.prs_perslid_externid IS NOT NULL -- SCIM-populatie! + AND COAlESCE (p.prs_perslid_inactief, SYSDATE) < TRUNC (SYSDATE) + AND p.prs_perslid_key = vp.prs_perslid_key(+) -- Actuele verplichtingen? + AND p.prs_perslid_key = pf.prs_perslid_key + GROUP BY '[' || TO_CHAR (p.prs_perslid_key) || '|' || p.prs_perslid_email || '|' || pf.prs_perslid_naam_full || '] ', + p.prs_perslid_key + ORDER BY 2; + BEGIN + v_count_del := 0; + FOR rec IN c1 + LOOP + BEGIN + IF rec.aant = 0 + THEN + v_errormsg := 'Fout schonen collega'; + DELETE FROM prs_collega + WHERE prs_perslid_key = rec.prs_perslid_key + OR prs_perslid_key_alt = rec.prs_perslid_key; + + v_errormsg := 'Fout schonen perslid'; + + UPDATE prs_perslid + SET prs_perslid_verwijder = SYSDATE + WHERE prs_perslid_key = rec.prs_perslid_key; + + v_count_del := v_count_del + 1; + + IF MOD (v_count_del, 1000) = 0 + THEN + COMMIT; + END IF; + ELSE + fac.writelog ('GDZW_SCHONENACCOUNTS', 'I', rec.aanduiding || '/#Verplichtingen: ' || TO_CHAR (rec.aant), 'Persoon niet geschoond'); + END IF; + EXCEPTION + WHEN OTHERS + THEN -- Kennelijk heeft persoon toch nog ernstige verplichtingen! + oracle_err_num := SQLCODE; + oracle_err_mes := SUBSTR (SQLERRM, 1, 200); + v_errormsg := v_errormsg || ' ORACLE (error ' || oracle_err_num || '/' || oracle_err_mes || ')'; + fac.writelog ('GDZW_SCHONENACCOUNTS', 'W', rec.aanduiding || v_errormsg, 'Fout schonen persoon'); + END; + END LOOP; + + fac.writelog ('GDZW_SCHONENACCOUNTS', 'S', 'Personen/#geschoond: ' || TO_CHAR (v_count_del), ''); + COMMIT; + EXCEPTION + WHEN OTHERS + THEN + oracle_err_num := SQLCODE; + oracle_err_mes := SUBSTR (SQLERRM, 1, 100); + v_errormsg := v_errormsg || ' ORACLE (error ' || oracle_err_num || '/' || oracle_err_mes || ')'; + fac.writelog ('GDZW_SCHONENACCOUNTS', 'E', v_errormsg, ''); + COMMIT; + END schonen_accounts; +END; +/ + +CREATE OR REPLACE PROCEDURE GDZW_DAILY +AS + v_errormsg VARCHAR2 (1000); + oracle_err_num NUMBER; + oracle_err_mes VARCHAR2 (200); +BEGIN + gdzw.schonen_accounts; +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 GDZW_DAILY; +/ + + ------ payload end ------