325 lines
13 KiB
SQL
325 lines
13 KiB
SQL
--
|
|
-- $Id$
|
|
--
|
|
-- Script containing customer specific sql statements for the FACILITOR database
|
|
|
|
DEFINE thisfile = 'SZDB.SQL'
|
|
DEFINE dbuser = 'SZDB'
|
|
|
|
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 SZDB
|
|
AS
|
|
PROCEDURE processemail (pfrom IN VARCHAR2,
|
|
pto IN VARCHAR2,
|
|
psubject IN VARCHAR2,
|
|
pbody IN VARCHAR2,
|
|
psessionid IN VARCHAR2,
|
|
pemailkey IN NUMBER);
|
|
|
|
PROCEDURE mld_after_insert (p_melding_key IN NUMBER);
|
|
|
|
END;
|
|
/
|
|
|
|
CREATE OR REPLACE PACKAGE BODY SZDB
|
|
AS
|
|
-- Status: proven concept
|
|
PROCEDURE processemail (pfrom IN VARCHAR2,
|
|
pto IN VARCHAR2,
|
|
psubject IN VARCHAR2,
|
|
pbody IN VARCHAR2,
|
|
psessionid IN VARCHAR2,
|
|
pemailkey IN NUMBER
|
|
)
|
|
AS
|
|
sender prs_perslid.prs_perslid_key%TYPE;
|
|
kostenplaats prs_afdeling.prs_kostenplaats_key%TYPE;
|
|
newkey mld_melding.mld_melding_key%TYPE;
|
|
defaultstdmelding fac_setting.fac_setting_default%TYPE;
|
|
kkey_att mld_kenmerk.mld_kenmerk_key%TYPE;
|
|
kkey_mail mld_kenmerk.mld_kenmerk_key%TYPE;
|
|
errormsg fac_result.fac_result_waarde%TYPE;
|
|
BEGIN
|
|
-- Valideer de sender in pfrom: kennen we deze?
|
|
SELECT prs_perslid_key, d.prs_kostenplaats_key
|
|
INTO sender, kostenplaats
|
|
FROM prs_perslid p, prs_afdeling d
|
|
WHERE p.prs_afdeling_key = d.prs_afdeling_key
|
|
AND UPPER (prs_perslid_email) = UPPER (pfrom);
|
|
|
|
CASE
|
|
WHEN UPPER (pto) LIKE 'MELDING@%'
|
|
THEN
|
|
defaultstdmelding := 1;
|
|
kkey_att := 1;
|
|
kkey_mail := 2;
|
|
|
|
-- suggested extensions:
|
|
-- check for MLDUSE-write autorisations
|
|
-- parse the subject to find an appropriate stdmelding, if uniquely possible
|
|
-- append (as a note?) to an existing melding if #key is found in the subject
|
|
BEGIN
|
|
INSERT INTO mld_melding (mld_melding_module,
|
|
mld_meldbron_key,
|
|
mld_melding_datum,
|
|
mld_melding_onderwerp,
|
|
mld_melding_omschrijving,
|
|
mld_melding_status,
|
|
mld_stdmelding_key,
|
|
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 (pbody, 1, 4000),
|
|
CHR (13) || CHR (10) || CHR (13) || CHR (10),
|
|
CHR (13) || CHR (10)),
|
|
1,
|
|
4000), -- verwijder onnodige witregels
|
|
NULL,
|
|
defaultstdmelding,
|
|
sender,
|
|
sender,
|
|
kostenplaats,
|
|
3)
|
|
RETURNING mld_melding_key
|
|
INTO newkey;
|
|
|
|
|
|
INSERT INTO fac_result (fac_result_sessionid,
|
|
fac_result_naam,
|
|
fac_result_waarde)
|
|
VALUES (psessionid,
|
|
'kenmerkpath',
|
|
'MLD\M' || to_char( TRUNC(newkey/1000), 'FM0000') || '___\M' || newkey || '\' || kkey_att || '\');
|
|
|
|
INSERT INTO fac_result (fac_result_sessionid,
|
|
fac_result_naam,
|
|
fac_result_waarde)
|
|
VALUES (psessionid,
|
|
'kenmerkorgmailpath',
|
|
'MLD\M' || TO_CHAR (TRUNC (newkey / 1000), 'FM0000') || '___\M' || newkey || '\' || kkey_mail || '\');
|
|
|
|
mld.setmeldingstatus (newkey, 2, sender);
|
|
END;
|
|
ELSE
|
|
NULL;
|
|
END CASE;
|
|
|
|
IF errormsg IS NOT NULL
|
|
THEN
|
|
INSERT INTO fac_result (fac_result_sessionid,
|
|
fac_result_naam,
|
|
fac_result_waarde)
|
|
VALUES (psessionid, 'errormsg', errormsg);
|
|
END IF;
|
|
EXCEPTION
|
|
WHEN OTHERS
|
|
THEN
|
|
fac.writelog (
|
|
'PROCESSEMAIL',
|
|
'W',
|
|
'Mail kon niet verwerkt worden afzender: '
|
|
|| pfrom
|
|
|| '['
|
|
|| errormsg
|
|
|| ']',
|
|
'OTHERS (error '
|
|
|| SQLCODE
|
|
|| '/'
|
|
|| SUBSTR (SQLERRM, 1, 100)
|
|
|| ')');
|
|
INSERT INTO fac_result (fac_result_sessionid,
|
|
fac_result_naam,
|
|
fac_result_waarde)
|
|
VALUES (psessionid,
|
|
'errormsg',
|
|
'Database fout - Neem contact op met uw systeembeheerder');
|
|
END;
|
|
|
|
PROCEDURE mld_after_insert (p_melding_key IN NUMBER)
|
|
AS
|
|
c_kenmerk_key MLD_KENMERK.MLD_KENMERK_KEY%TYPE := 43; -- Datum kamer beschikbaar
|
|
v_kenmerk_oms MLD_KENMERK.MLD_KENMERK_OMSCHRIJVING%TYPE;
|
|
v_kenmerkm_waarde MLD_KENMERKMELDING.MLD_KENMERKMELDING_WAARDE%TYPE;
|
|
v_melding_oms MLD_MELDING.MLD_MELDING_OMSCHRIJVING%TYPE;
|
|
c_stdmelding_key MLD_STDMELDING.MLD_STDMELDING_KEY%TYPE := 111; -- Mutatie / Nieuwe client
|
|
v_stdmelding_key MLD_STDMELDING.MLD_STDMELDING_KEY%TYPE;
|
|
BEGIN
|
|
SELECT COALESCE (mld_kenmerk_omschrijving, mld_srtkenmerk_omschrijving)
|
|
INTO v_kenmerk_oms
|
|
FROM mld_kenmerk k, mld_srtkenmerk sk
|
|
WHERE k.mld_srtkenmerk_key = sk.mld_srtkenmerk_key
|
|
AND k.mld_kenmerk_key = c_kenmerk_key;
|
|
|
|
SELECT mld_melding_omschrijving, mld_stdmelding_key
|
|
INTO v_melding_oms, v_stdmelding_key
|
|
FROM mld_melding
|
|
WHERE mld_melding_key = p_melding_key;
|
|
|
|
IF v_stdmelding_key = c_stdmelding_key
|
|
THEN
|
|
v_kenmerkm_waarde := FLX.getflex ('MLD', c_kenmerk_key, p_melding_key);
|
|
|
|
IF v_kenmerkm_waarde IS NOT NULL
|
|
THEN
|
|
IF INSTR (v_melding_oms, v_kenmerk_oms) = 1
|
|
THEN
|
|
-- Het kenmerk staat al in de omschrijving. Dan overschrijven we die.
|
|
v_melding_oms :=
|
|
v_kenmerk_oms
|
|
|| ': '
|
|
|| v_kenmerkm_waarde
|
|
|| CHR (10)
|
|
|| SUBSTR (v_melding_oms,
|
|
LENGTH (v_kenmerk_oms) + 14,
|
|
3900);
|
|
ELSE
|
|
v_melding_oms :=
|
|
v_kenmerk_oms
|
|
|| ': '
|
|
|| v_kenmerkm_waarde
|
|
|| CHR (10)
|
|
|| SUBSTR (v_melding_oms, 1, 3900);
|
|
END IF;
|
|
|
|
UPDATE mld_melding
|
|
SET mld_melding_omschrijving = v_melding_oms
|
|
WHERE mld_melding_key = p_melding_key;
|
|
END IF;
|
|
END IF;
|
|
|
|
COMMIT;
|
|
END;
|
|
|
|
|
|
END;
|
|
/
|
|
|
|
CREATE OR REPLACE VIEW szdb_v_mutatie_status
|
|
AS
|
|
SELECT m.mld_melding_key,
|
|
mld_melding_datum,
|
|
LISTAGG (
|
|
km.mld_kenmerk_omschrijving
|
|
|| ': '
|
|
|| km.mld_kenmerkmelding_waarde,
|
|
CHR (10))
|
|
WITHIN GROUP (ORDER BY km.mld_kenmerk_volgnummer)
|
|
AS details,
|
|
l.alg_locatie_code,
|
|
l.alg_locatie_omschrijving,
|
|
aog.alg_gebouw_code,
|
|
aog.alg_gebouw_naam,
|
|
aog.alg_verdieping_code,
|
|
aog.alg_ruimte_nr,
|
|
aog.alg_ruimte_omschrijving,
|
|
FLX.getflex('MLD', 43, m.mld_melding_key) kamer_leeg,
|
|
ms.mld_statuses_omschrijving,
|
|
o.mld_opdr_bedrijfopdr_volgnr,
|
|
COALESCE (pf.prs_perslid_naam_full, b.prs_bedrijf_naam)
|
|
uitvoerder,
|
|
o.mld_opdr_plandatum,
|
|
os.mld_statusopdr_omschrijving,
|
|
o.mld_opdr_omschrijving
|
|
FROM mld_melding m,
|
|
mld_opdr o,
|
|
prs_v_perslid_fullnames_all pf,
|
|
prs_bedrijf b,
|
|
mld_statuses ms,
|
|
mld_statusopdr os,
|
|
alg_v_allonrgoed_gegevens aog,
|
|
alg_locatie l,
|
|
(SELECT km.mld_melding_key,
|
|
k.mld_kenmerk_volgnummer,
|
|
k.MLD_KENMERK_OMSCHRIJVING,
|
|
km.mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerk k, mld_kenmerkmelding km
|
|
WHERE k.mld_kenmerk_key = km.mld_kenmerk_key
|
|
AND k.mld_kenmerk_omschrijving IS NOT NULL) km
|
|
WHERE mld_stdmelding_key = 111 -- mutatie
|
|
AND m.mld_melding_key = o.mld_melding_key(+)
|
|
AND m.mld_melding_key = km.mld_melding_key(+)
|
|
AND o.mld_uitvoerende_keys = b.prs_bedrijf_key(+)
|
|
AND o.mld_uitvoerende_keys = pf.prs_perslid_key(+)
|
|
AND m.mld_melding_status = ms.mld_statuses_key
|
|
AND o.mld_statusopdr_key = os.mld_statusopdr_key(+)
|
|
AND m.mld_alg_onroerendgoed_keys = aog.alg_onroerendgoed_keys
|
|
AND m.mld_alg_locatie_key = l.alg_locatie_key
|
|
GROUP BY m.mld_melding_key,
|
|
ms.mld_statuses_omschrijving,
|
|
o.mld_opdr_bedrijfopdr_volgnr,
|
|
os.mld_statusopdr_omschrijving,
|
|
pf.prs_perslid_naam_full,
|
|
b.prs_bedrijf_naam,
|
|
o.mld_opdr_plandatum,
|
|
o.mld_opdr_omschrijving,
|
|
mld_melding_datum,
|
|
l.alg_locatie_code,
|
|
l.alg_locatie_omschrijving,
|
|
aog.alg_gebouw_code,
|
|
aog.alg_gebouw_naam,
|
|
aog.alg_verdieping_code,
|
|
aog.alg_ruimte_nr,
|
|
aog.alg_ruimte_omschrijving,
|
|
ms.mld_statuses_omschrijving;
|
|
|
|
-- Notificatie view om personen die een object op hun naam gekregen hebben te notificeren.
|
|
CREATE OR REPLACE VIEW szdb_v_noti_ins_2_prs
|
|
AS
|
|
SELECT 'CUST01' code,
|
|
NULL sender,
|
|
d.ins_alg_ruimte_key receiver,
|
|
'Ontvangstbevestiging ' || sd.ins_srtdeel_omschrijving || ' ' || d.ins_deel_omschrijving text,
|
|
d.ins_deel_key key,
|
|
NULL xkey
|
|
FROM fac_tracking t, ins_deel d, ins_srtdeel sd
|
|
WHERE t.fac_tracking_refkey = d.ins_deel_key
|
|
AND d.ins_srtdeel_key = sd.ins_srtdeel_key
|
|
AND UPPER (fac_tracking_oms) LIKE '%PLAATS OF EIGENAAR%'
|
|
AND fac_srtnotificatie_key = 137
|
|
AND ins_alg_ruimte_type = 'P'
|
|
AND t.fac_tracking_datum BETWEEN (SELECT fac_notificatie_job_nextrun
|
|
- fac_notificatie_job_interval
|
|
/ 24
|
|
FROM fac_notificatie_job
|
|
WHERE fac_notificatie_job_view =
|
|
'SZDB_V_NOTI_INS_2_PRS')
|
|
AND (SELECT fac_notificatie_job_nextrun
|
|
FROM fac_notificatie_job
|
|
WHERE fac_notificatie_job_view =
|
|
'SZDB_V_NOTI_INS_2_PRS');
|
|
|
|
|
|
------ 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
|