625 lines
24 KiB
MySQL
625 lines
24 KiB
MySQL
--
|
|
-- $Id$
|
|
--
|
|
-- Script containing customer specific configuration sql statements for EBNF
|
|
|
|
DEFINE thisfile = 'EBNF.SQL'
|
|
DEFINE dbuser = '^EBNF'
|
|
|
|
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 PACKAGE EBNF
|
|
AS
|
|
PROCEDURE schonen_accounts;
|
|
END;
|
|
/
|
|
|
|
CREATE OR REPLACE PACKAGE BODY EBNF
|
|
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 ('EBNF_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 ('EBNF_SCHONENACCOUNTS', 'W', rec.aanduiding || v_errormsg, 'Fout schonen persoon');
|
|
END;
|
|
END LOOP;
|
|
|
|
fac.writelog ('EBNF_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 ('EBNF_SCHONENACCOUNTS', 'E', v_errormsg, '');
|
|
COMMIT;
|
|
END schonen_accounts;
|
|
END;
|
|
/
|
|
|
|
CREATE OR REPLACE PROCEDURE EBNF_DAILY
|
|
AS
|
|
v_errormsg VARCHAR2 (1000);
|
|
oracle_err_num NUMBER;
|
|
oracle_err_mes VARCHAR2 (200);
|
|
BEGIN
|
|
ebnf.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 EBNF_DAILY;
|
|
/
|
|
|
|
CREATE OR REPLACE VIEW EBNF_V_NOTI_BEZOEKERS
|
|
(
|
|
SENDER,
|
|
RECEIVER,
|
|
TEXT,
|
|
CODE,
|
|
KEY,
|
|
XKEY,
|
|
XEMAIL,
|
|
XMOBILE,
|
|
ATTACHMENTS
|
|
)
|
|
AS
|
|
SELECT NULL sender,
|
|
NULL receiver,
|
|
'Welkom bij Energie Beheer Nederland' text,
|
|
'CUST01' code,
|
|
a.bez_afspraak_key key,
|
|
NULL xkey,
|
|
b.bez_bezoekers_email xemail,
|
|
NULL xmobile,
|
|
(bijl.bijlage) AS attachments
|
|
FROM bez_bezoekers b,
|
|
bez_afspraak a,
|
|
alg_locatie l,
|
|
(SELECT af.bez_afspraak_key, fac_bijlagen_key bijlage
|
|
FROM fac_v_bijlagen bij, bez_afspraak af
|
|
WHERE fac_bijlagen_module = 'ALG'
|
|
AND af.alg_locatie_key = bij.fac_bijlagen_refkey
|
|
AND bij.fac_bijlagen_kenmerk_key = 1000) bijl, --Kenmerk routebeschrijving bij locatie
|
|
(SELECT fac_notificatie_job_nextrun, fac_notificatie_job_lastrun
|
|
FROM fac_notificatie_job
|
|
WHERE fac_notificatie_job_view = 'EBNF_V_NOTI_BEZOEKERS') n
|
|
WHERE b.bez_afspraak_key = a.bez_afspraak_key
|
|
AND a.alg_locatie_key = l.alg_locatie_key
|
|
AND a.bez_afspraak_key = bijl.bez_afspraak_key(+)
|
|
AND b.bez_bezoekers_email IS NOT NULL
|
|
AND b.bez_bezoekers_aanmaak > n.fac_notificatie_job_lastrun;
|
|
|
|
CREATE OR REPLACE VIEW ebnf_v_rap_mld_qrc
|
|
(
|
|
fclt_3d_locatie_key,
|
|
fclt_3d_discipline_key,
|
|
fclt_f_discipline,
|
|
fclt_f_soortmelding,
|
|
fclt_f_locatie,
|
|
fclt_f_gebouw,
|
|
fclt_f_verdieping,
|
|
plaats,
|
|
ruimte_key,
|
|
ruimtefunctie,
|
|
fclt_f_objectdiscipline,
|
|
fclt_f_objectgroep,
|
|
objectsoort_key,
|
|
fclt_f_objectsoort,
|
|
objectsoort_code,
|
|
ins_deel_key,
|
|
ins_deel_omschrijving,
|
|
ins_deel_upper,
|
|
hide_f_bookmark_id,
|
|
url
|
|
)
|
|
AS
|
|
SELECT l.alg_locatie_key,
|
|
disc.ins_discipline_key,
|
|
disc.ins_discipline_omschrijving,
|
|
msd.mld_stdmelding_omschrijving,
|
|
l.alg_locatie_omschrijving,
|
|
o.alg_gebouw_omschrijving,
|
|
o.alg_verdieping_omschrijving,
|
|
o.alg_plaatsaanduiding plaats,
|
|
d.ins_alg_ruimte_key ruimte_key,
|
|
sr.alg_srtruimte_omschrijving,
|
|
disc.ins_discipline_omschrijving,
|
|
sg.ins_srtgroep_omschrijving,
|
|
sd.ins_srtdeel_key,
|
|
sd.ins_srtdeel_omschrijving,
|
|
sd.ins_srtdeel_code,
|
|
d.ins_deel_key,
|
|
d.ins_deel_omschrijving,
|
|
d.ins_deel_upper,
|
|
b.fac_bookmark_id,
|
|
'https://ebnf.facilitor.nl/?u='
|
|
|| b.fac_bookmark_id
|
|
|| CHR(38)
|
|
||'ins_key='
|
|
|| d.ins_deel_key
|
|
FROM (SELECT DECODE (
|
|
INSTR (
|
|
SUBSTR (
|
|
UPPER (fac_bookmark_query),
|
|
INSTR (UPPER (fac_bookmark_query),
|
|
'STDM_KEY=')
|
|
),
|
|
'&'
|
|
),
|
|
0,
|
|
SUBSTR (
|
|
SUBSTR (
|
|
UPPER (fac_bookmark_query),
|
|
INSTR (UPPER (fac_bookmark_query),
|
|
'STDM_KEY=')
|
|
),
|
|
10
|
|
),
|
|
SUBSTR (
|
|
SUBSTR (
|
|
UPPER (fac_bookmark_query),
|
|
INSTR (UPPER (fac_bookmark_query),
|
|
'STDM_KEY=')
|
|
),
|
|
10,
|
|
INSTR (
|
|
SUBSTR (
|
|
UPPER (fac_bookmark_query),
|
|
INSTR (UPPER (fac_bookmark_query),
|
|
'STDM_KEY=')
|
|
),
|
|
'&'
|
|
)
|
|
- 10
|
|
)
|
|
)
|
|
stdm_key,
|
|
fac_bookmark_id
|
|
FROM fac_bookmark
|
|
WHERE UPPER (fac_bookmark_path) = 'APPL/PDA/MELDING.ASP'
|
|
AND INSTR (UPPER (fac_bookmark_query), 'STDM_KEY') > 0)
|
|
b, -- stdm_key-bookmarks
|
|
(SELECT sm.mld_stdmelding_key,
|
|
sm.mld_stdmelding_omschrijving,
|
|
si.ins_srtinstallatie_key ins_srtdeel_key
|
|
FROM mld_stdmelding sm,
|
|
mld_stdmelding_srtinst si
|
|
WHERE sm.mld_stdmelding_key = si.mld_stdmelding_key
|
|
AND sm.mld_stdmelding_verwijder IS NULL
|
|
AND si.ins_srtinstallatie_niveau = 'S'
|
|
UNION ALL
|
|
SELECT sm.mld_stdmelding_key,
|
|
sm.mld_stdmelding_omschrijving,
|
|
sd.ins_srtdeel_key
|
|
FROM mld_stdmelding sm,
|
|
mld_stdmelding_srtinst si,
|
|
ins_srtdeel sd
|
|
WHERE sm.mld_stdmelding_key = si.mld_stdmelding_key
|
|
AND sm.mld_stdmelding_verwijder IS NULL
|
|
AND si.ins_srtinstallatie_niveau = 'G'
|
|
AND si.ins_srtinstallatie_key = sd.ins_srtgroep_key
|
|
UNION ALL
|
|
SELECT sm.mld_stdmelding_key,
|
|
sm.mld_stdmelding_omschrijving,
|
|
sd.ins_srtdeel_key
|
|
FROM mld_stdmelding sm,
|
|
mld_stdmelding_srtinst si,
|
|
ins_srtgroep sg,
|
|
ins_srtdeel sd
|
|
WHERE sm.mld_stdmelding_key = si.mld_stdmelding_key
|
|
AND sm.mld_stdmelding_verwijder IS NULL
|
|
AND si.ins_srtinstallatie_niveau = 'D'
|
|
AND si.ins_srtinstallatie_key = sg.ins_discipline_key
|
|
AND sg.ins_srtgroep_key = sd.ins_srtgroep_key) msd, -- object-meldingen
|
|
ins_v_aanwezigdeel d,
|
|
ins_srtdeel sd,
|
|
ins_srtgroep sg,
|
|
ins_discipline disc,
|
|
ins_v_alg_overzicht o,
|
|
alg_locatie l,
|
|
alg_ruimte r,
|
|
alg_srtruimte sr
|
|
WHERE fac.safe_to_number (b.stdm_key) = msd.mld_stdmelding_key
|
|
AND msd.ins_srtdeel_key = d.ins_srtdeel_key
|
|
AND d.ins_alg_ruimte_type IN ('T', 'R', 'W')
|
|
AND d.ins_deel_parent_key IS NULL
|
|
AND d.ins_srtdeel_key = sd.ins_srtdeel_key
|
|
AND sd.ins_srtgroep_key = sg.ins_srtgroep_key
|
|
AND sg.ins_discipline_key = disc.ins_discipline_key
|
|
AND d.ins_alg_ruimte_key = o.alg_onroerendgoed_keys
|
|
AND d.ins_alg_ruimte_type = o.alg_onroerendgoed_type
|
|
AND d.ins_alg_locatie_key = o.alg_locatie_key -- redundant?
|
|
AND o.alg_locatie_key = l.alg_locatie_key
|
|
AND d.ins_alg_ruimte_key = r.alg_ruimte_key
|
|
AND r.alg_srtruimte_key = sr.alg_srtruimte_key(+);
|
|
|
|
CREATE OR REPLACE VIEW ebnf_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.naam
|
|
FROM res_v_aanwezigdeel isd,
|
|
datums,
|
|
(SELECT datum,
|
|
res_ins_deel_key,
|
|
DECODE (p.prs_perslid_visibility,
|
|
1,
|
|
pf.prs_perslid_naam_friendly,
|
|
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 VIEW EBNF_V_CATERINGRESER
|
|
(
|
|
RRR_KEY,
|
|
RESERVERING_KEY,
|
|
RES_RSV_RUIMTE_VOLGNR,
|
|
AANMK_DATUM,
|
|
LAST_UPD,
|
|
LAST_EXPORT,
|
|
VERW_DATUM,
|
|
RUIMTE_NR,
|
|
BESTELLER,
|
|
DATUM_VAN,
|
|
DATUM_TOT,
|
|
OMS,
|
|
AANTAL,
|
|
LOCATIE_CODE,
|
|
SOORT,
|
|
OPSTELLING,
|
|
FO_STATUS,
|
|
DIRTLEVEL
|
|
)
|
|
AS
|
|
SELECT "RRR_KEY",
|
|
"RESERVERING_KEY",
|
|
"RES_RSV_RUIMTE_VOLGNR",
|
|
"AANMK_DATUM",
|
|
"LAST_UPD",
|
|
"LAST_EXPORT",
|
|
"VERW_DATUM",
|
|
"RUIMTE_NR",
|
|
"BESTELLER",
|
|
"DATUM_VAN",
|
|
"DATUM_TOT",
|
|
"OMS",
|
|
"AANTAL",
|
|
"LOCATIE_CODE",
|
|
"SOORT",
|
|
"OPSTELLING",
|
|
"FO_STATUS",
|
|
"DIRTLEVEL"
|
|
FROM (SELECT DISTINCT
|
|
(rrr.res_rsv_ruimte_key)
|
|
rrr_key,
|
|
rrr.res_reservering_key
|
|
reservering_key,
|
|
rrr.res_rsv_ruimte_volgnr,
|
|
rrr.res_rsv_ruimte_aanmaak
|
|
aanmk_datum,
|
|
(SELECT MAX (fac_tracking_datum)
|
|
FROM fac_tracking
|
|
WHERE fac_tracking_refkey =
|
|
rrr.res_rsv_ruimte_key
|
|
AND fac_srtnotificatie_key = 117) --RESUPD
|
|
last_upd,
|
|
rrr.res_rsv_ruimte_externsyncdate
|
|
last_export,
|
|
rrr.res_rsv_ruimte_verwijder
|
|
verw_datum,
|
|
COALESCE (rer.res_ruimte_friendlyname, alg.alg_ruimte_nr)
|
|
ruimte_nr,
|
|
(SELECT prs_perslid_externid
|
|
FROM prs_perslid
|
|
WHERE prs_perslid_key = rrr.res_rsv_ruimte_contact_key)
|
|
besteller,
|
|
rrr.RES_RSV_RUIMTE_VAN
|
|
datum_van,
|
|
rrr.RES_RSV_RUIMTE_TOT
|
|
datum_tot,
|
|
rrr.res_rsv_ruimte_omschrijving
|
|
oms,
|
|
rrr.res_rsv_ruimte_bezoekers
|
|
aantal,
|
|
alg.alg_locatie_code
|
|
locatie_code,
|
|
'ruimte'
|
|
soort,
|
|
ros.res_opstelling_omschrijving
|
|
opstelling,
|
|
rrr.res_status_fo_key
|
|
fo_status,
|
|
rrr.res_rsv_ruimte_dirtlevel
|
|
dirtlevel
|
|
FROM res_rsv_ruimte rrr,
|
|
res_rsv_artikel rra,
|
|
res_ruimte_opstelling rop,
|
|
res_opstelling ros,
|
|
res_ruimte rer,
|
|
res_alg_ruimte rarm,
|
|
alg_v_ruimte_gegevens_all alg
|
|
WHERE rrr.res_status_bo_key = 2
|
|
AND rra.RES_RSV_RUIMTE_KEY = rrr.RES_RSV_RUIMTE_KEY
|
|
AND rrr.res_ruimte_opstel_key = rop.res_ruimte_opstel_key
|
|
AND ros.res_opstelling_key = rop.res_opstelling_key
|
|
AND rer.res_ruimte_key = rop.res_ruimte_key
|
|
AND rarm.res_ruimte_key = rer.res_ruimte_key
|
|
AND alg.alg_ruimte_key = rarm.alg_ruimte_key
|
|
UNION ALL
|
|
SELECT DISTINCT
|
|
(rrr.res_rsv_ruimte_key)
|
|
rrr_key,
|
|
rrr.res_reservering_key
|
|
reservering_key,
|
|
rrr.res_rsv_ruimte_volgnr,
|
|
rrr.res_rsv_ruimte_aanmaak
|
|
aanmk_datum,
|
|
(SELECT MAX (fac_tracking_datum)
|
|
FROM fac_tracking
|
|
WHERE fac_tracking_refkey =
|
|
rrr.res_rsv_ruimte_key
|
|
AND fac_srtnotificatie_key = 117) --RESUPD
|
|
last_upd,
|
|
rrr.res_rsv_ruimte_externsyncdate
|
|
last_export,
|
|
rrr.res_rsv_ruimte_verwijder
|
|
verw_datum,
|
|
alg.alg_ruimte_nr
|
|
ruimte_nr,
|
|
(SELECT pa.PRS_PERSLID_EMAIL
|
|
FROM PRS_V_PERSLID_GEGEVENS pa
|
|
WHERE pa.prs_perslid_key =
|
|
rrr.res_rsv_ruimte_contact_key)
|
|
besteller,
|
|
rrr.RES_RSV_RUIMTE_VAN
|
|
datum_van,
|
|
rrr.RES_RSV_RUIMTE_TOT
|
|
datum_tot,
|
|
rrr.res_rsv_ruimte_omschrijving
|
|
oms,
|
|
rrr.res_rsv_ruimte_bezoekers
|
|
aantal,
|
|
alg.alg_locatie_code
|
|
locatie_code,
|
|
'losse-catering'
|
|
soort,
|
|
'N.V.T.'
|
|
opstelling,
|
|
rrr.res_status_fo_key
|
|
fo_status,
|
|
0
|
|
dirtlevel
|
|
FROM res_rsv_ruimte rrr,
|
|
res_rsv_artikel rra,
|
|
alg_v_ruimte_gegevens_all alg
|
|
WHERE rrr.res_status_fo_key = 2
|
|
AND rra.RES_RSV_RUIMTE_KEY = rrr.RES_RSV_RUIMTE_KEY
|
|
AND alg.alg_ruimte_key = rrr.alg_ruimte_key
|
|
ORDER BY reservering_key);
|
|
|
|
CREATE OR REPLACE VIEW EBNF_V_NOTI_CATERAAR
|
|
(
|
|
SENDER,
|
|
RECEIVER,
|
|
TEXT,
|
|
CODE,
|
|
KEY,
|
|
XKEY,
|
|
XEMAIL,
|
|
XMOBILE
|
|
)
|
|
AS
|
|
SELECT NULL,
|
|
NULL,
|
|
'Er is een nieuwe catering aanvraag voor '
|
|
|| TO_CHAR (datum_van, 'dd-mm-yyyy')
|
|
|| ', reservering nummer '
|
|
|| reservering_key,
|
|
'CUST02',
|
|
reservering_key,
|
|
rrr_key,
|
|
'catering@ebn.nl',
|
|
NULL
|
|
FROM EBNF_V_CATERINGRESER, fac_notificatie_job nj
|
|
WHERE nj.fac_notificatie_job_view = 'EBNF_V_NOTI_CATERAAR'
|
|
AND ( nj.fac_notificatie_job_lastrun IS NULL
|
|
OR verw_datum > nj.fac_notificatie_job_lastrun)
|
|
AND TRUNC (aanmk_datum) = TRUNC (SYSDATE)
|
|
AND last_upd IS NULL
|
|
AND verw_datum IS NULL
|
|
UNION ALL
|
|
SELECT NULL,
|
|
NULL,
|
|
'Er is een (gewijzigde) catering aanvraag voor '
|
|
|| TO_CHAR (datum_van, 'dd-mm-yyyy')
|
|
|| ', reservering nummer '
|
|
|| reservering_key,
|
|
'CUST02',
|
|
reservering_key,
|
|
rrr_key,
|
|
'catering@ebn.nl',
|
|
NULL
|
|
FROM EBNF_V_CATERINGRESER, fac_notificatie_job nj
|
|
WHERE nj.fac_notificatie_job_view = 'EBNF_V_NOTI_CATERAAR'
|
|
AND ( nj.fac_notificatie_job_lastrun IS NULL
|
|
OR verw_datum > nj.fac_notificatie_job_lastrun)
|
|
AND TRUNC (LAST_UPD) = TRUNC (SYSDATE)
|
|
AND last_upd > aanmk_datum
|
|
AND verw_datum IS NULL
|
|
UNION ALL
|
|
SELECT NULL,
|
|
NULL,
|
|
'Er is een annulering van een catering aanvraag op '
|
|
|| TO_CHAR (datum_van, 'dd-mm-yyyy')
|
|
|| ', reservering nummer '
|
|
|| reservering_key,
|
|
'CUST02',
|
|
reservering_key,
|
|
rrr_key,
|
|
'catering@ebn.nl',
|
|
NULL
|
|
FROM EBNF_V_CATERINGRESER, fac_notificatie_job nj
|
|
WHERE nj.fac_notificatie_job_view = 'EBNF_V_NOTI_CATERAAR'
|
|
AND ( (verw_datum > nj.fac_notificatie_job_lastrun)
|
|
OR nj.fac_notificatie_job_lastrun IS NULL)
|
|
AND TRUNC (VERW_DATUM) = TRUNC (SYSDATE);
|
|
|
|
------ 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 |