563 lines
22 KiB
SQL
563 lines
22 KiB
SQL
--
|
|
-- $Id$
|
|
--
|
|
-- Script containing customer specific sql statements for the FACILITOR database
|
|
|
|
DEFINE thisfile = 'STAM.SQL'
|
|
DEFINE dbuser = '^STAM'
|
|
DEFINE custid = 'STAM'
|
|
|
|
SET ECHO ON
|
|
SET DEFINE ON
|
|
COLUMN fcltlogfile NEW_VALUE fcltlogfile NOPRINT;
|
|
WHENEVER SQLERROR EXIT;
|
|
SELECT adm.scriptspoolfile('&dbuser', '&thisfile') AS fcltlogfile FROM DUAL;
|
|
WHENEVER SQLERROR CONTINUE;
|
|
SPOOL &fcltlogfile
|
|
SET DEFINE OFF
|
|
|
|
------ payload begin -----
|
|
|
|
CREATE OR REPLACE VIEW STAM_V_PROJECTKOSTENPLAATSEN
|
|
(
|
|
KOSTENPLAATS_KEY,
|
|
KOSTENPLAATS,
|
|
KOSTENPLAATS_VERWIJDER
|
|
)
|
|
AS
|
|
SELECT prs_kostenplaats_key, prs_kostenplaats_upper,prs_kostenplaats_verwijder
|
|
FROM prs_kostenplaats k
|
|
WHERE k.prs_kostenplaats_module = 'PRJ';
|
|
|
|
CREATE OR REPLACE VIEW STAM_V_PROJECTMANAGERS
|
|
(
|
|
PRS_PERSLID_KEY,
|
|
PROJECTMANAGER
|
|
)
|
|
AS
|
|
SELECT p.prs_perslid_key, n.prs_perslid_naam_full
|
|
FROM prs_perslid p, prs_v_perslid_fullnames n
|
|
WHERE p.prs_srtperslid_key = 157
|
|
AND n.prs_perslid_key = p.prs_perslid_key;
|
|
|
|
CREATE OR REPLACE VIEW STAM_V_INS_QRC_OBJECT
|
|
(
|
|
HIDE_F_SORT,
|
|
LOCATIE_CODE,
|
|
FCLT_F_LOCATIE,
|
|
FCLT_F_GEBOUW,
|
|
FCLT_F_PLAATS,
|
|
RUIMTENR,
|
|
FCLT_F_DISCIPLINE,
|
|
FCLT_F_OBJECTGROEP,
|
|
FCLT_F_OBJECTSOORT,
|
|
FCLT_F_IDENTIFICATIE,
|
|
FCLT_F_BOOKMARK,
|
|
INS_DEEL_KEY,
|
|
INS_SRTDEEL_KEY,
|
|
FCLT_3D_DISCIPLINE_KEY,
|
|
FCLT_3D_LOCATIE_KEY,
|
|
INS_ALG_RUIMTE_TYPE,
|
|
INS_ALG_RUIMTE_KEY,
|
|
BRAND,
|
|
OBJ_TYPE,
|
|
HIDE_F_BOOKMARK_ID
|
|
)
|
|
AS
|
|
SELECT i.ins_deel_omschrijving hide_f_sort,
|
|
l.alg_locatie_code,
|
|
l.alg_locatie_code || ' ' || l.alg_locatie_omschrijving
|
|
fclt_f_locatie,
|
|
o.alg_gebouw_omschrijving fclt_f_gebouw,
|
|
SUBSTR (o.alg_plaatsaanduiding, 13) fclt_f_plaats,
|
|
o.alg_ruimte_nr,
|
|
d.ins_discipline_omschrijving fclt_f_discipline,
|
|
g.ins_srtgroep_omschrijving fclt_f_objectgroep,
|
|
s.ins_srtdeel_omschrijving fclt_f_objectsoort,
|
|
i.ins_deel_omschrijving fclt_f_identificatie,
|
|
b.fac_bookmark_naam fclt_f_bookmark,
|
|
i.ins_deel_key,
|
|
s.ins_srtdeel_key,
|
|
i.ins_discipline_key fclt_3d_discipline_key,
|
|
l.alg_locatie_key fclt_3d_locatie_key,
|
|
i.ins_alg_ruimte_type,
|
|
i.ins_alg_ruimte_key,
|
|
brand.ins_kenmerkdeel_waarde,
|
|
obj_type.ins_kenmerkdeel_waarde,
|
|
b.fac_bookmark_id hide_f_bookmark_id
|
|
FROM ins_deel i,
|
|
ins_v_alg_overzicht o,
|
|
ins_srtdeel s,
|
|
ins_srtgroep g,
|
|
ins_discipline d,
|
|
alg_locatie l,
|
|
fac_bookmark b,
|
|
(SELECT kd.ins_deel_key, kd.ins_kenmerkdeel_waarde
|
|
FROM ins_kenmerk k, ins_kenmerkdeel kd
|
|
WHERE k.ins_srtkenmerk_key = 41
|
|
AND kd.ins_kenmerk_key = k.ins_kenmerk_key) brand,
|
|
(SELECT kd.ins_deel_key, kd.ins_kenmerkdeel_waarde
|
|
FROM ins_kenmerk k, ins_kenmerkdeel kd
|
|
WHERE k.ins_srtkenmerk_key = 42
|
|
AND kd.ins_kenmerk_key = k.ins_kenmerk_key) obj_type
|
|
WHERE b.fac_bookmark_path = 'appl/pda/ins_deel.asp'
|
|
AND COALESCE (b.fac_bookmark_expire, SYSDATE + 1) > SYSDATE
|
|
AND ins_deel_verwijder IS NULL
|
|
AND COALESCE (i.ins_deel_vervaldatum, SYSDATE + 1) > SYSDATE
|
|
AND i.ins_deel_module = 'INS'
|
|
AND i.ins_deel_parent_key IS NULL
|
|
AND s.ins_srtdeel_key = i.ins_srtdeel_key
|
|
AND g.ins_srtgroep_key = s.ins_srtgroep_key
|
|
AND d.ins_discipline_key = g.ins_discipline_key
|
|
AND o.alg_onroerendgoed_keys = i.ins_alg_ruimte_key
|
|
AND o.alg_onroerendgoed_type = i.ins_alg_ruimte_type
|
|
AND i.ins_alg_ruimte_type IN ('T', 'R', 'W')
|
|
AND o.alg_locatie_key = i.ins_alg_locatie_key
|
|
AND l.alg_locatie_key = i.ins_alg_locatie_key
|
|
AND i.ins_deel_key = brand.ins_deel_key(+)
|
|
AND i.ins_deel_key = obj_type.ins_deel_key(+);
|
|
|
|
CREATE OR REPLACE VIEW STAM_V_INS_QRC_RUIMTE
|
|
(
|
|
FCLT_3D_LOCATIE_KEY,
|
|
FCLT_F_LOCATIE,
|
|
FCLT_F_GEBOUW,
|
|
PLAATS,
|
|
SOORTRUIMTE,
|
|
INS_ALG_RUIMTE_TYPE,
|
|
ALG_DISTRICT_KEY,
|
|
ALG_RUIMTE_KEY,
|
|
HIDE_F_BOOKMARK_ID
|
|
)
|
|
AS
|
|
SELECT l.alg_locatie_key,
|
|
l.alg_locatie_omschrijving,
|
|
x.alg_gebouw_naam,
|
|
substr(x.alg_plaatsaanduiding, 7) plaats,
|
|
x.alg_ruimte_omschrijving soortruimte,
|
|
SR.ALG_SRTRUIMTE_OMSCHRIJVING,
|
|
l.alg_district_key,
|
|
x.alg_ruimte_key,
|
|
b.fac_bookmark_id
|
|
FROM ALG_V_ALLONRGOED_GEGEVENS x,
|
|
alg_locatie l,
|
|
alg_district di,
|
|
fac_bookmark b,
|
|
alg_ruimte r,
|
|
alg_srtruimte sr
|
|
WHERE b.fac_bookmark_naam = 'QRC naar ruimte'
|
|
AND X.ALG_RUIMTE_KEY = R.ALG_RUIMTE_KEY
|
|
AND R.ALG_SRTRUIMTE_KEY = SR.ALG_SRTRUIMTE_KEY
|
|
AND x.alg_locatie_key = L.ALG_LOCATIE_KEY
|
|
AND l.alg_district_key = di.alg_district_key;
|
|
|
|
CREATE OR REPLACE VIEW STAM_V_CATERING_RUIMTE
|
|
(
|
|
RUIMTENR,
|
|
RUIMTEOMSCHR
|
|
)
|
|
AS
|
|
SELECT ALG_RUIMTE_KEY RUIMTE,
|
|
ALG_RUIMTE_NR || '/' || ALG_RUIMTE_OMSCHRIJVING
|
|
FROM ALG_RUIMTE R, ALG_ONRGOEDKENMERK K
|
|
WHERE K.ALG_ONRGOED_KEY = R.ALG_RUIMTE_KEY;
|
|
|
|
CREATE OR REPLACE PROCEDURE stam_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);
|
|
v_aantal_in_FCLT NUMBER;
|
|
BEGIN
|
|
v_errorhint := 'Generieke update';
|
|
-- de sequence array staat beschreven in PRS_PAC.SRC bij de prs.import_perslid proc
|
|
prs.import_perslid (
|
|
p_import_key,
|
|
'0;0;0;0;0;0;11;4;0;3;'
|
|
|| '0;0;0;0;0;7;8;1;0;5;'
|
|
|| '6;2;0;0;0;0;9;12;13;10;'
|
|
|| '0;0;0;0;0;0;0;0;0;0;'
|
|
|| '0;0;0;0;0;0',
|
|
'"mail";"samAccountName";"givenName";"sn";"employeeID";"title";"telephoneNumber";"mobile";"physicalDeliveryOfficeName";"department";"departmentNumber";"extensionAttribute1";"manager"%');
|
|
COMMIT;
|
|
|
|
--- locatie vanuit deze import is altijd Sittard
|
|
UPDATE fac_imp_perslid p
|
|
SET alg_locatie_code = 'NLSTD';
|
|
|
|
-- vanuit kenmerk1 moet het gebouw en de verdieping bepaald worden
|
|
UPDATE fac_imp_perslid p
|
|
SET alg_gebouw_code =
|
|
DECODE ( (SUBSTR (P.PRS_KENMERK1, 1, 2)),
|
|
'-1', 'Mercator 3',
|
|
'0.', 'Mercator 3',
|
|
'1.', 'Mercator 3',
|
|
'2.', 'Mercator 3',
|
|
'7.', 'Mercator 3',
|
|
'A.', 'Mercator 3',
|
|
''),
|
|
alg_verdieping_volgnr =
|
|
DECODE ( (SUBSTR (P.PRS_KENMERK1, 1, 2)),
|
|
'-1', '1',
|
|
'0.', '2',
|
|
'1.', '3',
|
|
'2.', '5',
|
|
'7.', '10',
|
|
'A.', '4',
|
|
'');
|
|
|
|
COMMIT;
|
|
|
|
-- op basis van de afdelingsomschrijving in kenmerk4 kan de juiste afdelingscode herleid worden
|
|
UPDATE fac_imp_perslid p
|
|
SET prs_afdeling_naam =
|
|
(SELECT distinct a.prs_afdeling_naam
|
|
FROM prs_afdeling a
|
|
WHERE UPPER (a.prs_afdeling_omschrijving) =
|
|
UPPER (p.prs_kenmerk4));
|
|
|
|
-- als gebouw en verdieping niet bepaald kunnen worden op basis van kenmerk1, dan betreft het buitenlandse mdw, of mdw van de moedermaatschappij. Deze komen op een dummy plek 'Unknown'
|
|
UPDATE fac_imp_perslid p
|
|
SET alg_ruimte_nr = 'Unknown',
|
|
alg_gebouw_code = 'Mercator 3',
|
|
alg_verdieping_volgnr = 2
|
|
WHERE alg_gebouw_code IS NULL;
|
|
|
|
-- de laatste positie van de waarde uit kenmerk1 bepalen het werkpleknummer voor alle medewerkers waar een gebouw en verdieping bepaald kon worden
|
|
UPDATE fac_imp_perslid p
|
|
SET prs_werkplek_volgnr = SUBSTR (P.PRS_KENMERK1, 8, 1)
|
|
WHERE alg_ruimte_nr IS NULL;
|
|
|
|
--- de eerste 6 posities van de waarde uit kenmerk1 bepalen het ruimtenr voor alle medewerkers waar een gebouw en verdieping bepaald kon worden
|
|
UPDATE fac_imp_perslid p
|
|
SET alg_ruimte_nr = SUBSTR (P.PRS_KENMERK1, 1, 6)
|
|
WHERE alg_ruimte_nr IS NULL;
|
|
|
|
--- uit kenmerk3 kan de manager herleid worden als alle 'ballast' eraf gehaald wordt
|
|
UPDATE fac_imp_perslid p
|
|
SET prs_kenmerk3 = SUBSTR(prs_kenmerk3, 4, (instr(prs_kenmerk3, ',')-4) )
|
|
WHERE prs_kenmerk3 IS NOT NULL;
|
|
|
|
--- de afdeling kan worden afgeleid uit de kostenplaats icm de manager van de afdeling (kenmerk1000)
|
|
UPDATE FAC_IMP_PERSLID i
|
|
SET prs_afdeling_naam =
|
|
(SELECT a.prs_afdeling_naam
|
|
FROM prs_kostenplaats kp,
|
|
prs_afdeling a,
|
|
prs_perslid p,
|
|
prs_kenmerklink kl
|
|
WHERE kp.prs_kostenplaats_upper(+) = UPPER (prs_kenmerk2)
|
|
AND kp.prs_kostenplaats_key = a.prs_kostenplaats_key
|
|
AND UPPER (i.prs_kenmerk3) = UPPER (p.prs_perslid_oslogin)
|
|
AND kl.prs_link_key = a.prs_afdeling_key
|
|
AND kl.prs_kenmerk_key = 1000
|
|
AND kl.prs_kenmerklink_waarde = p.prs_perslid_key);
|
|
|
|
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 stam_import_perslid;
|
|
/
|
|
|
|
CREATE OR REPLACE PROCEDURE stam_update_perslid (p_import_key IN NUMBER)
|
|
IS
|
|
-- Alle personen verwijderen die niet meer in import bestand voorkomen.
|
|
-- Match bij STAM is personeelnummer, hieronder de query om alle personen te verwijderen die:
|
|
-- a) niet meer in het importbestand staan, wel in Facilitor, en
|
|
-- b) waarvan de persoon in Facilitor een gevulde personeelsnummer heeft (leeg personeelsnummer van af blijven, dit handmatig ingevoerde persleden)
|
|
-- c) waarvan de persoon in Facilitor niet begint met een _ in de loginnaam (ook van af blijven)
|
|
-- d)
|
|
|
|
CURSOR c_del
|
|
IS
|
|
SELECT p.prs_perslid_key, p.prs_perslid_nr, pf.prs_perslid_naam_full
|
|
FROM fac_imp_perslid i, prs_perslid p, prs_v_perslid_fullnames_all pf
|
|
WHERE UPPER (p.prs_perslid_nr) = UPPER (i.prs_perslid_nr(+))
|
|
AND p.prs_perslid_verwijder IS NULL
|
|
AND SUBSTR (p.prs_perslid_oslogin, 1, 1) <> '_'
|
|
AND p.prs_perslid_nr IS NOT NULL
|
|
AND pf.prs_perslid_key = p.prs_perslid_key
|
|
AND i.prs_perslid_nr IS NULL
|
|
ORDER BY 2;
|
|
|
|
v_count NUMBER;
|
|
BEGIN
|
|
-- generic update
|
|
-- 'LOGIN' betekent dat op basis van Login wordt gematched.
|
|
-- 'NR' betekent dat op basis van Personeelsnummer wordt gematched.
|
|
-- 'A' betekent altijd alle (andere/overige) werkplekken verwijderen
|
|
prs.update_perslid (p_import_key, 'NR', NULL);
|
|
|
|
-- 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;
|
|
END stam_update_perslid;
|
|
/
|
|
|
|
CREATE OR REPLACE VIEW STAM_V_RAP_SEARCHRESULT
|
|
(
|
|
FCLT_F_DATUM,
|
|
FCLT_F_PERSOON,
|
|
FCLT_F_ZOEKTERM,
|
|
RESULTAAT,
|
|
FCLT_F_KEUZE_TYPE,
|
|
KEUZE_URL,
|
|
KEUZE_OMSCHRIJVING
|
|
)
|
|
AS
|
|
SELECT fac_gui_counter_date datum,
|
|
prs_perslid_naam_full persoon,
|
|
fgc.fac_gui_counter_info zoekterm,
|
|
COALESCE (result.result, 'Geen') resultaat,
|
|
COALESCE (choice.TYPE, 'Geen') keuze_type,
|
|
choice.url keuze_url,
|
|
choice.oms keuze_omschrijving
|
|
FROM fac_gui_counter fgc,
|
|
prs_v_perslid_fullnames pf,
|
|
(SELECT fac_gui_counter_refkey,
|
|
fac_gui_counter_info url,
|
|
'Reserveerbaar artikel' TYPE,
|
|
res_artikel_omschrijving oms
|
|
FROM fac_gui_counter fgc, res_artikel ra
|
|
WHERE fac_gui_counter_info IS NOT NULL
|
|
AND fac_gui_counter_group = 'searchchoice'
|
|
AND fac_gui_counter_info LIKE '%res_artikel%'
|
|
AND ra.res_artikel_key(+) =
|
|
fac.safe_to_number(SUBSTR (
|
|
fac_gui_counter_info,
|
|
(INSTR (fac_gui_counter_info,
|
|
'key=')
|
|
+ 4)))
|
|
UNION
|
|
SELECT fac_gui_counter_refkey,
|
|
fac_gui_counter_info,
|
|
'Reserveerbaar object',
|
|
res_deel_omschrijving
|
|
FROM fac_gui_counter fgc, res_deel rd
|
|
WHERE fac_gui_counter_info IS NOT NULL
|
|
AND fac_gui_counter_group = 'searchchoice'
|
|
AND fac_gui_counter_info LIKE '%res_deel%'
|
|
AND rd.res_deel_key(+) =
|
|
fac.safe_to_number(SUBSTR (
|
|
fac_gui_counter_info,
|
|
(INSTR (fac_gui_counter_info,
|
|
'key=')
|
|
+ 4)))
|
|
UNION
|
|
SELECT fac_gui_counter_refkey,
|
|
fac_gui_counter_info,
|
|
'Melding',
|
|
std.mld_stdmelding_omschrijving oms
|
|
FROM fac_gui_counter fgc, mld_stdmelding std
|
|
WHERE fac_gui_counter_info IS NOT NULL
|
|
AND fac_gui_counter_group = 'searchchoice'
|
|
AND fac_gui_counter_info LIKE '%stdm%'
|
|
AND std.mld_stdmelding_key(+) =
|
|
fac.safe_to_number(SUBSTR (
|
|
fac_gui_counter_info,
|
|
(INSTR (fac_gui_counter_info,
|
|
'=')
|
|
+ 1)))
|
|
UNION
|
|
SELECT fac_gui_counter_refkey,
|
|
fac_gui_counter_info,
|
|
'Kennisbank',
|
|
fac_faq_question oms
|
|
FROM fac_gui_counter fgc, fac_faq faq
|
|
WHERE fac_gui_counter_info IS NOT NULL
|
|
AND fac_gui_counter_group = 'searchchoice'
|
|
AND fac_gui_counter_info LIKE '%faq%'
|
|
AND fac_faq_key(+) =
|
|
fac.safe_to_number(SUBSTR (
|
|
fac_gui_counter_info,
|
|
(INSTR (fac_gui_counter_info,
|
|
'=')
|
|
+ 1)))
|
|
UNION
|
|
SELECT fac_gui_counter_refkey,
|
|
fac_gui_counter_info,
|
|
'Reserveerbare ruimte',
|
|
res_ruimte_nr oms
|
|
FROM fac_gui_counter fgc, res_ruimte
|
|
WHERE fac_gui_counter_info IS NOT NULL
|
|
AND fac_gui_counter_group = 'searchchoice'
|
|
AND fac_gui_counter_info LIKE '%res_ruimte%'
|
|
AND res_ruimte_key(+) =
|
|
fac.safe_to_number(SUBSTR (
|
|
fac_gui_counter_info,
|
|
(INSTR (fac_gui_counter_info,
|
|
'=')
|
|
+ 1)))
|
|
UNION
|
|
SELECT fac_gui_counter_refkey,
|
|
fac_gui_counter_info,
|
|
'Bestelling',
|
|
ins_discipline_omschrijving
|
|
FROM fac_gui_counter fgc, bes_discipline
|
|
WHERE fac_gui_counter_info IS NOT NULL
|
|
AND fac_gui_counter_group = 'searchchoice'
|
|
AND fac_gui_counter_info LIKE '%bes%'
|
|
AND ins_discipline_key(+) =
|
|
fac.safe_to_number(SUBSTR (
|
|
fac_gui_counter_info,
|
|
(INSTR (fac_gui_counter_info,
|
|
'dis_key=')
|
|
+ 8)))
|
|
UNION
|
|
SELECT fac_gui_counter_refkey,
|
|
fac_gui_counter_info,
|
|
'Telefoonboek',
|
|
prs_perslid_naam_full
|
|
FROM fac_gui_counter fgc, prs_v_perslid_fullnames pf
|
|
WHERE fac_gui_counter_info IS NOT NULL
|
|
AND fac_gui_counter_group = 'searchchoice'
|
|
AND fac_gui_counter_info LIKE '%phone%'
|
|
AND pf.prs_perslid_key(+) =
|
|
fac.safe_to_number(SUBSTR (
|
|
fac_gui_counter_info,
|
|
(INSTR (fac_gui_counter_info,
|
|
'=')
|
|
+ 1)))) choice,
|
|
(SELECT fac_gui_counter_refkey,
|
|
REPLACE (REPLACE (fac_gui_counter_info, '{', ''), '}', '')
|
|
result
|
|
FROM fac_gui_counter fgc
|
|
WHERE fac_gui_counter_info IS NOT NULL
|
|
AND fac_gui_counter_group = 'searchresult') result
|
|
WHERE fac_gui_counter_group = 'search'
|
|
AND fgc.fac_gui_counter_info IS NOT NULL
|
|
AND fgc.prs_perslid_key = pf.prs_perslid_key
|
|
AND choice.fac_gui_counter_refkey(+) = fgc.fac_gui_counter_key
|
|
AND result.fac_gui_counter_refkey(+) = fgc.fac_gui_counter_key;
|
|
|
|
CREATE OR REPLACE FORCE VIEW stam_v_noti_mutatie_res
|
|
(
|
|
sender,
|
|
receiver,
|
|
text,
|
|
code,
|
|
fac_srtnotificatie_key,
|
|
key,
|
|
xkey,
|
|
xemail,
|
|
xmobile
|
|
)
|
|
AS
|
|
SELECT DISTINCT
|
|
NULL sender,
|
|
NULL receiver,
|
|
REPLACE (n.fac_srtnotificatie_oms,
|
|
'##RES##',
|
|
r.res_reservering_key || '/' || r.res_rsv_ruimte_volgnr)
|
|
|| ' adjusted',
|
|
fac_srtnotificatie_code,
|
|
n.fac_srtnotificatie_key,
|
|
r.res_reservering_key,
|
|
NULL xkey,
|
|
'secretariat@stamicarbon.com' xemail,
|
|
NULL xmobile
|
|
FROM fac_tracking t, res_rsv_ruimte r, fac_srtnotificatie n
|
|
WHERE t.fac_tracking_refkey = r.res_rsv_ruimte_key
|
|
AND t.fac_srtnotificatie_key = 83 ---reservering is aangepast
|
|
AND r.res_activiteit_key <> 30
|
|
AND n.fac_srtnotificatie_code = 'CUST01'
|
|
AND t.fac_tracking_datum >
|
|
(SELECT fac_notificatie_job_nextrun
|
|
- fac_notificatie_job_interval / 24
|
|
FROM fac_notificatie_job
|
|
WHERE UPPER (fac_notificatie_job_view) =
|
|
'STAM_V_NOTI_MUTATIE_RES')
|
|
AND t.fac_tracking_datum <
|
|
(SELECT fac_notificatie_job_nextrun
|
|
FROM fac_notificatie_job
|
|
WHERE UPPER (fac_notificatie_job_view) =
|
|
'STAM_V_NOTI_MUTATIE_RES')
|
|
UNION ALL
|
|
SELECT DISTINCT
|
|
NULL sender,
|
|
NULL receiver,
|
|
REPLACE (n.fac_srtnotificatie_oms,
|
|
'##RES##',
|
|
r.res_reservering_key || '/' || r.res_rsv_ruimte_volgnr)
|
|
|| ' deleted',
|
|
fac_srtnotificatie_code,
|
|
n.fac_srtnotificatie_key,
|
|
r.res_reservering_key,
|
|
NULL xkey,
|
|
'secretariat@stamicarbon.com' xemail,
|
|
NULL xmobile
|
|
FROM fac_tracking t, res_rsv_ruimte r, fac_srtnotificatie n
|
|
WHERE t.fac_tracking_refkey = r.res_rsv_ruimte_key
|
|
AND t.fac_srtnotificatie_key = 87 --- reservering is verwijderd
|
|
AND r.res_activiteit_key <> 30
|
|
AND n.fac_srtnotificatie_code = 'CUST01'
|
|
AND t.fac_tracking_datum >
|
|
(SELECT fac_notificatie_job_nextrun
|
|
- fac_notificatie_job_interval / 24
|
|
FROM fac_notificatie_job
|
|
WHERE UPPER (fac_notificatie_job_view) =
|
|
'STAM_V_NOTI_MUTATIE_RES')
|
|
AND t.fac_tracking_datum <
|
|
(SELECT fac_notificatie_job_nextrun
|
|
FROM fac_notificatie_job
|
|
WHERE UPPER (fac_notificatie_job_view) =
|
|
'STAM_V_NOTI_MUTATIE_RES')
|
|
UNION ALL
|
|
SELECT DISTINCT
|
|
NULL sender,
|
|
NULL receiver,
|
|
'Recurrence ' || r.res_reservering_key || ' has been adjusted',
|
|
fac_srtnotificatie_code,
|
|
n.fac_srtnotificatie_key,
|
|
r.res_reservering_key,
|
|
NULL xkey,
|
|
'secretariat@stamicarbon.com' xemail,
|
|
NULL xmobile
|
|
FROM fac_tracking t, res_rsv_ruimte r, fac_srtnotificatie n
|
|
WHERE t.fac_tracking_refkey = r.res_rsv_ruimte_key
|
|
AND t.fac_srtnotificatie_key = 94 --- reeks is gewijzigd
|
|
AND r.res_activiteit_key <> 30
|
|
AND n.fac_srtnotificatie_code = 'CUST01'
|
|
AND t.fac_tracking_datum >
|
|
(SELECT fac_notificatie_job_nextrun
|
|
- fac_notificatie_job_interval / 24
|
|
FROM fac_notificatie_job
|
|
WHERE UPPER (fac_notificatie_job_view) =
|
|
'STAM_V_NOTI_MUTATIE_RES')
|
|
AND t.fac_tracking_datum <
|
|
(SELECT fac_notificatie_job_nextrun
|
|
FROM fac_notificatie_job
|
|
WHERE UPPER (fac_notificatie_job_view) =
|
|
'STAM_V_NOTI_MUTATIE_RES');
|
|
|
|
BEGIN
|
|
DBMS_UTILITY.COMPILE_SCHEMA (USER, FALSE);
|
|
END;
|
|
/
|
|
|
|
|
|
------ 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
|