180 lines
6.5 KiB
SQL
180 lines
6.5 KiB
SQL
-- Script containing customer specific configuration sql statements for HAYG: HayGroup
|
|
-- (c) 2006 Facilitor Software Nederland/Dijkoraad IT bv
|
|
-- $Revision$
|
|
-- $Id$
|
|
--
|
|
-- Support: +31 53 4800700
|
|
|
|
SET DEFINE OFF
|
|
|
|
SPOOL xhayg.lst
|
|
SET ECHO ON
|
|
|
|
|
|
CREATE OR REPLACE PROCEDURE hayg_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);
|
|
BEGIN
|
|
|
|
-- verwijder lege regels
|
|
DELETE fac_imp_file
|
|
WHERE fac_import_key = p_import_key
|
|
AND fac_imp_file_line LIKE ';;;;;;;%';
|
|
|
|
v_errorhint := 'Generieke update';
|
|
-- de sequence array staat beschreven in FAC_PACF.SRC bij de fac_import_perslid_upd_body proc
|
|
prs.import_perslid (p_import_key,
|
|
'2;0;0;0;0;0;3;7;8;12;' ||
|
|
'6;9;10;11;13;24;25;26;0;1;' ||
|
|
'5;23;0;0;0;0;4;14;15;16;'||
|
|
'17;18;19;20;21;22;28;29;3;27;'||
|
|
'0;0;0;0;0;0',
|
|
'Persnr.;Locatie;Afdelingsnummer;Team;Functie;Voorletters;Geboortenaam;Voorv. geb.naam;Geb.naam partner;Voorvoegsel partner;Naamgebruik;Roepnaam;Geslacht;Geboren;Straat;Huisnr.;Toev.;Postc;Plaats;Telnr. privé;Mob. privé;Mail privé;Login;Telnr. werk;Mob. werk;Mail werk;Uren/wk;In dienst;Uit dienst%'
|
|
);
|
|
|
|
-- Klantspecifieke aanpassingen
|
|
v_errorhint := 'Aanvullen niet ingevulde gebouw, verdieping en ruimteinformatie en omzetten dienstverband';
|
|
UPDATE fac_imp_perslid i SET alg_gebouw_code = DECODE (alg_locatie_code, 'ZEI', 'HQ', 'ENS', 'KE', 'AMS', 'KA'),
|
|
alg_verdieping_volgnr = DECODE (alg_locatie_code, 'ZEI', 0, 'ENS', 2, 'AMS', 7),
|
|
alg_ruimte_nr = DECODE (alg_locatie_code, 'ZEI', '0.01', 'ENS', '2.06', 'AMS', '7.09'),
|
|
prs_perslid_dienstverband = round(fac.safe_to_number(REPLACE(i.prs_kenmerk14,',','.'))/0.4);
|
|
|
|
v_errorhint := 'Nog niet bestaande afdelingen aanmaken';
|
|
--kenmerk1 afdeling omschrijving
|
|
--kenmerk13 afdeling code
|
|
INSERT INTO prs_afdeling (prs_bedrijf_key, prs_afdeling_naam, prs_afdeling_omschrijving, prs_kostenplaats_key)
|
|
SELECT DISTINCT 21, i.prs_kenmerk13, i.prs_kenmerk1, 41
|
|
FROM fac_imp_perslid i
|
|
WHERE NOT EXISTS
|
|
( SELECT prs_afdeling_key
|
|
FROM prs_afdeling
|
|
WHERE prs_afdeling_verwijder IS NULL
|
|
AND prs_afdeling_naam = i.prs_kenmerk13);
|
|
|
|
|
|
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 hayg_import_perslid;
|
|
/
|
|
|
|
|
|
CREATE OR REPLACE PROCEDURE hayg_update_perslid (
|
|
p_import_key IN NUMBER
|
|
) IS
|
|
|
|
CURSOR c_flex
|
|
IS
|
|
SELECT i.*, p.prs_perslid_key prs_key
|
|
FROM fac_imp_perslid i, prs_perslid p
|
|
WHERE p.prs_perslid_nr = i.prs_perslid_nr
|
|
AND p.prs_perslid_verwijder IS NULL
|
|
ORDER BY 2;
|
|
|
|
|
|
|
|
CURSOR c_del
|
|
IS
|
|
SELECT p.prs_perslid_key, p.prs_perslid_nr
|
|
FROM fac_imp_perslid i, prs_perslid p
|
|
WHERE p.prs_perslid_nr = i.prs_perslid_nr(+)
|
|
AND p.prs_perslid_nr IS NOT NULL
|
|
AND i.prs_perslid_nr IS NULL
|
|
AND p.prs_perslid_verwijder IS NULL
|
|
ORDER BY 2;
|
|
|
|
v_count NUMBER;
|
|
|
|
BEGIN
|
|
-- generic update
|
|
|
|
SELECT count(*)
|
|
INTO v_count
|
|
FROM fac_imp_perslid;
|
|
|
|
IF v_count < 100
|
|
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;
|
|
|
|
prs.update_perslid (p_import_key, 'NR', 'A');
|
|
|
|
-- update flex fields
|
|
FOR rec IN c_flex
|
|
LOOP
|
|
BEGIN
|
|
PRS.upsertkenmerk (1027, rec.prs_key, rec.prs_kenmerk1); -- team
|
|
PRS.upsertkenmerk (1028, rec.prs_key, to_char(fac.safe_to_date(rec.prs_kenmerk2, 'dd-mm-yyyy'), 'dd-mm-yyyy')); -- geboortedatum
|
|
PRS.upsertkenmerk (1029, rec.prs_key, to_char(fac.safe_to_date(rec.prs_kenmerk11, 'dd-mm-yyyy'), 'dd-mm-yyyy')); -- indienst
|
|
PRS.upsertkenmerk (1030, rec.prs_key, to_char(fac.safe_to_date(rec.prs_kenmerk12, 'dd-mm-yyyy'), 'dd-mm-yyyy')); -- uitdienst;
|
|
PRS.upsertkenmerk (1021, rec.prs_key, rec.prs_kenmerk3 || ' ' || rec.prs_kenmerk4 || rec.prs_kenmerk5); -- straat, huisnr, toev
|
|
PRS.upsertkenmerk (1022, rec.prs_key, rec.prs_kenmerk6); -- postcode
|
|
PRS.upsertkenmerk (1023, rec.prs_key, rec.prs_kenmerk7); -- plaats
|
|
PRS.upsertkenmerk (1024, rec.prs_key, rec.prs_kenmerk10); -- email
|
|
PRS.upsertkenmerk (1025, rec.prs_key, rec.prs_kenmerk8); -- telefoon
|
|
PRS.upsertkenmerk (1026, rec.prs_key, rec.prs_kenmerk9); -- mobiel
|
|
END;
|
|
END LOOP;
|
|
|
|
-- 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;
|
|
|
|
-- verwijderen oude afdelingen
|
|
UPDATE prs_afdeling a
|
|
SET prs_afdeling_verwijder = SYSDATE
|
|
WHERE NOT EXISTS (SELECT prs_afdeling_key
|
|
FROM prs_v_afd_verplichting v
|
|
WHERE v.prs_afdeling_key = a.prs_afdeling_key)
|
|
AND NOT EXISTS
|
|
(SELECT prs_afdeling_key
|
|
FROM prs_perslid p
|
|
WHERE p.prs_afdeling_key = a.prs_afdeling_key
|
|
AND p.prs_perslid_verwijder IS NULL)
|
|
AND NOT EXISTS
|
|
(SELECT prs_afdeling_key
|
|
FROM prs_afdeling ap
|
|
WHERE ap.prs_afdeling_parentkey = a.prs_afdeling_key
|
|
AND ap.prs_afdeling_verwijder IS NULL)
|
|
AND a.prs_afdeling_verwijder IS NULL;
|
|
|
|
-- verwijderen oude functies
|
|
UPDATE prs_srtperslid s
|
|
SET prs_srtperslid_verwijder = SYSDATE
|
|
WHERE NOT EXISTS
|
|
(SELECT prs_perslid_key
|
|
FROM prs_perslid p
|
|
WHERE p.prs_srtperslid_key = s.prs_srtperslid_key
|
|
AND prs_perslid_verwijder IS NULL)
|
|
AND prs_srtperslid_verwijder IS NULL;
|
|
|
|
END hayg_update_perslid;
|
|
/
|
|
|
|
|
|
BEGIN fac.registercustversion('HAYG', 3); END;
|
|
/
|
|
BEGIN adm.systrackscriptId('$Id$', 0); END;
|
|
/
|
|
commit;
|
|
|
|
spool off
|