ALLI#87260
svn path=/Customer/trunk/; revision=70502
This commit is contained in:
269
ALLI/alli.sql
269
ALLI/alli.sql
@@ -1186,7 +1186,7 @@ BEGIN
|
||||
|
||||
COMMIT;
|
||||
|
||||
-- E<>n persoon met dit nummer; werk bij
|
||||
-- E<>n persoon met dit nummer; werk bij
|
||||
ELSE
|
||||
|
||||
v_errorhint := 'Fout bij wijzigen persoon';
|
||||
@@ -2262,6 +2262,269 @@ and UPPER(KD.FAC_KENMERKDOMEIN_OBJECTNAAM) = 'ALLI_V_BO_MEDEWERKERS_BOUWBORD';
|
||||
|
||||
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
|
||||
-- basisoverzicht van reserveringen + gekoppelde objecten (alle objecten).
|
||||
|
||||
/* Formatted on 2/10/2025 12:22:37 (QP5 v5.336) */
|
||||
CREATE OR REPLACE FORCE VIEW ALLI.ALLI_V_OBJECTRESER
|
||||
(
|
||||
RESERVERING_KEY,
|
||||
RRR_KEY,
|
||||
RES_RUIMTE_KEY,
|
||||
RES_ACTIVITEIT_KEY,
|
||||
DATUM_VAN,
|
||||
DATUM_TOT,
|
||||
TIJD_VAN,
|
||||
TIJD_TOT,
|
||||
LOCATIE_CODE,
|
||||
RUIMTE_NR,
|
||||
OBJECTEN,
|
||||
AANMK_DATUM,
|
||||
LAST_UPD,
|
||||
VERW_DATUM,
|
||||
CODE,
|
||||
KEY,
|
||||
XKEY,
|
||||
XEMAIL
|
||||
)
|
||||
BEQUEATH DEFINER
|
||||
AS
|
||||
WITH
|
||||
obj
|
||||
AS
|
||||
( SELECT rrd.res_rsv_ruimte_key AS rrr_key,
|
||||
LISTAGG (d.res_deel_omschrijving, ', ')
|
||||
WITHIN GROUP (ORDER BY d.res_deel_omschrijving) AS objecten
|
||||
FROM res_rsv_deel rrd
|
||||
JOIN res_deel d ON d.res_deel_key = rrd.res_deel_key
|
||||
GROUP BY rrd.res_rsv_ruimte_key)
|
||||
SELECT rrr.res_reservering_key
|
||||
AS reservering_key,
|
||||
rrr.res_rsv_ruimte_key
|
||||
AS rrr_key,
|
||||
rer.res_ruimte_key
|
||||
AS res_ruimte_key,
|
||||
rrr.res_activiteit_key
|
||||
AS res_activiteit_key,
|
||||
TO_CHAR (rrr.res_rsv_ruimte_van, 'dd-mm-yyyy')
|
||||
AS datum_van,
|
||||
TO_CHAR (rrr.res_rsv_ruimte_tot, 'dd-mm-yyyy')
|
||||
AS datum_tot,
|
||||
TO_CHAR (rrr.res_rsv_ruimte_van, 'HH24:MI')
|
||||
AS tijd_van,
|
||||
TO_CHAR (rrr.res_rsv_ruimte_tot, 'HH24:MI')
|
||||
AS tijd_tot,
|
||||
alg.alg_locatie_code
|
||||
AS locatie_code,
|
||||
COALESCE (rer.res_ruimte_friendlyname, alg.alg_ruimte_nr)
|
||||
AS ruimte_nr,
|
||||
NVL (o.objecten, 'object')
|
||||
AS objecten,
|
||||
rrr.res_rsv_ruimte_aanmaak
|
||||
AS aanmk_datum,
|
||||
(SELECT MAX (f.fac_tracking_datum)
|
||||
FROM fac_tracking f
|
||||
WHERE f.fac_tracking_refkey = rrr.res_rsv_ruimte_key
|
||||
AND f.fac_srtnotificatie_key = 117)
|
||||
AS last_upd,
|
||||
rrr.res_rsv_ruimte_verwijder
|
||||
AS verw_datum,
|
||||
'CUST02'
|
||||
AS code,
|
||||
rrr.res_reservering_key
|
||||
AS key,
|
||||
rrr.res_rsv_ruimte_key
|
||||
AS xkey,
|
||||
'localsupport@de-alliantie.nl'
|
||||
AS xemail
|
||||
FROM res_rsv_ruimte rrr
|
||||
LEFT JOIN res_ruimte_opstelling rop
|
||||
ON rop.res_ruimte_opstel_key = rrr.res_ruimte_opstel_key
|
||||
LEFT JOIN res_ruimte rer
|
||||
ON rer.res_ruimte_key = rop.res_ruimte_key
|
||||
LEFT JOIN alg_v_ruimte_gegevens_all alg
|
||||
ON alg.alg_ruimte_key = rrr.alg_ruimte_key
|
||||
LEFT JOIN obj o ON o.rrr_key = rrr.res_rsv_ruimte_key
|
||||
WHERE EXISTS
|
||||
(SELECT 1
|
||||
FROM res_rsv_deel rrd
|
||||
WHERE rrd.res_rsv_ruimte_key = rrr.res_rsv_ruimte_key);
|
||||
|
||||
|
||||
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
-- subset van ALLI_V_OBJECTRESER specifiek voor AV-middelen (microfoon, verrijdbaar scherm).
|
||||
|
||||
/* Formatted on 2/10/2025 12:25:09 (QP5 v5.336) */
|
||||
CREATE OR REPLACE FORCE VIEW ALLI.ALLI_V_OBJECTRESER_AVSRT
|
||||
(
|
||||
RESERVERING_KEY,
|
||||
RRR_KEY,
|
||||
RES_RUIMTE_KEY,
|
||||
RES_ACTIVITEIT_KEY,
|
||||
DATUM_VAN,
|
||||
DATUM_TOT,
|
||||
TIJD_VAN,
|
||||
TIJD_TOT,
|
||||
LOCATIE_CODE,
|
||||
RUIMTE_NR,
|
||||
OBJECTEN,
|
||||
AANMK_DATUM,
|
||||
LAST_UPD,
|
||||
VERW_DATUM,
|
||||
CODE,
|
||||
KEY,
|
||||
XKEY,
|
||||
XEMAIL
|
||||
)
|
||||
BEQUEATH DEFINER
|
||||
AS
|
||||
WITH
|
||||
obj
|
||||
AS
|
||||
( SELECT rrd.res_rsv_ruimte_key AS rrr_key,
|
||||
LISTAGG (d.res_deel_omschrijving, ', ')
|
||||
WITHIN GROUP (ORDER BY d.res_deel_omschrijving) AS objecten
|
||||
FROM res_rsv_deel rrd
|
||||
JOIN res_deel d ON d.res_deel_key = rrd.res_deel_key
|
||||
WHERE UPPER (d.res_deel_omschrijving) LIKE 'MICRO%'
|
||||
OR REGEXP_LIKE (UPPER (d.res_deel_omschrijving),
|
||||
'VERRIJDBAAR.*SCHERM')
|
||||
GROUP BY rrd.res_rsv_ruimte_key)
|
||||
SELECT rrr.res_reservering_key,
|
||||
rrr.res_rsv_ruimte_key,
|
||||
rer.res_ruimte_key,
|
||||
rrr.res_activiteit_key,
|
||||
TO_CHAR (rrr.res_rsv_ruimte_van, 'dd-mm-yyyy')
|
||||
AS datum_van,
|
||||
TO_CHAR (rrr.res_rsv_ruimte_tot, 'dd-mm-yyyy')
|
||||
AS datum_tot,
|
||||
TO_CHAR (rrr.res_rsv_ruimte_van, 'HH24:MI')
|
||||
AS tijd_van,
|
||||
TO_CHAR (rrr.res_rsv_ruimte_tot, 'HH24:MI')
|
||||
AS tijd_tot,
|
||||
alg.alg_locatie_code,
|
||||
COALESCE (rer.res_ruimte_friendlyname, alg.alg_ruimte_nr)
|
||||
AS ruimte_nr,
|
||||
NVL (o.objecten, 'object')
|
||||
AS objecten,
|
||||
rrr.res_rsv_ruimte_aanmaak
|
||||
AS aanmk_datum,
|
||||
(SELECT MAX (f.fac_tracking_datum)
|
||||
FROM fac_tracking f
|
||||
WHERE f.fac_tracking_refkey = rrr.res_rsv_ruimte_key
|
||||
AND f.fac_srtnotificatie_key = 117)
|
||||
AS last_upd,
|
||||
rrr.res_rsv_ruimte_verwijder
|
||||
AS verw_datum,
|
||||
'CUST02'
|
||||
AS code,
|
||||
rrr.res_reservering_key
|
||||
AS key,
|
||||
rrr.res_rsv_ruimte_key
|
||||
AS xkey,
|
||||
'localsupport@de-alliantie.nl'
|
||||
AS xemail
|
||||
FROM res_rsv_ruimte rrr
|
||||
LEFT JOIN res_ruimte_opstelling rop
|
||||
ON rop.res_ruimte_opstel_key = rrr.res_ruimte_opstel_key
|
||||
LEFT JOIN res_ruimte rer
|
||||
ON rer.res_ruimte_key = rop.res_ruimte_key
|
||||
LEFT JOIN alg_v_ruimte_gegevens_all alg
|
||||
ON alg.alg_ruimte_key = rrr.alg_ruimte_key
|
||||
LEFT JOIN obj o ON o.rrr_key = rrr.res_rsv_ruimte_key
|
||||
WHERE EXISTS
|
||||
(SELECT 1
|
||||
FROM res_rsv_deel rrd
|
||||
JOIN res_deel d ON d.res_deel_key = rrd.res_deel_key
|
||||
WHERE rrd.res_rsv_ruimte_key = rrr.res_rsv_ruimte_key
|
||||
AND ( UPPER (d.res_deel_omschrijving) LIKE 'MICRO%'
|
||||
OR REGEXP_LIKE (UPPER (d.res_deel_omschrijving),
|
||||
'VERRIJDBAAR.*SCHERM')));
|
||||
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
-- tweede laag bovenop ALLI_V_OBJECTRESER_AVSRT. Bepaalt welke reserveringen nu gemaild moeten worden, afhankelijk van nieuw / gewijzigd / geannuleerd.
|
||||
|
||||
/* Formatted on 2/10/2025 12:26:24 (QP5 v5.336) */
|
||||
CREATE OR REPLACE FORCE VIEW ALLI.ALLI_V_NOTI_AVSRT
|
||||
(
|
||||
SENDER,
|
||||
RECEIVER,
|
||||
TEXT,
|
||||
CODE,
|
||||
KEY,
|
||||
XKEY,
|
||||
XEMAIL,
|
||||
XMOBILE
|
||||
)
|
||||
BEQUEATH DEFINER
|
||||
AS
|
||||
SELECT NULL AS sender,
|
||||
NULL AS receiver,
|
||||
'Er is een nieuwe AV-reservering voor '
|
||||
|| TO_CHAR (v.datum_van, 'dd-mm-yyyy')
|
||||
|| ' (reservering '
|
||||
|| v.reservering_key
|
||||
|| '), ruimte '
|
||||
|| v.ruimte_nr
|
||||
|| ' met object(en): '
|
||||
|| v.objecten AS text,
|
||||
v.code,
|
||||
v.reservering_key AS key,
|
||||
v.rrr_key AS xkey,
|
||||
v.xemail,
|
||||
NULL AS xmobile
|
||||
FROM ALLI_V_OBJECTRESER_AVSRT v, fac_notificatie_job nj
|
||||
WHERE nj.fac_notificatie_job_view = 'ALLI_V_NOTI_AVSRT'
|
||||
AND ( nj.fac_notificatie_job_lastrun IS NULL
|
||||
OR v.aanmk_datum > nj.fac_notificatie_job_lastrun)
|
||||
AND v.last_upd IS NULL
|
||||
AND v.verw_datum IS NULL
|
||||
UNION ALL
|
||||
/* === Gewijzigde reservering === */
|
||||
SELECT NULL AS sender,
|
||||
NULL AS receiver,
|
||||
'Er is een gewijzigde AV-reservering voor '
|
||||
|| TO_CHAR (v.datum_van, 'dd-mm-yyyy')
|
||||
|| ' (reservering '
|
||||
|| v.reservering_key
|
||||
|| '), ruimte '
|
||||
|| v.ruimte_nr
|
||||
|| ' met object(en): '
|
||||
|| v.objecten AS text,
|
||||
v.code,
|
||||
v.reservering_key AS key,
|
||||
v.rrr_key AS xkey,
|
||||
v.xemail,
|
||||
NULL AS xmobile
|
||||
FROM ALLI_V_OBJECTRESER_AVSRT v, fac_notificatie_job nj
|
||||
WHERE nj.fac_notificatie_job_view = 'ALLI_V_NOTI_AVSRT'
|
||||
AND ( nj.fac_notificatie_job_lastrun IS NULL
|
||||
OR v.last_upd > nj.fac_notificatie_job_lastrun)
|
||||
AND v.last_upd > v.aanmk_datum
|
||||
AND v.verw_datum IS NULL
|
||||
UNION ALL
|
||||
/* === Geannuleerde reservering === */
|
||||
SELECT NULL AS sender,
|
||||
NULL AS receiver,
|
||||
'Er is een annulering van een AV-reservering op '
|
||||
|| TO_CHAR (v.datum_van, 'dd-mm-yyyy')
|
||||
|| ' (reservering '
|
||||
|| v.reservering_key
|
||||
|| '), ruimte '
|
||||
|| v.ruimte_nr
|
||||
|| ' met object(en): '
|
||||
|| v.objecten AS text,
|
||||
v.code,
|
||||
v.reservering_key AS key,
|
||||
v.rrr_key AS xkey,
|
||||
v.xemail,
|
||||
NULL AS xmobile
|
||||
FROM ALLI_V_OBJECTRESER_AVSRT v, fac_notificatie_job nj
|
||||
WHERE nj.fac_notificatie_job_view = 'ALLI_V_NOTI_AVSRT'
|
||||
AND ( v.verw_datum > nj.fac_notificatie_job_lastrun
|
||||
OR nj.fac_notificatie_job_lastrun IS NULL)
|
||||
AND v.verw_datum IS NOT NULL;
|
||||
|
||||
|
||||
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
|
||||
-- View tbv notificatiejob contract-reminder (afgeleid van de FAC-standaard).
|
||||
-- 1x per week wordt de job aangeroepen, verschil met de standaard FAC is dat niet alleen de beheerder (voor de UNION),
|
||||
@@ -2273,7 +2536,7 @@ CREATE OR REPLACE VIEW alli_v_noti_cntreminder
|
||||
(code, sender, receiver, text, key, par1, par2, xkey)
|
||||
AS
|
||||
SELECT '', '', c.prs_perslid_key_beh,
|
||||
'Rapp<EFBFBD>l: Contract '
|
||||
'Rapp<EFBFBD>l: Contract '
|
||||
|| c.cnt_contract_nummer_intern
|
||||
|| ' ('
|
||||
|| c.cnt_contract_omschrijving
|
||||
@@ -2291,7 +2554,7 @@ AS
|
||||
AND (SYSDATE BETWEEN cnt.cnt_getrappeldatum (c.cnt_contract_key) AND cnt.cnt_getopzegdatum (c.cnt_contract_key))
|
||||
UNION
|
||||
SELECT '', '', fac.safe_to_number(fac_usrdata_omschr),
|
||||
'Rapp<EFBFBD>l: Contract '
|
||||
'Rapp<EFBFBD>l: Contract '
|
||||
|| c.cnt_contract_nummer_intern
|
||||
|| ' ('
|
||||
|| c.cnt_contract_omschrijving
|
||||
|
||||
Reference in New Issue
Block a user