QUAW#36327 personenimport Quawonen
svn path=/Customer/trunk/; revision=32450
This commit is contained in:
208
QUAW/QUAW.SQL
Normal file
208
QUAW/QUAW.SQL
Normal file
@@ -0,0 +1,208 @@
|
||||
--
|
||||
-- $Id$
|
||||
--
|
||||
-- Script containing customer specific sql statements for the FACILITOR database
|
||||
|
||||
DEFINE thisfile = 'QUAW.SQL'
|
||||
DEFINE dbuser = '^QUAW'
|
||||
DEFINE custid = 'QUAW'
|
||||
|
||||
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 ------
|
||||
|
||||
CREATE OR REPLACE PROCEDURE quaw_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_aantal_in_FCLT NUMBER;
|
||||
BEGIN
|
||||
UPDATE FAC_IMP_FILE
|
||||
SET fac_imp_file_line = REPLACE (fac_imp_file_line, ',', ';')
|
||||
WHERE fac_import_key = p_import_key;
|
||||
|
||||
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,
|
||||
'4;5;0;0;0;0;6;2;0;1;'
|
||||
|| '0;0;0;0;0;8;9;10;0;0;'
|
||||
|| '7;12;0;0;0;0;11;0;0;0;'
|
||||
|| '0;0;0;0;0;0;0;0;0;0;'
|
||||
|| '0;0;0;0;0;0',
|
||||
'"First Name";"Last Name";"DisplayName";"Locatie";"Gebouwcode";"Afdelingscode";"Aanhef";"Telefoonnummer";"Mobiel";"Email";"ipPhone";"loginnaam"%');
|
||||
|
||||
|
||||
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 quaw_import_prs;
|
||||
/
|
||||
|
||||
CREATE OR REPLACE PROCEDURE quaw_update_doorkiesnr (p_import_key IN NUMBER)
|
||||
IS
|
||||
CURSOR c_doorkiesnr
|
||||
IS
|
||||
SELECT '1000', P.PRS_PERSLID_KEY, I.PRS_KENMERK1
|
||||
FROM prs_perslid p, fac_imp_perslid i
|
||||
WHERE UPPER (P.PRS_PERSLID_OSLOGIN) = UPPER (I.PRS_PERSLID_OSLOGIN);
|
||||
BEGIN
|
||||
FOR rec IN c_doorkiesnr
|
||||
LOOP
|
||||
BEGIN
|
||||
prs.upsertkenmerk (1000, rec.PRS_PERSLID_KEY, rec.PRS_KENMERK1);
|
||||
END;
|
||||
END LOOP;
|
||||
END quaw_update_doorkiesnr;
|
||||
/
|
||||
|
||||
|
||||
CREATE OR REPLACE PROCEDURE quaw_update_prs (p_import_key IN NUMBER)
|
||||
IS
|
||||
-- Alle personen verwijderen die niet meer in import bestand voorkomen.
|
||||
-- Key bij QUAW is SAMAccountName, hieronder de query om alle personen te verwijderen die:
|
||||
-- a) niet meer in het importbestand staan, wel in Facilitor, en
|
||||
-- b) waarvan de persoon in Facilitor niet begint met een _ in de loginnaam (ook van af blijven)
|
||||
|
||||
|
||||
CURSOR c_del
|
||||
IS
|
||||
SELECT DISTINCT
|
||||
p.prs_perslid_key, p.prs_perslid_nr, pf.prs_perslid_naam_full
|
||||
FROM fac_imp_perslid i, prs_perslid p, prs_v_perslid_fullnames_all pf
|
||||
WHERE p.prs_perslid_verwijder IS NULL
|
||||
AND SUBSTR (p.prs_perslid_oslogin, 1, 1) <> '_'
|
||||
AND pf.prs_perslid_key = p.prs_perslid_key
|
||||
AND UPPER (p.prs_perslid_oslogin) NOT IN
|
||||
(SELECT UPPER (I.PRS_PERSLID_OSLOGIN)
|
||||
FROM fac_imp_perslid i)
|
||||
ORDER BY 2;
|
||||
|
||||
v_count NUMBER;
|
||||
BEGIN
|
||||
-- generic update
|
||||
|
||||
SELECT COUNT ( * ) INTO v_count FROM fac_imp_perslid;
|
||||
|
||||
-- 'LOGIN' betekent dat op basis van Login wordt gematched.
|
||||
-- 'NR' betekent dat op basis van Personeelsnummer wordt gematched.
|
||||
-- 'A' betekent altijd alle (andere/overige) werkplekken verwijderen
|
||||
prs.update_perslid (p_import_key, 'LOGIN', NULL);
|
||||
|
||||
quaw_update_doorkiesnr (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 quaw_update_prs;
|
||||
/
|
||||
|
||||
|
||||
-- QUAW#38329 QR code rapport
|
||||
|
||||
CREATE OR REPLACE VIEW QUAW_V_INS_QRC
|
||||
(
|
||||
hide_f_sort,
|
||||
fclt_3d_discipline_key,
|
||||
fclt_3d_locatie_key,
|
||||
fclt_f_locatie,
|
||||
fclt_f_gebouw,
|
||||
plaats,
|
||||
fclt_f_objectsoort,
|
||||
fclt_f_identificatie,
|
||||
ins_deel_key,
|
||||
soortruimte,
|
||||
ins_srtdeel_code,
|
||||
ins_srtdeel_key,
|
||||
ins_alg_ruimte_type,
|
||||
alg_gebouw_code,
|
||||
alg_verdieping_code,
|
||||
alg_district_key,
|
||||
ins_alg_ruimte_key,
|
||||
hide_f_bookmark_id
|
||||
)
|
||||
AS
|
||||
SELECT i.ins_deel_omschrijving hide_f_sort,
|
||||
i.ins_discipline_key fclt_3d_discipline_key,
|
||||
l.alg_locatie_key fclt_3d_locatie_key,
|
||||
l.alg_locatie_omschrijving fclt_f_locatie,
|
||||
o.alg_gebouw_omschrijving fclt_f_gebouw,
|
||||
o.alg_plaatsaanduiding plaats,
|
||||
s.ins_srtdeel_omschrijving fclt_f_objectsoort,
|
||||
i.ins_deel_omschrijving fclt_f_identificatie,
|
||||
i.ins_deel_key,
|
||||
(SELECT r.alg_ruimte_omschrijving
|
||||
FROM alg_ruimte r
|
||||
WHERE r.alg_ruimte_key = i.ins_alg_ruimte_key)
|
||||
soortruimte,
|
||||
s.ins_srtdeel_code,
|
||||
s.ins_srtdeel_key,
|
||||
i.ins_alg_ruimte_type,
|
||||
o.alg_gebouw_code,
|
||||
o.alg_verdieping_code,
|
||||
l.alg_district_key,
|
||||
i.ins_alg_ruimte_key,
|
||||
b.fac_bookmark_id hide_f_bookmark_id
|
||||
FROM ins_deel i,
|
||||
ins_v_alg_overzicht o,
|
||||
ins_srtdeel s,
|
||||
alg_locatie l,
|
||||
alg_district di,
|
||||
fac_bookmark b
|
||||
WHERE b.fac_bookmark_naam = 'QRC_OBJECT'
|
||||
AND ins_deel_verwijder IS NULL
|
||||
AND COALESCE (i.ins_deel_vervaldatum, SYSDATE + 1) > SYSDATE
|
||||
AND i.ins_deel_module = 'INS'
|
||||
AND i.ins_deel_parent_key IS NULL
|
||||
AND o.alg_onroerendgoed_keys = i.ins_alg_ruimte_key
|
||||
AND o.alg_onroerendgoed_type = i.ins_alg_ruimte_type
|
||||
AND i.ins_alg_ruimte_type IN ('T', 'R', 'W')
|
||||
AND o.alg_locatie_key = i.ins_alg_locatie_key
|
||||
AND i.ins_alg_locatie_key = l.alg_locatie_key
|
||||
AND l.alg_district_key = di.alg_district_key
|
||||
AND s.ins_srtdeel_key = i.ins_srtdeel_key;
|
||||
|
||||
BEGIN
|
||||
DBMS_UTILITY.COMPILE_SCHEMA (USER, FALSE);
|
||||
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