FCLT#85585 Standaardwerking van fac.processemail voor Mail2Melding uitbreiden savepoint

svn path=/Database/trunk/; revision=69168
This commit is contained in:
Peter Feij
2025-05-27 21:52:02 +00:00
parent 4ceee0d1f8
commit 359011d53e

View File

@@ -172,7 +172,12 @@ CREATE OR REPLACE PACKAGE fac
PROCEDURE registercustversion (pcustid IN VARCHAR2, pcustnr IN NUMBER);
FUNCTION getdbversion RETURN VARCHAR2;
FUNCTION getDefaultBehandelteam(p_stdm IN NUMBER) RETURN NUMBER;
PROCEDURE processemail (pfrom IN VARCHAR2, pto IN VARCHAR2, psubject IN VARCHAR2, pbody IN VARCHAR2, psessionid IN VARCHAR2);
PROCEDURE processemail (p_from IN VARCHAR2
, p_to IN VARCHAR2
, p_subject IN VARCHAR2
, p_body IN VARCHAR2
, p_session_id IN VARCHAR2
, p_email_set_key IN NUMBER);
FUNCTION isdatefeestdag(p_date IN DATE, pCalendarId IN VARCHAR2 DEFAULT 'Default') RETURN BOOLEAN;
FUNCTION calcnextcyclusdate (p_date IN DATE, p_mode IN NUMBER, p_eenheid IN NUMBER, p_periode IN NUMBER, p_bits IN NUMBER, pCalendarId IN VARCHAR2 DEFAULT 'Default') RETURN DATE;
FUNCTION nextcyclusdate (p_date IN DATE, p_mode IN NUMBER, p_eenheid IN NUMBER, p_periode IN NUMBER, p_bits IN NUMBER, p_steps IN NUMBER DEFAULT 0, p_ismjob IN NUMBER DEFAULT 0, pCalendarId IN VARCHAR2 DEFAULT 'Default') RETURN DATE;
@@ -5328,160 +5333,380 @@ CREATE OR REPLACE PACKAGE BODY fac AS
RETURN verstring;
END;
-- Hulpfuncties voor processemail
-- Haalt default Behandelteam op
FUNCTION getDefaultBehandelteam(p_stdm IN NUMBER)
FUNCTION getdefaultbehandelteam (p_stdm IN NUMBER)
RETURN NUMBER
IS
stdm_default_disc mld_stdmelding.mld_stdmelding_default_disc%TYPE;
BEGIN
SELECT mld_stdmelding_default_disc
INTO stdm_default_disc
FROM mld_stdmelding
WHERE mld_stdmelding_key = p_stdm;
RETURN stdm_default_disc;
SELECT mld_stdmelding_default_disc
INTO stdm_default_disc
FROM mld_stdmelding
WHERE mld_stdmelding_key = p_stdm;
RETURN stdm_default_disc;
EXCEPTION
WHEN NO_DATA_FOUND
THEN
RETURN NULL;
WHEN NO_DATA_FOUND
THEN
RETURN NULL;
END;
-- Status: improved concept
PROCEDURE processemail (pfrom IN VARCHAR2
, pto IN VARCHAR2
, psubject IN VARCHAR2
, pbody IN VARCHAR2
, psessionid IN VARCHAR2)
PROCEDURE processemail (p_from IN VARCHAR2
, p_to IN VARCHAR2
, p_subject IN VARCHAR2
, p_body IN VARCHAR2
, p_session_id IN VARCHAR2
, p_email_set_key IN NUMBER)
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;
-- Local variables
l_sender prs_perslid.prs_perslid_key%TYPE;
l_cost_center prs_afdeling.prs_kostenplaats_key%TYPE;
l_new_key mld_melding.mld_melding_key%TYPE;
l_std_message_key mld_stdmelding.mld_stdmelding_key%TYPE;
l_std_thirdparty_flag mld_stdmelding.mld_stdmelding_thirdparty%TYPE;
l_std_discipline_key mld_stdmelding.mld_ins_discipline_key%TYPE;
l_fallback_sender fac_email_setting.prs_perslid_key_auth%TYPE;
l_using_fallback BOOLEAN := FALSE;
l_existing_mld_key mld_melding.mld_melding_key%TYPE;
l_sender_email_ext mld_melding.mld_melding_email_ext%TYPE;
l_kenmerk_key mld_kenmerk.mld_kenmerk_key%TYPE;
l_error_msg fac_result.fac_result_waarde%TYPE;
l_default_disc mld_stdmelding.mld_ins_discipline_key%TYPE;
-- Precomputed cleaned body
l_clean_body VARCHAR2 (4000);
-- Clean up the email body: remove double blank lines, truncate to fit
FUNCTION clean_body_text (p_body IN VARCHAR2, p_subject IN VARCHAR2)
RETURN VARCHAR2
IS
l_text VARCHAR2 (4000);
BEGIN
l_text := REPLACE (SUBSTR (p_body, 1, 4000 - (LENGTH (p_subject) + 2)), CHR (13) || CHR (10) || CHR (13) || CHR (10), CHR (13) || CHR (10));
RETURN SUBSTR (l_text, 1, 4000);
END clean_body_text;
-- Helper function: extract existing ticket key
FUNCTION get_mld_key_from_subject (subj IN VARCHAR2, sndr IN NUMBER)
RETURN NUMBER
IS
m VARCHAR2 (4000);
d VARCHAR2 (10);
k NUMBER;
BEGIN
m :=
REGEXP_SUBSTR (subj
, '([A-Za-z]{1,3})?#?\d{1,10}'
, 1
, 1
, 'i');
IF m IS NOT NULL
THEN
d := REGEXP_SUBSTR (m, '\d{1,10}');
END IF;
IF d IS NOT NULL
THEN
SELECT MAX (mld_melding_key)
INTO k
FROM mld_melding
WHERE mld_melding_key = fac.safe_to_number (d) AND prs_perslid_key = sndr;
RETURN k;
END IF;
RETURN NULL;
EXCEPTION
WHEN NO_DATA_FOUND
THEN
RETURN NULL;
END;
-- Helper function: clean body text
FUNCTION clean_body (bod IN VARCHAR2, subj IN VARCHAR2)
RETURN VARCHAR2
IS
t VARCHAR2 (4000);
BEGIN
t := REPLACE (SUBSTR (bod, 1, 4000 - (LENGTH (subj) + 2)), CHR (13) || CHR (10) || CHR (13) || CHR (10), CHR (13) || CHR (10));
RETURN SUBSTR (t, 1, 4000);
END;
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);
-- Precompute body variants
l_clean_body := clean_body (p_body, p_subject);
-- Kunnen we ook de NAW-variant toepassen (HSLE)?
-- 1. Validate sender
BEGIN
SELECT p.prs_perslid_key, d.prs_kostenplaats_key
INTO l_sender, l_cost_center
FROM prs_perslid p JOIN prs_afdeling d ON p.prs_afdeling_key = d.prs_afdeling_key
WHERE p.prs_perslid_verwijder IS NULL
AND (p.prs_perslid_inactief IS NULL OR p.prs_perslid_inactief > SYSDATE)
AND (p.prs_perslid_einddatum IS NULL OR p.prs_perslid_einddatum > SYSDATE)
AND UPPER (p.prs_perslid_email) = UPPER (p_from);
EXCEPTION
WHEN NO_DATA_FOUND
THEN
l_sender := NULL;
fac.writelog ('PROCESSEMAIL'
, 'I'
, 'Unknown sender: ' || p_from
, NULL);
END;
-- 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;
-- 2. Fetch standard message config
BEGIN
SELECT s.mld_stdmelding_key
, s.mld_stdmelding_thirdparty
, s.mld_ins_discipline_key
, e.prs_perslid_key_auth
INTO l_std_message_key
, l_std_thirdparty_flag
, l_std_discipline_key
, l_fallback_sender
FROM fac_email_setting e JOIN mld_stdmelding s ON e.mld_stdmelding_key = s.mld_stdmelding_key
WHERE e.fac_email_setting_key = p_email_set_key
AND s.mld_stdmelding_verwijder IS NULL
AND (s.mld_stdmelding_vervaldatum IS NULL OR s.mld_stdmelding_vervaldatum > SYSDATE);
EXCEPTION
WHEN NO_DATA_FOUND
THEN
l_error_msg := 'Invalid email configuration';
fac.writelog ('PROCESSEMAIL'
, 'W'
, l_error_msg
, NULL);
RETURN;
END;
-- check for MLDUSE-write autorisation voor deze discipline
IF thisstdmelding IS NOT NULL
-- 3. Fallback if third-party
IF l_sender IS NULL AND l_std_thirdparty_flag = 1 AND l_fallback_sender IS NOT NULL
THEN
stdm_default_disc := getdefaultbehandelteam (thisstdmelding);
l_sender := l_fallback_sender;
l_using_fallback := TRUE;
fac.writelog ('PROCESSEMAIL'
, 'I'
, 'Using fallback sender for ' || p_from
, NULL);
END IF;
-- append (as a note?) to an existing melding if #key is found in the subject
IF l_sender IS NULL
THEN
l_error_msg := 'Sender unknown';
fac.writelog ('PROCESSEMAIL'
, 'W'
, l_error_msg
, NULL);
RETURN;
END IF;
-- 4. Authorization check
BEGIN
SELECT 1
INTO l_kenmerk_key
FROM fac_v_webgebruiker v
WHERE v.fac_functie_key = (SELECT fac_functie_key
FROM fac_functie
WHERE fac_functie_code = 'WEB_MLDUSE')
AND v.ins_discipline_key = l_std_discipline_key
AND v.prs_perslid_key = l_sender
AND v.fac_gebruiker_prs_level_write < 9
AND v.fac_gebruiker_alg_level_write < 9;
EXCEPTION
WHEN NO_DATA_FOUND
THEN
l_error_msg := 'Not authorized for discipline ' || l_std_discipline_key;
fac.writelog ('PROCESSEMAIL'
, 'W'
, l_error_msg
, NULL);
RETURN;
END;
-- 5. Create new or append
l_existing_mld_key := get_mld_key_from_subject (p_subject, l_sender);
IF l_existing_mld_key IS NULL
THEN
-- New melding
l_default_disc := fac.getdefaultbehandelteam (l_std_message_key);
IF l_using_fallback
THEN
l_sender_email_ext := p_from;
END IF;
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
, mld_melding_email_ext
, prs_kostenplaats_key
, mld_melding_spoed
, mld_ins_discipline_key)
VALUES ('MLD'
, 4
, SYSDATE
, p_subject
, l_clean_body
, NULL
, l_std_message_key
, l_sender
, l_sender
, l_sender_email_ext
, l_cost_center
, 3
, l_default_disc)
RETURNING mld_melding_key
INTO l_new_key;
mld.setmeldingstatus (l_new_key, 2, l_sender);
IF l_default_disc IS NOT NULL
THEN
mld.notifybackoffice (l_new_key, 'MLDBHG', 2);
END IF;
mld.mld_nextworkflowstep (l_new_key, -1);
-- logging voor de mailserver..
INSERT INTO fac_result (fac_result_sessionid, fac_result_naam, fac_result_waarde)
VALUES (p_session_id, 'maillog', 'Geregistreerd onder melding ' || TO_CHAR (l_new_key));
ELSE
-- Append note
INSERT INTO mld_melding_note (mld_melding_key
, mld_melding_note_omschrijving
, prs_perslid_key
, mld_melding_note_flag)
VALUES (l_existing_mld_key
, l_clean_body
, l_sender
, 1);
fac.trackaction ('MLDNOT'
, l_existing_mld_key
, l_sender
, NULL
, '#Notitie via email'); -- TODO notitie is zelf tracking toch, obsolete??
UPDATE mld_melding
SET mld_melding_actiecode = 128 + 1
WHERE mld_melding_key = l_existing_mld_key;
-- logging voor de mailserver..
INSERT INTO fac_result (fac_result_sessionid, fac_result_naam, fac_result_waarde)
VALUES (p_session_id, 'maillog', 'Notitie toegevoegd aan melding ' || TO_CHAR (l_existing_mld_key));
fac.writelog ('PROCESSEMAIL'
, 'I'
, 'Appended note to ' || l_existing_mld_key
, NULL);
l_new_key := l_existing_mld_key;
-- 6a. ORGMAIL kenmerk
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
, thisstdmelding
, sender
, sender
, kostenplaats
, 3
, stdm_default_disc)
RETURNING mld_melding_key
INTO newkey;
l_error_msg := 'Saving original mail body';
-- find the lowest volgnummer of the flexfield of type folder.
SELECT MIN (mld_kenmerk_key)
INTO kkey
SELECT k.mld_kenmerk_key
INTO l_kenmerk_key
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_stdmelding_key = l_std_message_key
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);
AND BITAND (k.mld_kenmerk_rolcode, 1) = 1
AND k.mld_kenmerk_code = 'ORGMAIL';
IF kkey IS NOT NULL
INSERT INTO fac_result (fac_result_sessionid, fac_result_naam, fac_result_waarde)
VALUES (p_session_id, 'kenmerkorgmailpath', 'MLD\M' || TO_CHAR (TRUNC (l_new_key / 1000), 'FM0000') || '___\M' || l_new_key || '\' || l_kenmerk_key || '\');
EXCEPTION
WHEN NO_DATA_FOUND
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);
IF stdm_default_disc IS NOT NULL
fac.writelog ('PROCESSEMAIL'
, 'I'
, 'Geen bijlagenkenmerk (code ORGMAIL) voor origineel bericht geconstateerd.'
, l_error_msg);
WHEN TOO_MANY_ROWS
THEN
mld.notifybackoffice (newkey, 'MLDBHG', 2);
END IF;
fac.writelog ('PROCESSEMAIL'
, 'I'
, 'Niet eenduidig bijlagenkenmerk (code ORGMAIL) voor origineel bericht geconstateerd.'
, l_error_msg);
END;
-- 6b. Attachment kenmerk
-- Ik denk dat we dat ook beter doen met een magic kenmerk_code
BEGIN
SELECT k.mld_kenmerk_key
INTO l_kenmerk_key
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 = l_std_message_key
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 BITAND (k.mld_kenmerk_rolcode, 1) = 1
AND k.mld_kenmerk_code = 'MAILATT';
INSERT INTO fac_result (fac_result_sessionid, fac_result_naam, fac_result_waarde)
VALUES (p_session_id, 'kenmerkpath', 'MLD\M' || TO_CHAR (TRUNC (l_new_key / 1000), 'FM0000') || '___\M' || l_new_key || '\' || l_kenmerk_key || '\');
EXCEPTION
WHEN NO_DATA_FOUND
THEN
fac.writelog ('PROCESSEMAIL'
, 'I'
, 'Geen bijlagenkenmerk (code MAILATT) voor bijlage geconstateerd.'
, l_error_msg);
WHEN TOO_MANY_ROWS
THEN
fac.writelog ('PROCESSEMAIL'
, 'I'
, 'Niet eenduidig bijlagenkenmerk (code MAILATT) voor bijlage geconstateerd.'
, l_error_msg);
END;
ELSE
-- Geen processor hiervoor
NULL;
END IF;
IF errormsg IS NOT NULL
-- 7. Final error
IF l_error_msg IS NOT NULL
THEN
INSERT INTO fac_result (fac_result_sessionid, fac_result_naam, fac_result_waarde)
VALUES (psessionid, 'errormsg', errormsg);
VALUES (p_session_id, 'errormsg', l_error_msg);
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));
, 'E'
, 'Error: ' || SQLERRM
, NULL);
INSERT INTO fac_result (fac_result_sessionid, fac_result_naam, fac_result_waarde)
VALUES (psessionid, 'errormsg', SUBSTR('Error during processemail'||errormsg, 1, 4000));
END;
VALUES (p_session_id, 'errormsg', 'Unexpected error');
END processemail;
-- Is de meegegeven datum een feestdag
FUNCTION isdatefeestdag(p_date IN DATE, pCalendarId IN VARCHAR2 DEFAULT 'Default')