205 lines
7.0 KiB
SQL
205 lines
7.0 KiB
SQL
--
|
|
-- $Id$
|
|
--
|
|
-- Script containing customer specific sql statements for the FACILITOR database
|
|
-- Voor dbuser invullen: - indien script voor 1 klant is: 'AADS' (de klantcode, zoals vermeld in fac_version_cust)
|
|
-- - script is voor meerdere klanten: 'AAXX' (de groepcode, zoals vermeld in fac_version_group)
|
|
-- - script is voor meerdere klanten met naam volgens een bepaald patroon: '^AA|^ASMS|^GULU|^NMMS|^RABO|^ZKHM'
|
|
-- Ook als het script gedraaid wordt voor de verkeerde cust wordt er een logfile gemaakt.
|
|
-- (dit in tegenstelling tot sample_xxxx.sql)
|
|
|
|
DEFINE thisfile = 'FBEA.SQL'
|
|
DEFINE dbuser = 'FBEA'
|
|
|
|
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 PROCEDURE fbea_processemail (pfrom IN VARCHAR2,
|
|
pto IN VARCHAR2,
|
|
psubject IN VARCHAR2,
|
|
pbody IN VARCHAR2,
|
|
psessionid IN VARCHAR2,
|
|
pemailkey IN NUMBER)
|
|
AS
|
|
v_count NUMBER;
|
|
sender prs_perslid.prs_perslid_key%TYPE;
|
|
defaultstdmelding fac_setting.fac_setting_default%TYPE;
|
|
v_newkey mld_melding.mld_melding_key%TYPE;
|
|
v_gebouwkey mld_melding.mld_alg_onroerendgoed_keys%TYPE;
|
|
v_locatiekey mld_melding.mld_alg_locatie_key%TYPE;
|
|
errormsg fac_result.fac_result_waarde%TYPE;
|
|
BEGIN
|
|
-- Valideer de sender in pfrom: kennen we deze?
|
|
SELECT COUNT (*)
|
|
INTO v_count
|
|
FROM prs_perslid p
|
|
WHERE UPPER (prs_perslid_email) = UPPER (pfrom);
|
|
|
|
-- Bekende afzender --> dat is de melder
|
|
IF (v_count = 1)
|
|
THEN
|
|
SELECT prs_perslid_key
|
|
INTO sender
|
|
FROM prs_perslid p
|
|
WHERE UPPER (prs_perslid_email) = UPPER (pfrom);
|
|
|
|
-- Geen bekende afzender --> _FACILITOR
|
|
ELSE
|
|
SELECT prs_perslid_key
|
|
INTO sender
|
|
FROM prs_perslid p
|
|
WHERE prs_perslid_key = 3;
|
|
END IF;
|
|
|
|
CASE
|
|
-- Op basis van het mailadres bepalen we het gebouw waar de melding voor bedoeld is
|
|
-- Voorlopig doen we dat alleen voor Het Eemhuis en ICOON
|
|
-- 11 Eemhuis
|
|
-- 2 ICOON
|
|
-- 3 Bibliotheek Baarn
|
|
-- 4 Bibliotheek Bunschoten
|
|
-- 5 Bibliotheek Hoogland
|
|
-- 6 Scholen in de Kunst Hoogland
|
|
-- 7 Bibliotheek Leusden Aanbouw
|
|
-- 8 Scholen in de Kunst Leusden
|
|
-- 9 Scholen in de Kunst Soest
|
|
-- 10 Bibliotheek Woudenberg
|
|
-- 901 Bibliotheek Woudenberg - Boerderij
|
|
-- 921 Bibliotheek Leusden Boerderij
|
|
|
|
|
|
WHEN UPPER (pto) LIKE 'HETEEMHUIS@%'
|
|
THEN
|
|
v_gebouwkey := '1';
|
|
WHEN UPPER (pto) LIKE 'ICOON@%'
|
|
THEN
|
|
v_gebouwkey := '4';
|
|
ELSE
|
|
NULL;
|
|
END CASE;
|
|
|
|
-- suggested extensions:
|
|
-- check for MLDUSE-write autorisations
|
|
-- parse the subject to find an appropriate stdmelding, if uniquely possible
|
|
IF v_gebouwkey IS NOT NULL
|
|
THEN
|
|
BEGIN
|
|
SELECT g.alg_locatie_key
|
|
INTO v_locatiekey
|
|
FROM alg_gebouw g
|
|
WHERE g.alg_gebouw_key = v_gebouwkey;
|
|
|
|
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,
|
|
mld_alg_locatie_key,
|
|
mld_alg_onroerendgoed_keys,
|
|
prs_perslid_key,
|
|
prs_perslid_key_voor,
|
|
mld_melding_email_ext,
|
|
mld_melding_spoed)
|
|
VALUES (
|
|
'MLD',
|
|
4, -- email
|
|
SYSDATE,
|
|
SUBSTR (psubject, 1, 60),
|
|
SUBSTR (
|
|
REPLACE (
|
|
SUBSTR (pbody, 1, 4000),
|
|
CHR (13) || CHR (10) || CHR (13) || CHR (10),
|
|
CHR (13) || CHR (10)),
|
|
1,
|
|
4000), -- verwijder onnodige witregels
|
|
2,
|
|
61,
|
|
v_locatiekey,
|
|
v_gebouwkey,
|
|
sender,
|
|
sender,
|
|
pfrom,
|
|
3)
|
|
RETURNING mld_melding_key
|
|
INTO v_newkey;
|
|
|
|
INSERT INTO fac_result (fac_result_sessionid,
|
|
fac_result_naam,
|
|
fac_result_waarde)
|
|
VALUES (psessionid,
|
|
'maillog',
|
|
'Geregistreerd onder melding ' || v_newkey);
|
|
END;
|
|
|
|
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;
|
|
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 fbea_processemail;
|
|
/
|
|
|
|
|
|
------ 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 |