FSN#55356 -- Initiële versie (PROD)
svn path=/Customer/trunk/; revision=40320
This commit is contained in:
342
APGR/apgr.sql
Normal file
342
APGR/apgr.sql
Normal file
@@ -0,0 +1,342 @@
|
||||
--
|
||||
-- $Id$
|
||||
--
|
||||
-- Script containing customer specific sql statements for the A-Point database
|
||||
|
||||
DEFINE thisfile = 'APGR.SQL'
|
||||
DEFINE dbuser = '^APGR'
|
||||
DEFINE custid = 'APGR'
|
||||
|
||||
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 apgr_import_prs (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,
|
||||
'0;0;0;0;0;0;8;11;0;6;' ||
|
||||
'0;0;0;0;0;10;5;4;0;0;' ||
|
||||
'1;9;0;0;0;0;3;0;0;0;'||
|
||||
'0;0;0;0;0;0;0;0;0;0;'||
|
||||
'0;0;0;0;0;0',
|
||||
'title;Type;Group;mail;telephoneNumber;givenName;company;department;sAMAccountName;ipPhone;sn%'
|
||||
);
|
||||
|
||||
-- Handmatig ingelezen prs_perslid_nr behouden, deze staat niet in de AD export
|
||||
UPDATE fac_imp_perslid
|
||||
SET prs_perslid_nr =
|
||||
(SELECT p.prs_perslid_nr
|
||||
FROM prs_v_perslid_gegevens p
|
||||
WHERE UPPER (fac_imp_perslid.prs_perslid_oslogin) =
|
||||
UPPER (p.prs_perslid_oslogin));
|
||||
|
||||
-- De AD export kent geen plaatsgegevens, dus deze moeten behouden blijven uit de handmatige prs import
|
||||
UPDATE fac_imp_perslid
|
||||
SET
|
||||
(alg_locatie_code,
|
||||
alg_gebouw_code,
|
||||
alg_verdieping_volgnr,
|
||||
alg_ruimte_nr
|
||||
) =
|
||||
(SELECT l.alg_locatie_code,
|
||||
pw.alg_gebouw_code,
|
||||
pw.alg_verdieping_volgnr,
|
||||
pw.alg_ruimte_nr
|
||||
FROM prs_v_perslidwerkplek_gegevens pw,
|
||||
prs_perslid p,
|
||||
alg_locatie l
|
||||
WHERE p.prs_perslid_key = pw.prs_perslid_key
|
||||
AND pw.alg_locatie_key = l.alg_locatie_key
|
||||
AND UPPER (p.prs_perslid_oslogin) =
|
||||
UPPER (fac_imp_perslid.prs_perslid_oslogin));
|
||||
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 apgr_import_prs;
|
||||
/
|
||||
|
||||
CREATE OR REPLACE PROCEDURE apgr_update_prs (
|
||||
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 p.prs_perslid_oslogin NOT LIKE '%_%'
|
||||
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);
|
||||
|
||||
apgr_post_update_prs(p_import_key);
|
||||
|
||||
-- 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 apgr_update_prs;
|
||||
/
|
||||
|
||||
CREATE OR REPLACE PROCEDURE apgr_post_update_prs (p_import_key IN NUMBER)
|
||||
AS
|
||||
-- Personen die in de ADgroup "FMIS_Personeel" zitten moeten de autorisatie "Personeel"(4) krijgen (als ze dat al niet hebben).
|
||||
-- Hetzelfde geldt voor de groepen "Frontend"(5), "Directie"(6), "Backoffice"(7) en "Applicatiebeheer"(8)
|
||||
CURSOR c_auth_personeel
|
||||
IS
|
||||
SELECT DISTINCT prs_perslid_key, prs_kenmerk1
|
||||
FROM fac_imp_perslid
|
||||
WHERE prs_kenmerk1 LIKE '%Personeel%'
|
||||
AND fac_import_key = p_import_key
|
||||
AND prs_perslid_key IS NOT NULL
|
||||
AND prs_perslid_key NOT IN (SELECT prs_perslid_key
|
||||
FROM fac_gebruikersgroep
|
||||
WHERE fac_groep_key = 23);
|
||||
|
||||
CURSOR c_auth_frontend
|
||||
IS
|
||||
SELECT DISTINCT prs_perslid_key, prs_kenmerk1
|
||||
FROM fac_imp_perslid
|
||||
WHERE prs_kenmerk1 LIKE '%Front%'
|
||||
AND fac_import_key = p_import_key
|
||||
AND prs_perslid_key IS NOT NULL
|
||||
AND prs_perslid_key NOT IN (SELECT prs_perslid_key
|
||||
FROM fac_gebruikersgroep
|
||||
WHERE fac_groep_key = 24);
|
||||
|
||||
CURSOR c_auth_directie
|
||||
IS
|
||||
SELECT DISTINCT prs_perslid_key, prs_kenmerk1
|
||||
FROM fac_imp_perslid
|
||||
WHERE prs_kenmerk1 LIKE '%Directie%'
|
||||
AND fac_import_key = p_import_key
|
||||
AND prs_perslid_key IS NOT NULL
|
||||
AND prs_perslid_key NOT IN (SELECT prs_perslid_key
|
||||
FROM fac_gebruikersgroep
|
||||
WHERE fac_groep_key = 25);
|
||||
|
||||
|
||||
CURSOR c_auth_fmbackoffice
|
||||
IS
|
||||
SELECT DISTINCT prs_perslid_key, prs_kenmerk1
|
||||
FROM fac_imp_perslid
|
||||
WHERE prs_kenmerk1 LIKE '%FMBack%'
|
||||
AND fac_import_key = p_import_key
|
||||
AND prs_perslid_key IS NOT NULL
|
||||
AND prs_perslid_key NOT IN (SELECT prs_perslid_key
|
||||
FROM fac_gebruikersgroep
|
||||
WHERE fac_groep_key = 26);
|
||||
|
||||
CURSOR c_auth_ictbackoffice
|
||||
IS
|
||||
SELECT DISTINCT prs_perslid_key, prs_kenmerk1
|
||||
FROM fac_imp_perslid
|
||||
WHERE prs_kenmerk1 LIKE '%ICTBack%'
|
||||
AND fac_import_key = p_import_key
|
||||
AND prs_perslid_key IS NOT NULL
|
||||
AND prs_perslid_key NOT IN (SELECT prs_perslid_key
|
||||
FROM fac_gebruikersgroep
|
||||
WHERE fac_groep_key = 41);
|
||||
|
||||
CURSOR c_auth_fmbeheer
|
||||
IS
|
||||
SELECT DISTINCT prs_perslid_key, prs_kenmerk1
|
||||
FROM fac_imp_perslid
|
||||
WHERE prs_kenmerk1 LIKE '%FMApp%'
|
||||
AND fac_import_key = p_import_key
|
||||
AND prs_perslid_key IS NOT NULL
|
||||
AND prs_perslid_key NOT IN (SELECT prs_perslid_key
|
||||
FROM fac_gebruikersgroep
|
||||
WHERE fac_groep_key = 27);
|
||||
|
||||
CURSOR c_auth_ictbeheer
|
||||
IS
|
||||
SELECT DISTINCT prs_perslid_key, prs_kenmerk1
|
||||
FROM fac_imp_perslid
|
||||
WHERE prs_kenmerk1 LIKE '%ICTApp%'
|
||||
AND fac_import_key = p_import_key
|
||||
AND prs_perslid_key IS NOT NULL
|
||||
AND prs_perslid_key NOT IN (SELECT prs_perslid_key
|
||||
FROM fac_gebruikersgroep
|
||||
WHERE fac_groep_key = 27);
|
||||
|
||||
BEGIN
|
||||
-- plaats personen in de juiste autorisatie groepen
|
||||
FOR rec IN c_auth_personeel
|
||||
LOOP
|
||||
BEGIN
|
||||
INSERT INTO FAC_GEBRUIKERSGROEP (prs_perslid_key, fac_groep_key)
|
||||
VALUES (rec.prs_perslid_key, 23);
|
||||
|
||||
-- Deze personen niet in de default groep
|
||||
DELETE FAC_GEBRUIKERSGROEP
|
||||
WHERE prs_perslid_key = rec.prs_perslid_key
|
||||
AND fac_groep_key = 1;
|
||||
END;
|
||||
END LOOP;
|
||||
|
||||
FOR rec IN c_auth_frontend
|
||||
LOOP
|
||||
BEGIN
|
||||
INSERT INTO FAC_GEBRUIKERSGROEP (prs_perslid_key, fac_groep_key)
|
||||
VALUES (rec.prs_perslid_key, 24);
|
||||
END;
|
||||
END LOOP;
|
||||
|
||||
FOR rec IN c_auth_directie
|
||||
LOOP
|
||||
BEGIN
|
||||
INSERT INTO FAC_GEBRUIKERSGROEP (prs_perslid_key, fac_groep_key)
|
||||
VALUES (rec.prs_perslid_key, 25);
|
||||
END;
|
||||
END LOOP;
|
||||
|
||||
FOR rec IN c_auth_fmbackoffice
|
||||
LOOP
|
||||
BEGIN
|
||||
INSERT INTO FAC_GEBRUIKERSGROEP (prs_perslid_key, fac_groep_key)
|
||||
VALUES (rec.prs_perslid_key, 26);
|
||||
END;
|
||||
END LOOP;
|
||||
|
||||
FOR rec IN c_auth_ictbackoffice
|
||||
LOOP
|
||||
BEGIN
|
||||
INSERT INTO FAC_GEBRUIKERSGROEP (prs_perslid_key, fac_groep_key)
|
||||
VALUES (rec.prs_perslid_key, 41);
|
||||
END;
|
||||
END LOOP;
|
||||
|
||||
FOR rec IN c_auth_fmbeheer
|
||||
LOOP
|
||||
BEGIN
|
||||
INSERT INTO FAC_GEBRUIKERSGROEP (prs_perslid_key, fac_groep_key)
|
||||
VALUES (rec.prs_perslid_key, 27);
|
||||
|
||||
INSERT INTO FAC_GEBRUIKERSGROEP (prs_perslid_key, fac_groep_key)
|
||||
VALUES (rec.prs_perslid_key, 26);
|
||||
END;
|
||||
END LOOP;
|
||||
|
||||
FOR rec IN c_auth_ictbeheer
|
||||
LOOP
|
||||
BEGIN
|
||||
INSERT INTO FAC_GEBRUIKERSGROEP (prs_perslid_key, fac_groep_key)
|
||||
VALUES (rec.prs_perslid_key, 27);
|
||||
|
||||
INSERT INTO FAC_GEBRUIKERSGROEP (prs_perslid_key, fac_groep_key)
|
||||
VALUES (rec.prs_perslid_key, 41);
|
||||
END;
|
||||
END LOOP;
|
||||
|
||||
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
|
||||
Reference in New Issue
Block a user