153 lines
5.5 KiB
SQL
153 lines
5.5 KiB
SQL
--
|
|
-- $Id$
|
|
--
|
|
-- Script containing customer specific sql statements for the FACILITOR database
|
|
-- Voor dbuser invullen: - indien script voor 1 klant is: 'AADS' (de klantcode, zoals vermeld in fac_version_cust)
|
|
-- - script is voor meerdere klanten: 'AAXX' (de groepcode, zoals vermeld in fac_version_group)
|
|
-- - script is voor meerdere klanten met naam volgens een bepaald patroon: '^AA|^ASMS|^GULU|^NMMS|^RABO|^ZKHM'
|
|
-- Ook als het script gedraaid wordt voor de verkeerde cust wordt er een logfile gemaakt.
|
|
-- (dit in tegenstelling tot sample_xxxx.sql)
|
|
|
|
DEFINE thisfile = 'LBRN.SQL'
|
|
DEFINE dbuser = 'LBRN'
|
|
|
|
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 PROCEDURE lbrn_import_contactpersoon(p_import_key IN NUMBER)
|
|
AS
|
|
oracle_err_num NUMBER;
|
|
oracle_err_mes VARCHAR2 (200);
|
|
v_errormsg VARCHAR2 (400);
|
|
v_errorhint VARCHAR2 (400);
|
|
v_count NUMBER;
|
|
BEGIN
|
|
-- de sequence array staat beschreven in FAC_PACF.SRC bij de fac_import_perslid_upd_body proc
|
|
-- ode sequence 'Afdelingscode;PersoonAchternaam;Tussenvoegsel;Voorletters;Voornaam;Titel/Aanhef;Telefoonnummer;Mobiel;Email;Functie%'
|
|
prs.import_perslid (p_import_key,
|
|
'0;0;0;0;0;0;4;1;0;2;' ||
|
|
'0;0;0;0;0;0;6;3;0;0;' ||
|
|
'5;3;0;0;0;0;4;0;0;0;'||
|
|
'0;0;0;0;0;0;0;0;0;0;'||
|
|
'0;0;0;0;0;0',
|
|
'"Surname";"GivenName";"mail";"Department";"Title"%'
|
|
);
|
|
|
|
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 lbrn_import_contactpersoon;
|
|
/
|
|
|
|
|
|
CREATE OR REPLACE PROCEDURE lbrn_update_contactpersoon( p_import_key IN NUMBER)
|
|
IS
|
|
CURSOR c_del IS
|
|
SELECT p.prs_perslid_key, p.prs_perslid_email, pf.prs_perslid_naam_full
|
|
FROM fac_imp_perslid i, prs_perslid p, prs_v_perslid_fullnames_all pf
|
|
WHERE i.prs_perslid_email(+) = p.prs_perslid_email
|
|
AND i.prs_perslid_email IS NULL
|
|
AND pf.prs_perslid_key = p.prs_perslid_key
|
|
AND p.prs_perslid_email IS NOT NULL
|
|
AND SUBSTR(COALESCE(p.prs_perslid_oslogin,'LEEG'),1,1) <> '_'
|
|
AND p.prs_perslid_verwijder IS NULL;
|
|
|
|
|
|
CURSOR c_sel IS
|
|
SELECT i.prs_perslid_email email, i.prs_kenmerk1 afdeling
|
|
FROM fac_imp_perslid i
|
|
WHERE i.fac_import_key = p_import_key;
|
|
|
|
v_count NUMBER;
|
|
v_perslid_key NUMBER;
|
|
v_bedrijf_key NUMBER;
|
|
v_groep_key NUMBER;
|
|
v_afdelingCode prs_afdeling.prs_afdeling_naam%TYPE;
|
|
oracle_err_num NUMBER;
|
|
oracle_err_mes VARCHAR2 (200);
|
|
v_errormsg VARCHAR2 (400);
|
|
v_errorhint VARCHAR2 (400);
|
|
BEGIN
|
|
-- generic update hierbij is email adres unieke sleutel , NULL geen werkplek koppeling
|
|
-- Als waardes aangevuld worden in facilitor deze eerst uit lezen en dan de imp_perslid object updaten
|
|
FOR rec in c_del
|
|
LOOP
|
|
BEGIN
|
|
v_errorhint := 'Persoon verwijderen: ' || rec.prs_perslid_naam_full || '-' || rec.prs_perslid_email;
|
|
prs.delete_perslid (p_import_key, rec.prs_perslid_key);
|
|
END;
|
|
END LOOP;
|
|
|
|
FOR rec1 IN c_sel
|
|
LOOP
|
|
BEGIN
|
|
v_afdelingCode := '';
|
|
v_errorhint :='Fout bij ophalen afdelingscode';
|
|
SELECT count(*), max(p.prs_afdeling_naam)
|
|
INTO v_count,v_afdelingCode
|
|
FROM prs_afdeling p
|
|
WHERE UPPER(p.prs_afdeling_omschrijving) like UPPER(rec1.afdeling)||'%'
|
|
AND p.prs_afdeling_verwijder IS NULL;
|
|
|
|
IF v_count=0
|
|
THEN
|
|
v_afdelingCode :='Onbekend';
|
|
END IF;
|
|
v_errorhint :='Fout bij update van fac_imp_perslid';
|
|
UPDATE fac_imp_perslid
|
|
SET prs_afdeling_naam = v_afdelingCode, prs_kenmerk1=''
|
|
WHERE prs_perslid_email = rec1.email
|
|
AND fac_import_key = p_import_key;
|
|
|
|
END;
|
|
END LOOP;
|
|
COMMIT;
|
|
prs.update_perslid (p_import_key, 'EMAIL', NULL);
|
|
|
|
-- Evt aanpassingen die gedaan moeten worden na de updat van de personen
|
|
-- BV : Voeg toe aan autorisatie groep
|
|
|
|
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 lbrn_update_contactpersoon;
|
|
/
|
|
|
|
|
|
------ 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
|