-- -- $Id$ -- -- Script containing customer specific sql statements for the Vesteda database DEFINE thisfile = 'VEST.SQL' DEFINE dbuser = '^VEST' DEFINE custid = 'VEST' SET ECHO ON SET DEFINE ON COLUMN fcltlogfile NEW_VALUE fcltlogfile NOPRINT; WHENEVER SQLERROR EXIT; SELECT adm.scriptspoolfile('&dbuser', '&thisfile') AS fcltlogfile FROM DUAL; WHENEVER SQLERROR CONTINUE; SPOOL &fcltlogfile SET DEFINE OFF ------ payload begin ------ -- -- Personen import -- CREATE OR REPLACE PROCEDURE vest_import_perslid (p_import_key IN NUMBER) AS oracle_err_num NUMBER; oracle_err_mes VARCHAR2 (200); v_errormsg VARCHAR2 (400); v_errorhint VARCHAR2 (400); v_newline FAC_IMP_FILE.FAC_IMP_FILE_LINE%TYPE; BEGIN BEGIN SELECT fac_imp_file_line INTO v_newline FROM fac_imp_file WHERE fac_import_key = p_import_key AND fac_imp_file_index = 1; IF v_newline LIKE CHR (TO_NUMBER ('EF', 'xx')) || CHR (TO_NUMBER ('BB', 'xx')) || CHR (TO_NUMBER ('BF', 'xx')) || '%' THEN -- EF BB BF aangetroffen fac.imp_writelog (p_import_key, 'W', 'Byte Order Mark aangetroffen', 'Bestand heeft onbehandeld UTF-8 formaat.' ); v_newline := SUBSTR (v_newline, 4); END IF; -- Verwijder de dubbele quotes v_newline := REPLACE (v_newline, '"'); UPDATE fac_imp_file SET fac_imp_file_line = v_newline WHERE fac_import_key = p_import_key AND fac_imp_file_index = 1; EXCEPTION WHEN OTHERS THEN fac.imp_writelog (p_import_key, 'E', 'Fout bij controle op Byte Order Mark', '' ); END; v_errorhint := 'Generieke update'; -- de sequence array staat beschreven in PRS_PAC.SRC bij de prs.import_perslid proc prs.import_perslid (p_import_key, '13;14;15;16;0;0;6;1;3;2;' || '0;0;0;0;9;10;11;5;0;12;' || '7;4;0;8;0;0;0;0;0;0;'|| '0;0;0;0;0;0;0;0;0;0;'|| '0;0;0;0;0;0', 'Achternaam;Voornaam;Tussenvoegsel;SamAccountName;Email;Afdeling;Functie;Titel/Aanhef;Geslacht;Telefoonnummer;Mobiel nummer;Personeelsnummer;Locatie;Gebouw;Verdieping;Ruimte%' ); UPDATE fac_imp_perslid SET alg_locatie_code = ( SELECT a.alg_locatie_code FROM alg_locatie a WHERE fac_imp_perslid.alg_locatie_code = a.alg_locatie_omschrijving); UPDATE fac_imp_perslid SET prs_afdeling_naam = ( SELECT p.prs_afdeling_naam FROM prs_afdeling p WHERE fac_imp_perslid.prs_afdeling_naam = substr (p.prs_afdeling_omschrijving, 1, 15)) WHERE fac_imp_perslid.prs_afdeling_naam NOT IN (SELECT p.prs_afdeling_naam FROM prs_afdeling p); DELETE FROM fac_imp_perslid WHERE alg_locatie_code NOT IN (SELECT alg_locatie_code FROM alg_locatie); COMMIT; EXCEPTION WHEN OTHERS THEN oracle_err_num := SQLCODE; oracle_err_mes := SUBSTR (SQLERRM, 1, 100); v_errormsg := 'Error ' || oracle_err_num || '/' || oracle_err_mes; fac.imp_writelog (p_import_key, 'E', v_errormsg, v_errorhint); END vest_import_perslid; / CREATE OR REPLACE PROCEDURE vest_update_perslid ( p_import_key IN NUMBER ) IS -- Alle personen verwijderen die niet meer in import bestand voorkomen. CURSOR c_del IS SELECT p.prs_perslid_key, p.prs_perslid_oslogin, pf.prs_perslid_naam_full FROM fac_imp_perslid i, prs_perslid p, prs_v_perslid_fullnames_all pf WHERE p.prs_perslid_oslogin = i.prs_perslid_oslogin(+) AND pf.prs_perslid_key = p.prs_perslid_key AND p.prs_perslid_oslogin IS NOT NULL AND i.prs_perslid_oslogin IS NULL AND p.prs_perslid_verwijder IS NULL AND substr (p.prs_perslid_oslogin, 1, 1) != '_' ORDER BY 2; v_count NUMBER; BEGIN -- generic update SELECT count(*) INTO v_count FROM fac_imp_perslid; IF v_count < 150 THEN fac.imp_writelog (p_import_key, 'E', 'Het aantal te importeren personen is te klein (' || TO_CHAR (v_count) || ')', 'Zie Specificatie' ); RETURN; END IF; -- 'LOGIN' betekent dat op basis van oslogin wordt gematched. -- 'A' betekent altijd alle (andere/overige) werkplekken verwijderen prs.update_perslid (p_import_key, 'LOGIN', NULL); -- Verwijder personen die niet meer in de import voorkomen. FOR rec IN c_del LOOP BEGIN prs.delete_perslid (p_import_key, rec.prs_perslid_key); END; END LOOP; END vest_update_perslid; / ------ 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