Files
Customer/GDZW/gdzw.sql
Sander Schepers 6a9f37df16 GDZW#79271 SSO via AzureAD (SCIM)
svn path=/Customer/trunk/; revision=63983
2024-03-20 10:24:16 +00:00

574 lines
23 KiB
SQL

--
-- $Id$
--
-- Script containing customer specific configuration sql statements for GDZW
DEFINE thisfile = 'GDZW.SQL'
DEFINE dbuser = '^GDZW'
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 VIEW gdzw_v_import_log
AS
SELECT imp_log_status fclt_f_status,
imp_log_omschrijving omschrijving,
imp_log_hint opmerking
FROM imp_log
WHERE imp_log_applicatie = 'PRS';
-- Rappelnotificaties naar contractbeheerder en -eigenaar.
-- (Notificatie naar eigenaar alleen als dit niet ook de beheerder is)
-- Dagelijks schedulen; rapporteert alleen de contracten die vandaag de rappeltermijn ingaan.
CREATE OR REPLACE VIEW gdzw_v_noti_cntreminder_geg
AS
SELECT 'CNTMAI' code,
'' sender,
c.prs_perslid_key_beh beh,
c.prs_perslid_key_eig eig,
cnt.cnt_getrappeldatum (c.cnt_contract_key) rap,
cnt.cnt_getopzegdatum (c.cnt_contract_key) opz,
'Rappel: Contract '
|| c.cnt_contract_nummer_intern
|| ' ('
|| c.cnt_contract_omschrijving
|| ' '
|| b.prs_bedrijf_naam
|| ')'
|| ' moet uiterlijk per '
|| TO_CHAR (cnt.cnt_getopzegdatum (c.cnt_contract_key),
'DD-MM-YYYY')
|| ' worden verlengd of opgezegd.' text,
c.cnt_contract_key key,
c.cnt_contract_nummer_intern par1,
cnt.cnt_getopzegdatum (c.cnt_contract_key) par2,
NULL xkey
FROM cnt_v_aanwezigcontract c, prs_bedrijf b
WHERE b.prs_bedrijf_key = c.cnt_prs_bedrijf_key
AND cnt_contract_verwijder IS NULL
AND cnt_contract_status = 0
AND TRUNC(SYSDATE) = TRUNC(cnt.cnt_getrappeldatum(c.cnt_contract_key));
CREATE OR REPLACE VIEW gdzw_v_noti_cntreminder
(
CODE,
SENDER,
RECEIVER,
TEXT,
KEY,
PAR1,
PAR2,
XKEY
)
AS
SELECT code,
sender,
beh receiver,
text,
key,
par1,
par2,
xkey
FROM gdzw_v_noti_cntreminder_geg
WHERE beh IS NOT NULL
UNION ALL
SELECT code,
sender,
eig receiver,
text,
key,
par1,
par2,
xkey
FROM gdzw_v_noti_cntreminder_geg
WHERE eig IS NOT NULL
AND eig != beh;
CREATE OR REPLACE VIEW gdzw_v_rap_keyvsfe
(
soort_gebruiker,
Naam,
Loginnaam,
laatste_login
)
AS
SELECT DECODE (key_user, 1, 'KEY', 'FE'),
pf.prs_perslid_naam_full,
oslogin,
prs_perslid_login
FROM (SELECT *
FROM (SELECT p.prs_perslid_key prs_key,
COALESCE (p.prs_perslid_oslogin,
p.prs_perslid_oslogin2)
oslogin,
1 login, -- 1=user heeft login + groep + rechten
DECODE (
SIGN(TRUNC(COALESCE (p.prs_perslid_login + 92,
SYSDATE - 1))
- TRUNC (SYSDATE)),
-1,
0,
1) -- 1=user heeft laatste 92 dagen ingelogd
recent_login
FROM prs_v_aanwezigperslid p
WHERE EXISTS -- op basis van login + groep + rechten
(SELECT 1
FROM fac_v_webgebruiker gg
WHERE gg.prs_perslid_key = p.prs_perslid_key)
AND NOT EXISTS -- FSN#36597: WEB_FACFAC-users niet meetellen!
(SELECT 1
FROM fac_v_webgebruiker gg, fac_functie f
WHERE gg.prs_perslid_key =
p.prs_perslid_key
AND gg.fac_functie_key =
f.fac_functie_key
AND fac_functie_code = 'WEB_FACFAC')
UNION ALL -- FSN#24029: Soms ook personen zonder login meetellen!
SELECT p.prs_perslid_key,
NULL oslogin,
1 login, -- 1=user telt mee, want allow_for_others!
0 recent_login -- geen login, dus nooit recent ingelogd
FROM prs_v_aanwezigperslid p
WHERE COALESCE (p.prs_perslid_oslogin,
p.prs_perslid_oslogin2) IS NULL
AND (fac.getSetting ('mld_allow_for_others') = 1
OR EXISTS
(SELECT 1
FROM bes_disc_params dp
WHERE dp.bes_disc_params_for_others = 1))
UNION ALL -- FSN#27315: En ook eventuele "sensorusers" meetellen!
SELECT NULL prs_perslid_key,
NULL oslogin,
COUNT ( * ) login, -- elke sensoruser telt mee als FE!
1 recent_login -- recent actief dus tellen als recent
FROM ins_v_aanwezigdeel d
WHERE ins_deel_statedate > TRUNC (SYSDATE - 30)) x
LEFT JOIN -- 1=user heeft rechten op key-codes=notFE-codes
(SELECT DISTINCT fclt_f_login, 1 key_user
FROM fac_v_rap_groeprechten gr, fac_functie f
WHERE gr.fclt_f_funcode = f.fac_functie_code
AND f.fac_functie_groep IN (1, 2)) a
ON x.oslogin = a.fclt_f_login
LEFT JOIN -- FSN#30404: 1=user is cross-domain (xd) user
(SELECT p.prs_perslid_key, 1 xd_user
FROM prs_v_aanwezigperslid p,
prs_v_afdeling_boom ab
WHERE p.prs_afdeling_key = ab.prs_afdeling_key
AND p.prs_perslid_apikey IS NOT NULL
AND ab.prs_bedrijf_key =
fac.safe_to_number(fac.getSetting('xd_primary_bedrijfkey')))
b
ON x.prs_key = b.prs_perslid_key) st,
prs_perslid p,
prs_v_perslid_fullnames pf
WHERE login = 1
AND p.prs_perslid_key = st.prs_key
AND pf.prs_perslid_key = p.prs_perslid_key;
CREATE OR REPLACE VIEW GDZW_V_NOTI_HRMEXTRA
(
CODE,
SENDER,
RECEIVER,
TEXT,
KEY,
XKEY,
XSENDER,
XEMAIL,
XMOBILE
)
AS
SELECT DISTINCT
'CUST01'
AS code,
NULL
AS sender,
NULL
AS receiver,
'Er is een onderdeel in een HR workflow afgerond'
AS text,
m.mld_melding_key
AS key,
NULL
AS extra_key,
NULL,
(SELECT LISTAGG ((kmm1.mld_kenmerkmelding_waarde), '; ')
WITHIN GROUP (ORDER BY m.mld_melding_key DESC) AS xemail
FROM mld_kenmerkmelding kmm1, mld_kenmerk km1
WHERE kmm1.mld_melding_key = m.mld_melding_key
AND kmm1.mld_kenmerkmelding_verwijder IS NULL
AND kmm1.mld_kenmerk_key = km1.mld_kenmerk_key
AND ( UPPER (km1.mld_kenmerk_omschrijving) =
'EMAILADRES MEDEWERKER'
OR UPPER (km1.mld_srtkenmerk_key) = 321))
AS xemail,
NULL
FROM mld_melding m,
mld_stdmelding sm,
ins_tab_discipline d,
ins_srtdiscipline sd,
mld_kenmerkmelding kmm,
mld_kenmerk km
WHERE m.mld_melding_key NOT IN
(SELECT t.fac_tracking_refkey
FROM fac_tracking t
WHERE t.fac_tracking_oms LIKE '%CUST01%'
AND t.fac_tracking_refkey = m.mld_melding_key)
AND m.mld_stdmelding_key = sm.mld_stdmelding_key
AND sm.mld_ins_discipline_key = d.ins_discipline_key
AND d.ins_srtdiscipline_key = sd.ins_srtdiscipline_key
AND sd.ins_srtdiscipline_key IN (141, 142) -- Vakgroeptypen 'Facilitair - PnO workflows' en 'ICT - PnO workflows'
AND kmm.mld_melding_key = m.mld_melding_key
AND km.mld_kenmerk_key = kmm.mld_kenmerk_key
AND m.mld_melding_status = 2
AND ( UPPER (km.mld_kenmerk_omschrijving) =
'EMAILADRES MEDEWERKER'
OR UPPER (km.mld_srtkenmerk_key) = 321)
AND kmm.mld_melding_key = m.mld_melding_key
AND kmm.mld_kenmerkmelding_verwijder IS NULL
AND kmm.mld_kenmerk_key = km.mld_kenmerk_key
ORDER BY m.mld_melding_key;
CREATE OR REPLACE PROCEDURE gdzw_processemail (pfrom IN VARCHAR2,
pto IN VARCHAR2,
psubject IN VARCHAR2,
pbody IN VARCHAR2,
psessionid IN VARCHAR2,
pemailkey IN NUMBER)
AS
v_sender prs_perslid.prs_perslid_key%TYPE;
v_kostenplaats prs_afdeling.prs_kostenplaats_key%TYPE;
v_mldstat mld_melding.mld_melding_status%TYPE;
v_stdmelding mld_stdmelding.mld_stdmelding_key%TYPE;
v_stduitvoer mld_stdmelding.mld_stdmelding_t_uitvoertijd%TYPE;
v_errormsg fac_result.fac_result_waarde%TYPE;
v_from VARCHAR2 (4000);
v_fromaddr VARCHAR2 (4000);
v_body VARCHAR2 (4000);
m_body VARCHAR2 (4000);
v_mldkey mld_melding.mld_melding_key%TYPE;
v_mailorigin mld_kenmerk.mld_kenmerk_key%TYPE;
BEGIN
v_sender := 4; --Standaard de persoon Facilitor
v_stdmelding := fac.safe_to_number (fac.getsetting ('defaultstdmelding'));
v_mailorigin := 1121; --Kenmerk_key oorspronkelijke mail
-- Verwijder de Bounce Address Tag Validation
v_errormsg := '(0x101)';
IF pfrom LIKE 'prvs=%'
THEN
v_from := SUBSTR (pfrom, INSTR (pfrom, '=', -1) + 1);
ELSE
v_from := pfrom;
END IF;
v_errormsg := '(0x102)';
-- Indien een mail is doorgestuurd, dan moet er teruggevallen worden op de v_fromaddr.
SELECT fac_result_waarde
INTO v_fromaddr
FROM fac_result
WHERE fac_result_sessionid = psessionid AND fac_result_naam = 'fromaddr';
v_fromaddr := REPLACE (REPLACE (v_fromaddr, '>', ''), '<', '');
v_body := pbody;
m_body := pbody;
-- Valideer de sender in pfrom: kennen we deze?
v_errormsg := '(0x111)';
SELECT MIN (p.prs_perslid_key), MIN (d.prs_kostenplaats_key)
INTO v_sender, v_kostenplaats
FROM prs_perslid p, prs_afdeling d
WHERE p.prs_afdeling_key = d.prs_afdeling_key
AND p.prs_perslid_verwijder IS NULL
AND UPPER (prs_perslid_email) = UPPER (v_from);
CASE
WHEN UPPER (pto) LIKE 'FACILITORM2M@%'
THEN
BEGIN
v_errormsg :=
SUBSTR (('(0x201)' || psessionid || pfrom || m_body),
0,
4000);
-- Valideer de sender in pfromaddr: kennen we deze?
-- Bij facilitorm2m@gdzw.facilitor.nl worden de mails via facilitorm2m@ggdzw.nl doorgestuurd.
-- Dit zijn meldingen mbt dataveiligheid.
-- In fromaddr zit dan het mailadres van de oorspronkelijke melder.
-- Bij facilitorm2m meldingen mag de fromaddr de v_sender uit v_from overschrijven.
SELECT MIN (p.prs_perslid_key), MIN (d.prs_kostenplaats_key)
INTO v_sender, v_kostenplaats
FROM prs_perslid p, prs_afdeling d
WHERE p.prs_afdeling_key = d.prs_afdeling_key
AND p.prs_perslid_verwijder IS NULL
AND UPPER (prs_perslid_email) = UPPER (v_fromaddr);
EXCEPTION
WHEN OTHERS
THEN
fac.writelog (
'PROCESSEMAIL',
'W',
'Mail kon niet geformateerd worden afzender:'
|| pfrom
|| '['
|| v_errormsg
|| ']',
'OTHERS (error '
|| SQLCODE
|| '/'
|| SUBSTR (SQLERRM, 1, 100)
|| ')');
END;
--Hieronder de acties die gedaan moeten worden.
BEGIN
v_errormsg := '(0x211)' || pfrom || psubject;
v_stdmelding := 1041; -- Standaardmelding 'Dataveiligheid' in vakgroeptype ICT Servicedesk
v_mldstat := 2; -- Standaard de status in Nieuw (2).
v_stduitvoer :=
mld.getstduitvoer (v_stdmelding,
NULL,
NULL,
NULL);
v_errormsg := '(0x212)' || pfrom || v_mldkey || psubject;
INSERT INTO mld_melding (mld_melding_module,
mld_meldbron_key,
mld_melding_datum,
mld_melding_onderwerp,
mld_melding_omschrijving,
mld_melding_status,
mld_melding_t_uitvoertijd,
mld_stdmelding_key,
mld_alg_locatie_key,
mld_melding_externnr,
prs_perslid_key,
prs_perslid_key_voor,
prs_kostenplaats_key,
mld_melding_spoed)
VALUES (
'MLD',
4, -- email
SYSDATE,
SUBSTR (psubject, 1, 80),
SUBSTR (
REPLACE (
SUBSTR (v_body, 1, 4000),
CHR (13)
|| CHR (10)
|| CHR (13)
|| CHR (10),
CHR (13) || CHR (10)),
1,
4000), -- verwijder onnodige witregels
v_mldstat,
NULL, -- v_stduitvoer
v_stdmelding,
NULL, -- Locatie onbekend
NULL,
v_sender,
v_sender,
v_kostenplaats,
3)
RETURNING mld_melding_key
INTO v_mldkey;
v_errormsg := '(0x221)';
mld.setmeldingstatus (v_mldkey, v_mldstat, v_sender);
INSERT INTO fac_result (fac_result_sessionid,
fac_result_naam,
fac_result_waarde)
VALUES (psessionid,
'maillog',
'Geregistreerd onder melding ' || v_mldkey);
END;
IF v_mldkey IS NOT NULL
THEN
BEGIN
-- Originele email wordt opgeslagen bij de opdracht
v_errormsg := '(0x231`)' || v_mldkey || psubject;
INSERT INTO fac_result (fac_result_sessionid,
fac_result_naam,
fac_result_waarde)
VALUES (
psessionid,
'kenmerkorgmailpath',
'MLD\M'
|| TO_CHAR (TRUNC (v_mldkey / 1000),
'FM0000')
|| '___\M'
|| v_mldkey
|| '\'
|| v_mailorigin
|| '\');
END;
END IF;
ELSE
v_errormsg :=
'(0x900)' || v_mldkey || psubject || ' - geen pto herkend';
INSERT INTO fac_result (fac_result_sessionid,
fac_result_naam,
fac_result_waarde)
VALUES (psessionid, 'maillog', v_errormsg);
END CASE;
EXCEPTION
WHEN OTHERS
THEN
INSERT INTO fac_result (fac_result_sessionid,
fac_result_naam,
fac_result_waarde)
VALUES (psessionid, 'maillog', v_errormsg);
fac.writelog (
'PROCESSEMAIL',
'E',
'Mail kon niet ingelezen worden afzender:'
|| pfrom
|| '['
|| v_errormsg
|| v_mldkey
|| psubject
|| ']',
'OTHERS (error '
|| SQLCODE
|| '/'
|| SUBSTR (SQLERRM, 1, 100)
|| ')');
END;
/
CREATE OR REPLACE PACKAGE GDZW
AS
PROCEDURE schonen_accounts;
END;
/
CREATE OR REPLACE PACKAGE BODY GDZW
AS
-- Verwijder via SCIM geinactiveerde personen!
PROCEDURE schonen_accounts
AS
c_prs_dummy_key NUMBER (10) := -1; -- DUMMY tbv overzetten verplichtingen verwijderde personen
v_errormsg VARCHAR2 (1000);
oracle_err_num NUMBER;
oracle_err_mes VARCHAR2 (200);
v_count_del NUMBER (10);
CURSOR c1
IS
SELECT '[' || TO_CHAR (p.prs_perslid_key) || '|' || p.prs_perslid_email || '|' || pf.prs_perslid_naam_full || '] '
aanduiding,
p.prs_perslid_key,
COUNT (vp.prs_perslid_key) aant
FROM prs_v_aanwezigperslid p, prs_v_verplichting_keys vp, prs_v_perslid_fullnames pf
WHERE p.prs_perslid_externid IS NOT NULL -- SCIM-populatie!
AND COAlESCE (p.prs_perslid_inactief, SYSDATE) < TRUNC (SYSDATE)
AND p.prs_perslid_key = vp.prs_perslid_key(+) -- Actuele verplichtingen?
AND p.prs_perslid_key = pf.prs_perslid_key
GROUP BY '[' || TO_CHAR (p.prs_perslid_key) || '|' || p.prs_perslid_email || '|' || pf.prs_perslid_naam_full || '] ',
p.prs_perslid_key
ORDER BY 2;
BEGIN
v_count_del := 0;
FOR rec IN c1
LOOP
BEGIN
IF rec.aant = 0
THEN
v_errormsg := 'Fout schonen collega';
DELETE FROM prs_collega
WHERE prs_perslid_key = rec.prs_perslid_key
OR prs_perslid_key_alt = rec.prs_perslid_key;
v_errormsg := 'Fout schonen perslid';
UPDATE prs_perslid
SET prs_perslid_verwijder = SYSDATE
WHERE prs_perslid_key = rec.prs_perslid_key;
v_count_del := v_count_del + 1;
IF MOD (v_count_del, 1000) = 0
THEN
COMMIT;
END IF;
ELSE
fac.writelog ('GDZW_SCHONENACCOUNTS', 'I', rec.aanduiding || '/#Verplichtingen: ' || TO_CHAR (rec.aant), 'Persoon niet geschoond');
END IF;
EXCEPTION
WHEN OTHERS
THEN -- Kennelijk heeft persoon toch nog ernstige verplichtingen!
oracle_err_num := SQLCODE;
oracle_err_mes := SUBSTR (SQLERRM, 1, 200);
v_errormsg := v_errormsg || ' ORACLE (error ' || oracle_err_num || '/' || oracle_err_mes || ')';
fac.writelog ('GDZW_SCHONENACCOUNTS', 'W', rec.aanduiding || v_errormsg, 'Fout schonen persoon');
END;
END LOOP;
fac.writelog ('GDZW_SCHONENACCOUNTS', 'S', 'Personen/#geschoond: ' || TO_CHAR (v_count_del), '');
COMMIT;
EXCEPTION
WHEN OTHERS
THEN
oracle_err_num := SQLCODE;
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
v_errormsg := v_errormsg || ' ORACLE (error ' || oracle_err_num || '/' || oracle_err_mes || ')';
fac.writelog ('GDZW_SCHONENACCOUNTS', 'E', v_errormsg, '');
COMMIT;
END schonen_accounts;
END;
/
CREATE OR REPLACE PROCEDURE GDZW_DAILY
AS
v_errormsg VARCHAR2 (1000);
oracle_err_num NUMBER;
oracle_err_mes VARCHAR2 (200);
BEGIN
gdzw.schonen_accounts;
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.writelog ('DAILY', 'E', 'Proces afgebroken!', v_errormsg);
END GDZW_DAILY;
/
------ 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