From 8f31417f0b39852d5dcb2378105532ecd3256e01 Mon Sep 17 00:00:00 2001 From: Sander Schepers Date: Tue, 10 Dec 2024 15:30:29 +0000 Subject: [PATCH] AREO#86602 De procedure prs.delete_perslid lijkt is volgens mij niet geschikt om zo te gebruiken zonder import_key. Daarom is de procedure nu aangepast. Bij geen verplichtingen wordt het account direct verwijderd. Bij verplichtingen wordt het inactief gezt. svn path=/Customer/trunk/; revision=67356 --- AREO/areo.sql | 110 +++++++++++++++++++++++++++++++++++++++++--------- 1 file changed, 92 insertions(+), 18 deletions(-) diff --git a/AREO/areo.sql b/AREO/areo.sql index 471458100..ddc9f171a 100644 --- a/AREO/areo.sql +++ b/AREO/areo.sql @@ -194,37 +194,111 @@ CREATE OR REPLACE PACKAGE BODY AREO AS PROCEDURE inactivate_prs AS - v_errormsg VARCHAR2 (1000); - v_errorhint VARCHAR2 (1000); - oracle_err_num NUMBER; - oracle_err_mes VARCHAR2 (200); - v_count NUMBER (10); - v_perslid_naam VARCHAR (100); - v_perslid_nr VARCHAR (30); + v_errormsg VARCHAR2 (1000); + oracle_err_num NUMBER; + oracle_err_mes VARCHAR2 (200); + v_count_del NUMBER (10); + v_count_inactive NUMBER (10); - --- Als een persoon 12 maanden niet meer heeft ingelogd, dan verwijderen we deze - CURSOR prs_del IS + CURSOR c1 IS SELECT p.prs_perslid_key, p.prs_perslid_oslogin, - p.prs_perslid_email, - prs_perslid_login - FROM prs_v_aanwezigperslid p - WHERE p.prs_perslid_login < - TRUNC (ADD_MONTHS (SYSDATE, -12), 'mm') + p.prs_perslid_email email, + prs_perslid_login, + COUNT (vp.prs_perslid_key) aant + FROM prs_v_aanwezigperslid p, prs_v_verplichting_keys vp + WHERE p.prs_perslid_login < + TRUNC (ADD_MONTHS (SYSDATE, -12), 'mm') + AND p.prs_perslid_key = vp.prs_perslid_key(+) GROUP BY p.prs_perslid_key, p.prs_perslid_oslogin, p.prs_perslid_email, prs_perslid_login; BEGIN - -- Proberen de accounts te verwijderen - FOR rec IN prs_del + v_count_del := 0; + v_count_inactive := 0; + + FOR rec IN c1 LOOP - prs.delete_perslid (NULL, rec.prs_perslid_key); + BEGIN + IF rec.aant = 0 + THEN + v_errormsg := 'Error clean up colleague'; + + DELETE FROM + prs_collega + WHERE prs_perslid_key = rec.prs_perslid_key + OR prs_perslid_key_alt = rec.prs_perslid_key; + + v_errormsg := 'Error delete account'; + + UPDATE prs_perslid + SET prs_perslid_verwijder = SYSDATE + WHERE prs_perslid_key = rec.prs_perslid_key; + + v_count_del := v_count_del + 1; + ELSE + v_errormsg := 'Error inactive colleague'; + + DELETE FROM + prs_collega + WHERE prs_perslid_key = rec.prs_perslid_key + OR prs_perslid_key_alt = rec.prs_perslid_key; + + v_errormsg := 'Error inactive account'; + + UPDATE prs_perslid + SET prs_perslid_inactief = SYSDATE + WHERE prs_perslid_key = rec.prs_perslid_key; + + v_count_inactive := v_count_inactive + 1; + 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 ('AREO_CLEANACCOUNTS', + 'W', + rec.email || v_errormsg, + 'error cleaning accounts'); + END; END LOOP; - END; + + fac.writelog ('AREO_CLEANACCOUNTS', + 'S', + 'Persons/#deleted: ' || 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 ('AREO_CLEANACCOUNTS', + 'E', + v_errormsg, + ''); + COMMIT; + END inactivate_prs; END; / + CREATE OR REPLACE PROCEDURE AREO_DAILY AS v_errormsg VARCHAR2 (1000);