De procedure prs.delete_perslid lijkt is volgens mij niet geschikt om zo te gebruiken zonder import_key. Daarom is de procedure nu aangepast. Bij geen verplichtingen wordt het account direct verwijderd. Bij verplichtingen wordt het inactief gezt. svn path=/Customer/trunk/; revision=67356
331 lines
11 KiB
MySQL
331 lines
11 KiB
MySQL
--
|
|
-- $Id$
|
|
--
|
|
-- Script containing customer specific sql statements for the FACILITOR database for Aareon (AREO)
|
|
|
|
DEFINE thisfile = 'AREO.SQL'
|
|
DEFINE dbuser = 'AREO'
|
|
|
|
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 AREO_V_QRC_WERKPLEKKEN
|
|
(
|
|
HIDE_F_SORT,
|
|
LOCATIE_CODE,
|
|
FCLT_F_LOCATIE,
|
|
FCLT_F_GEBOUW_NAAM,
|
|
FCLT_F_GEBOUW_OMSCHR,
|
|
FCLT_F_VERDIEPING,
|
|
ALG_RUIMTE_KEY,
|
|
FCLT_F_ALG_RUIMTE_NR,
|
|
INS_DEEL_KEY,
|
|
INS_DEEL_OMSCHR,
|
|
RES_DEEL_KEY,
|
|
RES_DEEL_OMSCHRIJVING,
|
|
FCLT_F_BOOKMARK,
|
|
FCLT_URL
|
|
)
|
|
AS
|
|
SELECT aog.alg_ruimte_nr,
|
|
l.alg_locatie_code,
|
|
l.alg_locatie_omschrijving,
|
|
aog.alg_gebouw_naam,
|
|
aog.alg_gebouw_naam,
|
|
aog.alg_verdieping_code,
|
|
aog.alg_ruimte_key,
|
|
aog.alg_ruimte_nr,
|
|
d.ins_deel_key,
|
|
d.ins_deel_omschrijving,
|
|
rd.res_deel_key,
|
|
rd.res_deel_omschrijving,
|
|
b.fac_bookmark_id hide_f_bookmark_id,
|
|
v.url
|
|
|| fac_bookmark_id
|
|
|| CHR (38)
|
|
|| 'res_deel_key='
|
|
|| res_deel_key url
|
|
FROM res_deel rd,
|
|
ins_deel d,
|
|
alg_v_onroerendgoed_gegevens aog,
|
|
alg_locatie l,
|
|
fac_bookmark b,
|
|
(SELECT CASE
|
|
WHEN INSTR (UPPER (USER), 'TEST', 1) > 0
|
|
THEN
|
|
'https://'
|
|
|| LOWER (fac_version_cust)
|
|
|| '.facilitor-test.nl/?u='
|
|
ELSE
|
|
'https://'
|
|
|| LOWER (fac_version_cust)
|
|
|| '.facilitor.nl/?u='
|
|
END url
|
|
FROM fac_version) v
|
|
WHERE rd.res_deel_verwijder IS NULL
|
|
AND UPPER (b.fac_bookmark_naam) IN
|
|
('QRC_RESERVIERUNG_ARBEITSPLATZ')
|
|
AND COALESCE (b.fac_bookmark_expire, SYSDATE + 1) > SYSDATE
|
|
AND d.ins_deel_key = rd.res_ins_deel_key
|
|
AND d.ins_discipline_key = 182 -- Objekt Diszipline Innere
|
|
AND d.ins_deel_verwijder IS NULL
|
|
AND ( rd.res_deel_vervaldatum > SYSDATE
|
|
OR rd.res_deel_vervaldatum IS NULL)
|
|
AND d.ins_alg_ruimte_key = aog.alg_ruimte_key
|
|
AND l.alg_locatie_key = aog.alg_locatie_key;
|
|
|
|
CREATE OR REPLACE VIEW AREO_V_LABEL_DEEL_RES_DATUM
|
|
(
|
|
FCLT_F_DATUM,
|
|
INS_DEEL_KEY,
|
|
RES_DEEL_OMSCHRIJVING,
|
|
WAARDE1,
|
|
WAARDE,
|
|
WAARDE3,
|
|
WAARDE_HTML,
|
|
WAARDE_HTML2,
|
|
TOOLTIP
|
|
)
|
|
AS
|
|
WITH
|
|
datums
|
|
AS
|
|
( SELECT TRUNC (SYSDATE) + LEVEL - 1 datum
|
|
FROM DUAL
|
|
CONNECT BY LEVEL <= 42)
|
|
SELECT datums.datum fclt_f_datum,
|
|
isd.res_ins_deel_key ins_deel_key,
|
|
res_deel_omschrijving,
|
|
CHR (10)
|
|
|| LISTAGG (
|
|
DECODE (
|
|
naam,
|
|
NULL, '',
|
|
'[s40]'
|
|
|| naam
|
|
|| ' ('
|
|
|| TO_CHAR (res_rsv_deel_van, 'HH24:MI')
|
|
|| '-'
|
|
|| DECODE (
|
|
TRUNC (res_rsv_deel_tot),
|
|
TRUNC (res_rsv_deel_van), TO_CHAR (
|
|
res_rsv_deel_tot,
|
|
'HH24:MI'),
|
|
TO_CHAR (res_rsv_deel_tot, 'DD-MM-YYYY HH24:MI'))
|
|
|| ')'),
|
|
CHR (10))
|
|
WITHIN GROUP (ORDER BY res_rsv_deel_van) waarde1,
|
|
CHR (10)
|
|
|| LISTAGG (DECODE (naam, NULL, '', '[s40]' || naam), CHR (10))
|
|
WITHIN GROUP (ORDER BY res_rsv_deel_van) waarde2,
|
|
CHR (10)
|
|
|| LISTAGG (DECODE (naam, NULL, '', '[s40]' || naam), CHR (10))
|
|
WITHIN GROUP (ORDER BY res_rsv_deel_van) waarde3,
|
|
LISTAGG (
|
|
DECODE (naam,
|
|
NULL, '',
|
|
'<span class="body">' || naam || '</span>'),
|
|
'<br>') waarde_html,
|
|
LISTAGG (
|
|
DECODE (naam,
|
|
NULL, '',
|
|
'<span class="body">' || naam || '</span>'),
|
|
'<br>')
|
|
WITHIN GROUP (ORDER BY res_rsv_deel_van) waarde_html2,
|
|
res_deel_omschrijving
|
|
FROM res_v_aanwezigdeel isd,
|
|
datums,
|
|
(SELECT datum,
|
|
res_ins_deel_key,
|
|
DECODE (
|
|
p.prs_perslid_visibility,
|
|
1, SUBSTR (p.prs_perslid_voornaam, 0, 1)
|
|
|| '. '
|
|
|| p.prs_perslid_naam,
|
|
a.prs_afdeling_omschrijving) naam,
|
|
res_rsv_deel_van,
|
|
res_rsv_deel_tot
|
|
FROM res_v_aanwezigdeel r,
|
|
res_v_aanwezigrsv_deel rrd,
|
|
res_rsv_ruimte rrr,
|
|
prs_v_perslid_fullnames pf,
|
|
prs_perslid p,
|
|
prs_afdeling a,
|
|
datums
|
|
WHERE r.res_deel_key = rrd.res_deel_key
|
|
AND rrd.res_rsv_ruimte_key = rrr.res_rsv_ruimte_key
|
|
AND rrr.res_rsv_ruimte_host_key = pf.prs_perslid_key
|
|
AND pf.prs_perslid_key = p.prs_perslid_key
|
|
AND p.prs_afdeling_key = a.prs_afdeling_key
|
|
AND datum + 1 >= res_rsv_deel_van
|
|
AND datum < res_rsv_deel_tot) res -- Bezet
|
|
WHERE isd.res_ins_deel_key = res.res_ins_deel_key(+)
|
|
AND datums.datum = res.datum(+)
|
|
GROUP BY datums.datum,
|
|
isd.res_ins_deel_key,
|
|
res_deel_omschrijving,
|
|
res_deel_opmerking,
|
|
res.naam;
|
|
|
|
|
|
CREATE OR REPLACE PACKAGE AREO
|
|
AS
|
|
|
|
PROCEDURE inactivate_prs;
|
|
|
|
END;
|
|
/
|
|
|
|
CREATE OR REPLACE PACKAGE BODY AREO
|
|
AS
|
|
PROCEDURE inactivate_prs
|
|
AS
|
|
v_errormsg VARCHAR2 (1000);
|
|
oracle_err_num NUMBER;
|
|
oracle_err_mes VARCHAR2 (200);
|
|
v_count_del NUMBER (10);
|
|
v_count_inactive NUMBER (10);
|
|
|
|
CURSOR c1 IS
|
|
SELECT p.prs_perslid_key,
|
|
p.prs_perslid_oslogin,
|
|
p.prs_perslid_email email,
|
|
prs_perslid_login,
|
|
COUNT (vp.prs_perslid_key) aant
|
|
FROM prs_v_aanwezigperslid p, prs_v_verplichting_keys vp
|
|
WHERE p.prs_perslid_login <
|
|
TRUNC (ADD_MONTHS (SYSDATE, -12), 'mm')
|
|
AND p.prs_perslid_key = vp.prs_perslid_key(+)
|
|
GROUP BY p.prs_perslid_key,
|
|
p.prs_perslid_oslogin,
|
|
p.prs_perslid_email,
|
|
prs_perslid_login;
|
|
BEGIN
|
|
v_count_del := 0;
|
|
v_count_inactive := 0;
|
|
|
|
FOR rec IN c1
|
|
LOOP
|
|
BEGIN
|
|
IF rec.aant = 0
|
|
THEN
|
|
v_errormsg := 'Error clean up colleague';
|
|
|
|
DELETE FROM
|
|
prs_collega
|
|
WHERE prs_perslid_key = rec.prs_perslid_key
|
|
OR prs_perslid_key_alt = rec.prs_perslid_key;
|
|
|
|
v_errormsg := 'Error delete account';
|
|
|
|
UPDATE prs_perslid
|
|
SET prs_perslid_verwijder = SYSDATE
|
|
WHERE prs_perslid_key = rec.prs_perslid_key;
|
|
|
|
v_count_del := v_count_del + 1;
|
|
ELSE
|
|
v_errormsg := 'Error inactive colleague';
|
|
|
|
DELETE FROM
|
|
prs_collega
|
|
WHERE prs_perslid_key = rec.prs_perslid_key
|
|
OR prs_perslid_key_alt = rec.prs_perslid_key;
|
|
|
|
v_errormsg := 'Error inactive account';
|
|
|
|
UPDATE prs_perslid
|
|
SET prs_perslid_inactief = SYSDATE
|
|
WHERE prs_perslid_key = rec.prs_perslid_key;
|
|
|
|
v_count_inactive := v_count_inactive + 1;
|
|
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 ('AREO_CLEANACCOUNTS',
|
|
'W',
|
|
rec.email || v_errormsg,
|
|
'error cleaning accounts');
|
|
END;
|
|
END LOOP;
|
|
|
|
fac.writelog ('AREO_CLEANACCOUNTS',
|
|
'S',
|
|
'Persons/#deleted: ' || 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 ('AREO_CLEANACCOUNTS',
|
|
'E',
|
|
v_errormsg,
|
|
'');
|
|
COMMIT;
|
|
END inactivate_prs;
|
|
END;
|
|
/
|
|
|
|
|
|
CREATE OR REPLACE PROCEDURE AREO_DAILY
|
|
AS
|
|
v_errormsg VARCHAR2 (1000);
|
|
oracle_err_num NUMBER;
|
|
oracle_err_mes VARCHAR2 (200);
|
|
BEGIN
|
|
areo.inactivate_prs;
|
|
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 AREO_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
|