-- -- $Id$ -- -- Script containing customer specific db-configuration for ALKM. DEFINE thisfile = 'ALKM.SQL' DEFINE dbuser = '^ALKM' SET ECHO ON SET DEFINE ON COLUMN fcltlogfile NEW_VALUE fcltlogfile NOPRINT; COLUMN fcltcusttxt NEW_VALUE fcltcusttxt NOPRINT; WHENEVER SQLERROR CONTINUE; SELECT adm.getscriptspoolfile('&thisfile') AS fcltlogfile FROM DUAL; SPOOL &fcltlogfile WHENEVER SQLERROR EXIT; SELECT adm.checkscriptcust('&dbuser') AS fcltcusttxt FROM DUAL; WHENEVER SQLERROR CONTINUE; --------------------------------------- PROMPT &fcltcusttxt --------------------------------------- SET DEFINE OFF ------ payload begin ------ CREATE OR REPLACE PACKAGE ALKM AS PROCEDURE schonen_accounts; END; / CREATE OR REPLACE PACKAGE BODY ALKM AS -- Verwijder via SCIM geinactiveerde personen! PROCEDURE schonen_accounts AS c_prs_dummy_key NUMBER (10) := -1; -- DUMMY tbv overzetten verplichtingen verwijderde personen --c_oud_medewerker VARCHAR2 (100) := 'Geanonimiseerd'; 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 --AND EXISTS -- (SELECT 1 -- FROM prs_v_afdeling_boom ab -- WHERE ab.prs_bedrijf_key = -1 -- AND ab.prs_afdeling_key = p.prs_afdeling_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'; --prs.delete_perslid (p_import_key, rec.prs_perslid_key); --UPDATE prs_perslid -- SET prs_perslid_naam = c_oud_medewerker, -- prs_perslid_tussenvoegsel = NULL, -- prs_perslid_voorletters = NULL, -- prs_perslid_voornaam = NULL, -- prs_perslid_initialen = NULL, -- prs_perslid_geslacht = NULL, -- prs_perslid_nr = NULL, -- prs_perslid_telefoonnr = NULL, -- prs_perslid_mobiel = NULL, -- prs_perslid_email = NULL, -- prs_perslid_oslogin = NULL, -- prs_perslid_oslogin2 = NULL, -- prs_perslid_verwijder = SYSDATE -- WHERE prs_perslid_key = rec.prs_perslid_key; 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 ('ALKM_SCHONEN', '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 ('ALKM_SCHONEN', 'W', rec.aanduiding || v_errormsg, 'Fout schonen persoon'); END; END LOOP; fac.writelog ('ALKM_SCHONEN', '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 ('ALKM_SCHONEN', 'E', v_errormsg, ''); COMMIT; END schonen_accounts; END; / CREATE OR REPLACE PROCEDURE ALKM_DAILY AS v_errormsg VARCHAR2 (1000); oracle_err_num NUMBER; oracle_err_mes VARCHAR2 (200); BEGIN alkm.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 ALKM_DAILY; / -- Bij initele uitrol één stroom: -- - OPDRACHTNOTITIE -: Toevoegen opdrachtnotitie! CREATE OR REPLACE PROCEDURE ALKM_processemail ( pfrom IN VARCHAR2, pto IN VARCHAR2, psubject IN VARCHAR2, pbody IN VARCHAR2, psessionid IN VARCHAR2, pemailkey IN NUMBER) AS c_onbekend_key NUMBER (10) := 4; -- API-user tbv. hMail-koppeling v_errormsg VARCHAR2 (1000); oracle_err_num NUMBER; oracle_err_mes VARCHAR2 (200); v_van_regel VARCHAR2 (255) := ''; v_van_email VARCHAR2 (255) := ''; v_perslid_key NUMBER (10); v_opdracht_id VARCHAR2 (255); v_opdracht_key NUMBER (10); v_typeopdr_key NUMBER (10); v_body VARCHAR2 (4000); v_folder_kkey NUMBER (10); v_count NUMBER (10); BEGIN CASE --WHEN INSTR (UPPER (pfrom), '???') > 0 AND UPPER (pto) LIKE 'OPDRACHTNOTITIE@%' WHEN UPPER (pto) LIKE 'OPDRACHTEN@%' THEN -- Probeer noteur te bepalen op basis van e-mail adres tussen '<>' na eerste voorkomen 'Van:'! v_errormsg := 'Fout bepalen noteur'; /* IF INSTR (UPPER (pbody), 'VAN:') > 0 THEN v_van_regel := TRIM (SUBSTR (pbody, INSTR (UPPER (pbody), 'VAN:') + 4, INSTR (SUBSTR (REPLACE (REPLACE (pbody, CHR (13), '#'), CHR (10), '#') || '#', INSTR (pbody, 'VAN:') + 4), '#') - 1)); IF INSTR (v_van_regel, '<') > 0 AND INSTR (v_van_regel, '<') < INSTR (v_van_regel, '>') THEN v_van_email := SUBSTR (v_van_regel, INSTR (v_van_regel, '<') + 1, INSTR (v_van_regel, '>') - INSTR (v_van_regel, '<') - 1); END IF; END IF; SELECT COUNT (*) INTO v_count FROM prs_contactpersoon WHERE prs_contactpersoon_email IS NULL AND prs_perslid_key IS NOT NULL AND UPPER (prs_contactpersoon_email) LIKE UPPER (v_van_email) || '%'; IF v_count = 1 THEN SELECT prs_perslid_key INTO v_perslid_key FROM prs_contactpersoon WHERE prs_contactpersoon_email IS NULL AND prs_perslid_key IS NOT NULL AND UPPER (prs_contactpersoon_email) LIKE UPPER (v_van_email) || '%'; ELSE -- Noteur kan niet 1-duidig worden bepaald, dus Onbekend! SELECT prs_perslid_key INTO v_perslid_key FROM prs_v_aanwezigperslid WHERE prs_perslid_key = c_onbekend_key; END IF; */ v_perslid_key := c_onbekend_key; v_errormsg := 'Fout bepalen opdracht'; v_opdracht_id := psubject; IF REGEXP_INSTR (v_opdracht_id, '\d') > 0 THEN v_opdracht_id := SUBSTR (v_opdracht_id, REGEXP_INSTR (v_opdracht_id, '\d')) || ' '; -- Gedeelte vanaf eerste cijfer in v_exist_ticket plus ' '! v_opdracht_id := SUBSTR (v_opdracht_id, 1, REGEXP_INSTR (v_opdracht_id, '\s') - 1); -- Gedeelte tot eerste white space in v_exist_ticket! END IF; v_errormsg := 'Fout bepalen opdracht ' || v_opdracht_id; SELECT mld_opdr_key, mld_typeopdr_key INTO v_opdracht_key, v_typeopdr_key FROM mld_opdr WHERE TO_CHAR (mld_melding_key) || '/' || TO_CHAR (mld_opdr_bedrijfopdr_volgnr) = SUBSTR (v_opdracht_id, REGEXP_INSTR (v_opdracht_id, '\d')); -- Body overnemen tot 1e voorkomen van hard afgesproken start DISCLAIMER! v_errormsg := 'Fout strippen disclaimer'; /* IF INSTR (UPPER (pbody), 'DISCLAIMER') > 0 AND INSTR (UPPER (pbody), 'DE INFORMATIE IN DIT BERICHT') > 0 THEN v_body := TRIM (SUBSTR (pbody, 1, INSTR (UPPER (pbody), 'DE INFORMATIE IN DIT BERICHT') - 12)); ELSE v_body := pbody; END IF; */ v_body := pbody; v_errormsg := 'Fout toevoegen opdracht-notitie'; INSERT INTO mld_opdr_note (mld_opdr_key, prs_perslid_key, mld_opdr_note_omschrijving) VALUES (v_opdracht_key, v_perslid_key, pfrom || CHR (13) || CHR (10) || psubject || CHR (13) || CHR (10) || SUBSTR (v_body, 1, 2000)); v_errormsg := 'Fout bijwerken opdracht-kleurbolletje'; UPDATE mld_opdr SET mld_opdr_flag = 1 -- Zwart WHERE mld_opdr_key = v_opdracht_key; -- Find the lowest volgnummer of the Folder-flexfield. v_errormsg := 'Fout toevoegen opdracht-bijlage'; SELECT MIN (k1.mld_kenmerk_key) INTO v_folder_kkey FROM mld_kenmerk k1, mld_srtkenmerk sk1 WHERE k1.mld_typeopdr_key = v_typeopdr_key AND k1.mld_kenmerk_verwijder IS NULL AND k1.mld_kenmerk_niveau = 'O' AND k1.mld_srtkenmerk_key = sk1.mld_srtkenmerk_key AND sk1.mld_srtkenmerk_kenmerktype = 'M' AND NOT EXISTS (SELECT 1 FROM mld_kenmerk k2, mld_srtkenmerk sk2 WHERE k2.mld_typeopdr_key = v_typeopdr_key AND k2.mld_kenmerk_verwijder IS NULL AND k2.mld_kenmerk_niveau = 'O' AND k2.mld_srtkenmerk_key = sk2.mld_srtkenmerk_key AND sk2.mld_srtkenmerk_kenmerktype = 'M' AND k2.mld_kenmerk_volgnummer < k1.mld_kenmerk_volgnummer); IF v_folder_kkey IS NOT NULL THEN INSERT INTO fac_result (fac_result_sessionid, fac_result_naam, fac_result_waarde) VALUES (psessionid, 'kenmerkpath', 'MLD\O' || TO_CHAR (TRUNC (v_opdracht_key / 1000), 'FM0000') || '___\O' || v_opdracht_key || '\' || v_folder_kkey || '\'); END IF; ELSE INSERT INTO fac_result (fac_result_sessionid, fac_result_naam, fac_result_waarde) VALUES (psessionid, 'errormsg', 'Ontvanger ongeldig - Neem contact op met uw systeembeheerder '); END CASE; EXCEPTION WHEN OTHERS THEN 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 ('PROCESSEMAIL', 'E', 'ALKM_processemail afgebroken!', '[' || v_van_email || '] ' || v_errormsg); INSERT INTO fac_result (fac_result_sessionid, fac_result_naam, fac_result_waarde) VALUES (psessionid, 'errormsg', 'Database fout - Neem contact op met uw systeembeheerder '); COMMIT; END; / ------ payload end ------ SET DEFINE OFF BEGIN adm.systrackscriptId ('$Id$', 0); END; / COMMIT; SET ECHO OFF SPOOL OFF SET DEFINE ON PROMPT Logfile of this upgrade is: &fcltlogfile