FCLT#85585 Standaardwerking van fac.processemail voor Mail2Melding uitbreiden
svn path=/Database/trunk/; revision=69116
This commit is contained in:
271
FAC/FAC_PAC.SRC
271
FAC/FAC_PAC.SRC
@@ -5345,162 +5345,143 @@ CREATE OR REPLACE PACKAGE BODY fac AS
|
||||
RETURN NULL;
|
||||
END;
|
||||
|
||||
-- Status: proven concept
|
||||
PROCEDURE processemail (pfrom IN VARCHAR2,
|
||||
pto IN VARCHAR2,
|
||||
psubject IN VARCHAR2,
|
||||
pbody IN VARCHAR2,
|
||||
psessionid IN VARCHAR2
|
||||
)
|
||||
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;
|
||||
stdm_default_disc mld_stdmelding.mld_stdmelding_default_disc%TYPE;
|
||||
kkey mld_kenmerk.mld_kenmerk_key%TYPE;
|
||||
errormsg fac_result.fac_result_waarde%TYPE;
|
||||
BEGIN
|
||||
-- Valideer de sender in pfrom: kennen we deze?
|
||||
SELECT p.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);
|
||||
-- Status: improved concept
|
||||
PROCEDURE processemail (pfrom IN VARCHAR2
|
||||
, pto IN VARCHAR2
|
||||
, psubject IN VARCHAR2
|
||||
, pbody IN VARCHAR2
|
||||
, psessionid IN VARCHAR2)
|
||||
AS
|
||||
sender prs_perslid.prs_perslid_key%TYPE;
|
||||
kostenplaats prs_afdeling.prs_kostenplaats_key%TYPE;
|
||||
newkey mld_melding.mld_melding_key%TYPE;
|
||||
thisstdmelding fac_email_setting.mld_stdmelding_key%TYPE;
|
||||
stdm_default_disc mld_stdmelding.mld_stdmelding_default_disc%TYPE;
|
||||
kkey mld_kenmerk.mld_kenmerk_key%TYPE;
|
||||
errormsg fac_result.fac_result_waarde%TYPE;
|
||||
BEGIN
|
||||
-- Valideer de sender in pfrom: kennen we deze?
|
||||
SELECT p.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 'SERVICEDESK@%'
|
||||
THEN
|
||||
defaultstdmelding := fac.getsetting ('defaultstdmelding');
|
||||
stdm_default_disc := getDefaultBehandelteam(defaultstdmelding);
|
||||
-- Kunnen we ook de NAW-variant toepassen (HSLE)?
|
||||
|
||||
-- Zoek welke melding we daar bij moeten aanmaken (max() voor NULL ipv no data found)
|
||||
SELECT MAX (mld_stdmelding_key)
|
||||
INTO thisstdmelding
|
||||
FROM fac_email_setting
|
||||
WHERE UPPER (pto) LIKE UPPER(fac_email_setting_user) || '@%' AND mld_stdmelding_key IS NOT NULL;
|
||||
|
||||
-- check for MLDUSE-write autorisation voor deze discipline
|
||||
|
||||
IF thisstdmelding IS NOT NULL
|
||||
THEN
|
||||
stdm_default_disc := getdefaultbehandelteam (thisstdmelding);
|
||||
|
||||
-- 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_omschrijving,
|
||||
mld_melding_status,
|
||||
mld_stdmelding_key,
|
||||
prs_perslid_key,
|
||||
prs_perslid_key_voor,
|
||||
prs_kostenplaats_key,
|
||||
mld_melding_spoed,
|
||||
mld_ins_discipline_key)
|
||||
VALUES ('MLD',
|
||||
4, -- email
|
||||
SYSDATE,
|
||||
SUBSTR (
|
||||
psubject || CHR (13)
|
||||
|| REPLACE (
|
||||
SUBSTR (pbody,
|
||||
1,
|
||||
4000 - (LENGTH (psubject) + 2)),
|
||||
CHR (13) || CHR (10) || CHR (13) || CHR (10),
|
||||
CHR (13) || CHR (10)),
|
||||
1,
|
||||
4000), -- verwijder onnodige witregels
|
||||
NULL,
|
||||
defaultstdmelding,
|
||||
sender,
|
||||
sender,
|
||||
kostenplaats,
|
||||
3,
|
||||
stdm_default_disc)
|
||||
RETURNING mld_melding_key
|
||||
INTO newkey;
|
||||
INSERT INTO mld_melding (mld_melding_module
|
||||
, mld_meldbron_key
|
||||
, mld_melding_datum
|
||||
, mld_melding_omschrijving
|
||||
, mld_melding_status
|
||||
, mld_stdmelding_key
|
||||
, prs_perslid_key
|
||||
, prs_perslid_key_voor
|
||||
, prs_kostenplaats_key
|
||||
, mld_melding_spoed
|
||||
, mld_ins_discipline_key)
|
||||
VALUES (
|
||||
'MLD'
|
||||
, 4
|
||||
, -- email
|
||||
SYSDATE
|
||||
, SUBSTR (
|
||||
psubject
|
||||
|| CHR (13)
|
||||
|| REPLACE (SUBSTR (pbody, 1, 4000 - (LENGTH (psubject) + 2)), CHR (13) || CHR (10) || CHR (13) || CHR (10), CHR (13) || CHR (10))
|
||||
, 1
|
||||
, 4000)
|
||||
, -- verwijder onnodige witregels
|
||||
NULL
|
||||
, thisstdmelding
|
||||
, sender
|
||||
, sender
|
||||
, kostenplaats
|
||||
, 3
|
||||
, stdm_default_disc)
|
||||
RETURNING mld_melding_key
|
||||
INTO newkey;
|
||||
|
||||
-- find the lowest volgnummer of the flexfield of type folder.
|
||||
SELECT MIN (mld_kenmerk_key)
|
||||
INTO kkey
|
||||
FROM mld_kenmerk k,
|
||||
mld_srtkenmerk sk,
|
||||
mld_stdmelding std,
|
||||
ins_tab_discipline d
|
||||
WHERE mld_srtkenmerk_kenmerktype = 'M'
|
||||
AND sk.mld_srtkenmerk_key = k.mld_srtkenmerk_key
|
||||
AND std.mld_stdmelding_key = defaultstdmelding
|
||||
AND std.mld_ins_discipline_key = d.ins_discipline_key
|
||||
AND ((k.mld_kenmerk_niveau = 'A' AND k.mld_stdmelding_key IS NULL)
|
||||
OR (k.mld_kenmerk_niveau = 'S' AND k.mld_stdmelding_key = std.mld_stdmelding_key)
|
||||
OR (k.mld_kenmerk_niveau = 'D' AND k.mld_stdmelding_key = d.ins_discipline_key)
|
||||
OR (k.mld_kenmerk_niveau = 'T' AND k.mld_stdmelding_key = d.ins_srtdiscipline_key))
|
||||
AND k.mld_kenmerk_verwijder IS NULL
|
||||
AND NOT EXISTS
|
||||
(SELECT mld_kenmerk_volgnummer
|
||||
FROM mld_kenmerk k1,
|
||||
mld_srtkenmerk sk1,
|
||||
mld_stdmelding std1,
|
||||
ins_tab_discipline d1
|
||||
WHERE sk1.mld_srtkenmerk_kenmerktype = 'M'
|
||||
AND sk1.mld_srtkenmerk_key =
|
||||
k1.mld_srtkenmerk_key
|
||||
AND std1.mld_stdmelding_key =
|
||||
defaultstdmelding
|
||||
AND std1.mld_ins_discipline_key =
|
||||
d1.ins_discipline_key
|
||||
AND ((k1.mld_kenmerk_niveau = 'A' AND k1.mld_stdmelding_key IS NULL)
|
||||
OR (k1.mld_kenmerk_niveau = 'S' AND k1.mld_stdmelding_key = std1.mld_stdmelding_key)
|
||||
OR (k1.mld_kenmerk_niveau = 'D' AND k1.mld_stdmelding_key = d1.ins_discipline_key)
|
||||
OR (k1.mld_kenmerk_niveau = 'T' AND k1.mld_stdmelding_key = d1.ins_srtdiscipline_key))
|
||||
AND k1.mld_kenmerk_verwijder IS NULL
|
||||
AND k1.mld_kenmerk_volgnummer >
|
||||
k.mld_kenmerk_volgnummer);
|
||||
-- find the lowest volgnummer of the flexfield of type folder.
|
||||
SELECT MIN (mld_kenmerk_key)
|
||||
INTO kkey
|
||||
FROM mld_kenmerk k
|
||||
, mld_srtkenmerk sk
|
||||
, mld_stdmelding std
|
||||
, ins_tab_discipline d
|
||||
WHERE mld_srtkenmerk_kenmerktype = 'M'
|
||||
AND sk.mld_srtkenmerk_key = k.mld_srtkenmerk_key
|
||||
AND std.mld_stdmelding_key = thisstdmelding
|
||||
AND std.mld_ins_discipline_key = d.ins_discipline_key
|
||||
AND ( (k.mld_kenmerk_niveau = 'A' AND k.mld_stdmelding_key IS NULL)
|
||||
OR (k.mld_kenmerk_niveau = 'S' AND k.mld_stdmelding_key = std.mld_stdmelding_key)
|
||||
OR (k.mld_kenmerk_niveau = 'D' AND k.mld_stdmelding_key = d.ins_discipline_key)
|
||||
OR (k.mld_kenmerk_niveau = 'T' AND k.mld_stdmelding_key = d.ins_srtdiscipline_key))
|
||||
AND k.mld_kenmerk_verwijder IS NULL
|
||||
AND NOT EXISTS
|
||||
(SELECT mld_kenmerk_volgnummer
|
||||
FROM mld_kenmerk k1
|
||||
, mld_srtkenmerk sk1
|
||||
, mld_stdmelding std1
|
||||
, ins_tab_discipline d1
|
||||
WHERE sk1.mld_srtkenmerk_kenmerktype = 'M'
|
||||
AND sk1.mld_srtkenmerk_key = k1.mld_srtkenmerk_key
|
||||
AND std1.mld_stdmelding_key = thisstdmelding
|
||||
AND std1.mld_ins_discipline_key = d1.ins_discipline_key
|
||||
AND ( (k1.mld_kenmerk_niveau = 'A' AND k1.mld_stdmelding_key IS NULL)
|
||||
OR (k1.mld_kenmerk_niveau = 'S' AND k1.mld_stdmelding_key = std1.mld_stdmelding_key)
|
||||
OR (k1.mld_kenmerk_niveau = 'D' AND k1.mld_stdmelding_key = d1.ins_discipline_key)
|
||||
OR (k1.mld_kenmerk_niveau = 'T' AND k1.mld_stdmelding_key = d1.ins_srtdiscipline_key))
|
||||
AND k1.mld_kenmerk_verwijder IS NULL
|
||||
AND k1.mld_kenmerk_volgnummer > k.mld_kenmerk_volgnummer);
|
||||
|
||||
IF kkey IS NOT NULL
|
||||
THEN
|
||||
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 || '\');
|
||||
END IF;
|
||||
IF kkey IS NOT NULL
|
||||
THEN
|
||||
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 || '\');
|
||||
END IF;
|
||||
|
||||
mld.setmeldingstatus (newkey, 2, sender);
|
||||
mld.setmeldingstatus (newkey, 2, sender);
|
||||
|
||||
IF stdm_default_disc IS NOT NULL
|
||||
THEN
|
||||
mld.notifybackoffice (newkey, 'MLDBHG', 2);
|
||||
END IF;
|
||||
IF stdm_default_disc IS NOT NULL
|
||||
THEN
|
||||
mld.notifybackoffice (newkey, 'MLDBHG', 2);
|
||||
END IF;
|
||||
END;
|
||||
ELSE
|
||||
ELSE
|
||||
-- Geen processor hiervoor
|
||||
NULL;
|
||||
END CASE;
|
||||
END IF;
|
||||
|
||||
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;
|
||||
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'
|
||||
, SUBSTR('Ontvangen mail van ' || pfrom || ' (' || psubject || ') kon niet verwerkt worden: ' || errormsg || '.', 1, 1000)
|
||||
, SUBSTR (SQLERRM, 1, 1000));
|
||||
|
||||
INSERT INTO fac_result (fac_result_sessionid, fac_result_naam, fac_result_waarde)
|
||||
VALUES (psessionid, 'errormsg', SUBSTR('Error during processemail'||errormsg, 1, 4000));
|
||||
END;
|
||||
|
||||
-- Is de meegegeven datum een feestdag
|
||||
FUNCTION isdatefeestdag(p_date IN DATE, pCalendarId IN VARCHAR2 DEFAULT 'Default')
|
||||
|
||||
@@ -2103,12 +2103,14 @@ CREATE_TABLE(fac_email_setting, 0)
|
||||
fac_email_setting_action VARCHAR2 (255),
|
||||
fac_email_setting_aanmaak DATE DEFAULT SYSDATE,
|
||||
fac_email_setting_expire DATE,
|
||||
fac_email_setting_attachpath VARCHAR2 (255),
|
||||
fac_email_setting_attachpath VARCHAR2 (255) DEFAULT '*flexfilespath',
|
||||
fac_email_setting_attachext VARCHAR2(255),
|
||||
fac_email_setting_reqattachext VARCHAR2(255),
|
||||
fac_email_setting_attachmaxkb NUMBER(10), -- Kilobyte
|
||||
fac_email_setting_loglevel NUMBER(3) DEFAULT 0 NOT NULL,
|
||||
fac_email_setting_opmerking VARCHAR2 (320),
|
||||
// Note: this column is defined in MLD_TAB.SRC
|
||||
// mld_stdmelding_key NUMBER(10) REFERENCES mld_stdmelding(mld_stdmelding_key) ON DELETE CASCADE,
|
||||
// Note: this column is defined in PRS_TAB.SRC
|
||||
// prs_perslid_key_auth NUMBER(10) REFERENCES prs_perslid(prs_perslid_key)
|
||||
CONSTRAINT fac_u_fac_email_setting_user UNIQUE(fac_email_setting_user, fac_email_setting_volgnr)
|
||||
|
||||
@@ -605,6 +605,11 @@ ALTER TABLE mld_stdmelding MODIFY mld_stdmelding_t_uitvoertijd NOT_NULL(mld_stdm
|
||||
ALTER TABLE mld_stdmelding MODIFY mld_stdmelding_t_uitvtijd_pr1 DEFAULT MLD_T_UITVOERTIJD(NULL, NULL);
|
||||
ALTER TABLE mld_stdmelding MODIFY mld_stdmelding_t_uitvtijd_pr2 DEFAULT MLD_T_UITVOERTIJD(NULL, NULL);
|
||||
ALTER TABLE mld_stdmelding MODIFY mld_stdmelding_t_uitvtijd_pr4 DEFAULT MLD_T_UITVOERTIJD(NULL, NULL);
|
||||
ALTER TABLE fac_email_setting ADD
|
||||
(
|
||||
mld_stdmelding_key
|
||||
NUMBER(10) REFERENCES mld_stdmelding(mld_stdmelding_key) ON DELETE CASCADE
|
||||
);
|
||||
ALTER TABLE ins_srtdeel ADD
|
||||
(
|
||||
mld_stdmelding_key
|
||||
|
||||
@@ -219,9 +219,15 @@ UPDATE prs_bedrijf SET prs_bedrijf_intern = NULL WHERE prs_bedrijf_intern = 0;
|
||||
ALTER TABLE prs_bedrijf
|
||||
ADD CONSTRAINT prs_c_prs_bedrijf_intern CHECK(prs_bedrijf_intern IS NULL OR prs_bedrijf_intern IN (1,2));
|
||||
|
||||
/////////////////////////////////////////////////////////////////////////////////////////// FCLT#00000
|
||||
/////////////////////////////////////////////////////////////////////////////////////////// LOGC#89125
|
||||
ALTER TABLE mld_melding_tag ADD mld_melding_tag_datum_acc DATE;
|
||||
|
||||
/////////////////////////////////////////////////////////////////////////////////////////// FCLT#85585
|
||||
ALTER TABLE fac_email_setting
|
||||
ADD (mld_stdmelding_key NUMBER (10) REFERENCES mld_stdmelding (mld_stdmelding_key) ON DELETE CASCADE);
|
||||
ALTER TABLE fac_email_setting
|
||||
MODIFY fac_email_setting_attachpath VARCHAR2 (255) DEFAULT '*flexfilespath';
|
||||
|
||||
/////////////////////////////////////////////////////////////////////////////////////////// FCLT#00000
|
||||
REGISTERONCE('$Id$')
|
||||
|
||||
|
||||
Reference in New Issue
Block a user