VBGO#65673 Implementatie/uitrol VBGO
svn path=/Customer/trunk/; revision=51168
This commit is contained in:
269
VBGO/vbgo.sql
Normal file
269
VBGO/vbgo.sql
Normal file
@@ -0,0 +1,269 @@
|
||||
--
|
||||
-- $Id$
|
||||
--
|
||||
-- Script containing customer specific db-configuration for VBGO.
|
||||
DEFINE thisfile = 'VBGO.SQL'
|
||||
DEFINE dbuser = '^VBGO'
|
||||
|
||||
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 ------
|
||||
|
||||
-- Koppeling om persoonsgegevens in te lezen vanuit AD(?) van Yask.
|
||||
CREATE OR REPLACE PROCEDURE vbgo_import_prs (p_import_key IN NUMBER)
|
||||
AS
|
||||
v_errormsg VARCHAR2 (1000) := '-';
|
||||
oracle_err_num NUMBER;
|
||||
oracle_err_mes VARCHAR2 (200);
|
||||
BEGIN
|
||||
-- v_alg_locatie_code 1
|
||||
-- v_alg_gebouw_code 2
|
||||
-- v_alg_verdieping_volgnr 3
|
||||
-- v_alg_ruimte_nr 4
|
||||
-- v_prs_werkplek_volgnr 5
|
||||
-- v_prs_werkplek_omschrijving 6
|
||||
-- v_prs_afdeling_naam 7
|
||||
-- v_prs_perslid_naam 8
|
||||
-- v_prs_perslid_tussenvoegsel 9
|
||||
-- v_prs_perslid_voornaam 10
|
||||
-- v_prs_perslid_voorletters 11
|
||||
-- v_prs_perslid_partner_naam 12
|
||||
-- v_prs_perslid_partner_tussenv 13
|
||||
-- v_prs_naamgebruik_code 14
|
||||
-- v_prs_perslid_geslacht 15
|
||||
-- v_prs_perslid_telefoonnr 16
|
||||
-- v_prs_perslid_mobiel 17
|
||||
-- v_prs_perslid_email 18
|
||||
-- v_prs_perslid_dienstverband 19
|
||||
-- v_prs_perslid_nr 20
|
||||
-- v_prs_srtperslid_omschrijving 21
|
||||
-- v_prs_perslid_oslogin 22
|
||||
-- v_prs_perslid_wachtwoord 23
|
||||
-- v_prs_perslid_titel 24
|
||||
-- v_prs_perslid_apikey 25
|
||||
-- v_dummy 26
|
||||
-- v_prs_kenmerk1 27
|
||||
-- v_prs_kenmerk2 28
|
||||
-- v_prs_kenmerk3 29
|
||||
-- v_prs_kenmerk4 30
|
||||
-- v_prs_kenmerk5 31
|
||||
-- v_prs_kenmerk6 32
|
||||
-- v_prs_kenmerk7 33
|
||||
-- v_prs_kenmerk8 34
|
||||
-- v_prs_kenmerk9 35
|
||||
-- v_prs_kenmerk10 36
|
||||
-- v_prs_kenmerk11 37
|
||||
-- v_prs_kenmerk12 38
|
||||
-- v_prs_kenmerk13 39
|
||||
-- v_prs_kenmerk14 40
|
||||
-- v_prs_kenmerk15 41
|
||||
-- v_prs_kenmerk16 42
|
||||
-- v_prs_kenmerk17 43
|
||||
-- v_prs_kenmerk18 44
|
||||
-- v_prs_kenmerk19 45
|
||||
-- v_prs_kenmerk20 46
|
||||
-- Voeg een lege regel toe anders wordt de eerste persoon geskipped.
|
||||
--INSERT INTO fac_imp_file (fac_imp_file_line, fac_imp_file_index, fac_import_key)
|
||||
-- VALUES ('Header', 0, p_import_key);
|
||||
|
||||
-- Afdeling-kolom kopieren naar extra kolom 11 (= kenmerk4)!
|
||||
UPDATE fac_imp_file i
|
||||
SET i.fac_imp_file_line =
|
||||
SUBSTR (fac_imp_file_line, 1, INSTR (fac_imp_file_line || ';', ';', 1, 10))
|
||||
|| ';'
|
||||
|| SUBSTR (fac_imp_file_line, INSTR (fac_imp_file_line, ';', 1, 3)
|
||||
+ 1, INSTR (fac_imp_file_line, ';', 1, 4)
|
||||
- INSTR (fac_imp_file_line, ';', 1, 3)
|
||||
- 1)
|
||||
WHERE fac_import_key = p_import_key AND fac_imp_file_index > 1;
|
||||
|
||||
-- Afdeling-kolom resetten (op 'XXX' want verplicht)!
|
||||
UPDATE fac_imp_file i
|
||||
SET i.fac_imp_file_line =
|
||||
SUBSTR (fac_imp_file_line, 1, INSTR (fac_imp_file_line, ';', 1, 3))
|
||||
|| 'XXX'
|
||||
|| SUBSTR (fac_imp_file_line, INSTR (fac_imp_file_line, ';', 1, 4))
|
||||
WHERE fac_import_key = p_import_key AND fac_imp_file_index > 1;
|
||||
|
||||
-- Functie-kolom kopieren naar extra kolom 12 (= kenmerk5)!
|
||||
UPDATE fac_imp_file i
|
||||
SET i.fac_imp_file_line =
|
||||
SUBSTR (fac_imp_file_line, 1, INSTR (fac_imp_file_line || ';', ';', 1, 11))
|
||||
|| ';'
|
||||
|| SUBSTR (fac_imp_file_line, INSTR (fac_imp_file_line, ';', 1, 5)
|
||||
+ 1, INSTR (fac_imp_file_line, ';', 1, 6)
|
||||
- INSTR (fac_imp_file_line, ';', 1, 5)
|
||||
- 1)
|
||||
WHERE fac_import_key = p_import_key AND fac_imp_file_index > 1;
|
||||
|
||||
-- Functie-kolom resetten (op 'Medewerker' want verplicht)!
|
||||
UPDATE fac_imp_file i
|
||||
SET i.fac_imp_file_line =
|
||||
SUBSTR (fac_imp_file_line, 1, INSTR (fac_imp_file_line, ';', 1, 5))
|
||||
|| 'Medewerker'
|
||||
|| SUBSTR (fac_imp_file_line, INSTR (fac_imp_file_line, ';', 1, 6))
|
||||
WHERE fac_import_key = p_import_key AND fac_imp_file_index > 1;
|
||||
COMMIT;
|
||||
|
||||
-- Generieke import.
|
||||
-- De sequence array staat beschreven in PRS_PAC.SRC bij de import_perslid-PROCEDURE.
|
||||
--'%UserPrincipalName;GivenName;SurName;Company;Department;Title;OfficePhone;Mobile;Mail;Maildomain%');
|
||||
prs.import_perslid (
|
||||
p_import_key,
|
||||
'0;0;0;0;0;0;4;3;0;2;'
|
||||
|| '0;0;0;0;0;7;8;9;0;0;'
|
||||
|| '6;0;0;0;0;0;1;5;10;11;'
|
||||
|| '12;0;0;0;0;0;0;0;0;0;'
|
||||
|| '0;0;0;0;0;0',
|
||||
'%UserPrincipalName;GivenName;SurName;Company;Department;Title;OfficePhone;Mobile;Mail;Maildomain%');
|
||||
|
||||
-- Klantspecifieke aanpassingen.
|
||||
-- Loginnaam-kolom volgens kenmerk1 gedeelte voor '@'!
|
||||
UPDATE fac_imp_perslid i
|
||||
SET i.prs_perslid_oslogin = SUBSTR (i.prs_kenmerk1, 1, INSTR (i.prs_kenmerk1, '@') - 1);
|
||||
|
||||
-- Afdeling-kolom bepalen via Company-kolom (in kenmerk4) -> ET (key=141) -> Afdeling-1!
|
||||
UPDATE fac_imp_perslid i
|
||||
SET i.prs_afdeling_naam =
|
||||
(SELECT MAX (a.prs_afdeling_upper)
|
||||
FROM fac_v_aanwezigusrdata ud, -- Mapping AD-Company -> Afdeling-1
|
||||
prs_afdeling a
|
||||
WHERE ud.fac_usrtab_key = 141 -- AD2Afdeling
|
||||
AND UPPER (ud.fac_usrdata_code) = UPPER (i.prs_kenmerk4)
|
||||
AND UPPER (ud.fac_usrdata_omschr) = UPPER (a.prs_afdeling_naam)
|
||||
AND a.prs_afdeling_parentkey IS NULL
|
||||
AND a.prs_afdeling_verwijder IS NULL)
|
||||
WHERE EXISTS
|
||||
(SELECT 1
|
||||
FROM fac_v_aanwezigusrdata ud, -- Mapping AD-Company -> Afdeling-1
|
||||
prs_afdeling a
|
||||
WHERE ud.fac_usrtab_key = 141 -- AD2Afdeling
|
||||
AND UPPER (ud.fac_usrdata_code) = UPPER (i.prs_kenmerk4)
|
||||
AND UPPER (ud.fac_usrdata_omschr) = UPPER (a.prs_afdeling_naam)
|
||||
AND a.prs_afdeling_parentkey IS NULL
|
||||
AND a.prs_afdeling_verwijder IS NULL);
|
||||
|
||||
-- Functie-kolom volgens kenmerk5 anders 'Medewerker' (zoals hierboven gereset)!
|
||||
UPDATE fac_imp_perslid i
|
||||
SET i.prs_srtperslid_omschrijving = COALESCE (SUBSTR (i.prs_kenmerk5, 1, 60), i.prs_srtperslid_omschrijving);
|
||||
COMMIT;
|
||||
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.imp_writelog (p_import_key, 'E', v_errormsg, 'Inleesproces personen afgebroken!');
|
||||
END vbgo_import_prs;
|
||||
/
|
||||
|
||||
CREATE OR REPLACE PROCEDURE vbgo_update_prs (p_import_key IN NUMBER)
|
||||
AS
|
||||
-- Maximaal percentage aan nieuwe medewerkers tov. actieve medewerkers (met
|
||||
-- een personeelsnummer).
|
||||
c_max_delta_percentage NUMBER (10) := 50; -- 50%!
|
||||
v_errormsg VARCHAR2 (1000) := '-';
|
||||
oracle_err_num NUMBER;
|
||||
oracle_err_mes VARCHAR2 (200);
|
||||
v_count_prs_import NUMBER (10); -- #actieve personen na import!
|
||||
v_count_prs_actual NUMBER (10); -- #actieve personen voor import!
|
||||
|
||||
-- Verwijderen personen niet in import als geldt: kwartaal niet ingelogd,
|
||||
-- onder afgesproken afdelingen en met e-mail adres!
|
||||
CURSOR c_del
|
||||
IS
|
||||
SELECT p.prs_perslid_key, p.prs_perslid_email
|
||||
FROM prs_v_aanwezigperslid p
|
||||
WHERE COALESCE (p.prs_perslid_login, p.prs_perslid_aanmaak) < TRUNC (ADD_MONTHS (SYSDATE, -3), 'mm') -- Kwartaal niet ingelogd!
|
||||
AND p.prs_afdeling_key IN (-1) -- Onder afgesproken afdelingen!
|
||||
AND p.prs_perslid_email IS NOT NULL -- Met e-mail adres!
|
||||
AND NOT EXISTS
|
||||
(SELECT 1
|
||||
FROM fac_imp_perslid
|
||||
WHERE UPPER (prs_perslid_email) = UPPER (p.prs_perslid_email))
|
||||
ORDER BY 2;
|
||||
BEGIN
|
||||
-- Bepaal aantal actieve personen in FACILITOR na import!
|
||||
SELECT COUNT (DISTINCT prs_perslid_nr)
|
||||
INTO v_count_prs_import
|
||||
FROM fac_imp_perslid
|
||||
WHERE prs_perslid_email IS NOT NULL;
|
||||
|
||||
-- Bepaal aantal actieve personen in FACILITOR voor import!
|
||||
SELECT DECODE (COUNT ( * ), 0, 1, COUNT ( * ))
|
||||
INTO v_count_prs_actual
|
||||
FROM prs_v_aanwezigperslid
|
||||
WHERE prs_perslid_email IS NOT NULL;
|
||||
|
||||
IF (TRUNC ( (v_count_prs_import / v_count_prs_actual) * 100) < (100 - c_max_delta_percentage))
|
||||
THEN
|
||||
fac.imp_writelog (
|
||||
p_import_key, 'E',
|
||||
'Verschil tussen huidig aantal en te importeren aantal personen te groot!',
|
||||
'- max. verschilpercentage = [' || TO_CHAR (c_max_delta_percentage) || '%]'
|
||||
|| CHR (13) || CHR (10)
|
||||
|| '- #personen/import = [' || TO_CHAR (v_count_prs_import) || ']'
|
||||
|| CHR (13) || CHR (10)
|
||||
|| '- #personen/huidig = [' || TO_CHAR (v_count_prs_actual) || ']');
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Generieke update (op e-mail adres).
|
||||
prs.update_perslid (p_import_key, 'EMAIL', NULL);
|
||||
/*
|
||||
-- Toekennen autorisatiegroep!
|
||||
--INSERT INTO fac_gebruikersgroep (prs_perslid_key, fac_groep_key)
|
||||
-- SELECT p.prs_perslid_key, -1
|
||||
-- FROM prs_perslid p
|
||||
-- WHERE p.prs_afdeling_key = -1
|
||||
-- AND NOT EXISTS
|
||||
-- (SELECT 1
|
||||
-- FROM fac_gebruikersgroep
|
||||
-- WHERE fac_groep_key = -1
|
||||
-- AND prs_perslid_key = p.prs_perslid_key);
|
||||
--COMMIT;
|
||||
|
||||
-- Controleren dat geen leeg bestand is ontvangen!
|
||||
--SELECT COUNT ( * ) INTO v_count FROM fac_imp_perslid;
|
||||
--IF v_count > 100
|
||||
--THEN
|
||||
-- Verwijder personen die niet meer in de import voorkomen.
|
||||
--FOR rec IN c_del
|
||||
--LOOP
|
||||
-- prs.delete_perslid (p_import_key, rec.prs_perslid_key);
|
||||
--END LOOP;
|
||||
--END IF;
|
||||
-- Verwijder personen die niet meer in de import voorkomen.
|
||||
FOR rec IN c_del
|
||||
LOOP
|
||||
prs.delete_perslid (p_import_key, rec.prs_perslid_key);
|
||||
END LOOP;
|
||||
*/
|
||||
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.imp_writelog (p_import_key, 'E', v_errormsg, 'Importproces personen afgebroken!');
|
||||
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
|
||||
Reference in New Issue
Block a user