diff --git a/FLOW/flow.sql b/FLOW/flow.sql new file mode 100644 index 000000000..78b44643d --- /dev/null +++ b/FLOW/flow.sql @@ -0,0 +1,210 @@ +-- +-- $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 = 'FLOW.SQL' +DEFINE dbuser = 'FLOW' + +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 FLOW +AS + + PROCEDURE flow_processemail(pfrom IN VARCHAR2, -- From-adres + pto IN VARCHAR2, -- To-adres + psubject IN VARCHAR2, -- onderwerp van de e-mail + pbody IN VARCHAR2, -- body van de e-mail + psessionid IN VARCHAR2, -- + puserkey IN NUMBER DEFAULT NULL); + +END; +/ + +CREATE OR REPLACE PACKAGE BODY FLOW +AS + + PROCEDURE flow_processemail(pfrom IN VARCHAR2, -- From-adres + pto IN VARCHAR2, -- To-adres + psubject IN VARCHAR2, -- onderwerp van de e-mail + pbody IN VARCHAR2, -- body van de e-mail + psessionid IN VARCHAR2, -- + puserkey IN NUMBER DEFAULT NULL) -- API user? + AS + v_count NUMBER; + defaultstdmelding fac_setting.fac_setting_default%TYPE; + sender prs_perslid.prs_perslid_key%TYPE; + owner prs_perslid.prs_perslid_key%TYPE; + v_kostenplaats_key prs_afdeling.prs_kostenplaats_key%TYPE; + v_melding_key mld_melding.mld_melding_key%TYPE; + kkey mld_kenmerk.mld_kenmerk_key%TYPE; + v_locatie_key NUMBER (10); + v_perslid_key NUMBER (10); + v_behandelaar_key NUMBER (10); + v_errormsg VARCHAR2 (1000); + oracle_err_num NUMBER; + oracle_err_mes VARCHAR2 (200); + + BEGIN + v_errormsg := 'Processing email from '||pfrom; + v_perslid_key := 22; -- Standaard alle meldingen naar Sandra + sender := 4; -- standaard naar hMail api user + v_kostenplaats_key := 1; -- FLOW_ALG + v_locatie_key:=1; + v_behandelaar_key:=22; + SELECT COUNT (*) + INTO v_count + FROM prs_v_aanwezigperslid + WHERE UPPER (prs_perslid_email) LIKE UPPER (pfrom) || '%'; + IF v_Count=1 + THEN + -- we kennen de persoon + SELECT p.prs_perslid_key, a.prs_kostenplaats_key, 1 + INTO v_perslid_key, v_kostenplaats_key, v_locatie_key + FROM prs_v_aanwezigperslid p, prs_afdeling a + WHERE p.prs_afdeling_key = a.prs_afdeling_key + AND p.prs_perslid_key=v_perslid_key; + ELSE + v_perslid_key := 4; + END IF; + CASE + WHEN UPPER(pto) LIKE 'MELDING@%' + THEN + v_errormsg := 'Getting std melding'; + defaultstdmelding := fac.getsetting ('defaultstdmelding'); + + BEGIN + v_errormsg := 'Inserting melding'; + INSERT INTO mld_melding (mld_melding_module, + mld_meldbron_key, + mld_alg_locatie_key, + mld_alg_onroerendgoed_keys, + mld_melding_datum, + mld_melding_omschrijving, + mld_stdmelding_key, + prs_kostenplaats_key, + prs_perslid_key, + prs_perslid_key_voor, + mld_melding_status, + mld_melding_spoed, + mld_melding_onderwerp, + mld_melding_behandelaar_key, + mld_ins_discipline_key) + VALUES ('MLD', + 4, -- email + v_locatie_key, + NULL, --v_onrgoed_keys, + SYSDATE, + pfrom || CHR (13) || CHR (10) || SUBSTR (pbody, 1, 2000), + defaultstdmelding, + v_kostenplaats_key, + v_perslid_key, + v_behandelaar_key, + NULL, + 3, -- prio normaal + SUBSTR (psubject, 1, 80), + v_behandelaar_key, + NULL) + RETURNING mld_melding_key + INTO v_melding_key; + + mld.setmeldingstatus (v_melding_key, 2, v_perslid_key); + + INSERT INTO fac_result (fac_result_sessionid, fac_result_naam, fac_result_waarde) + VALUES (psessionid, 'maillog', 'Geregistreerd onder melding ' || v_melding_key); + + + -- verwerk bijlagen + -- 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 = '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 = '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(v_melding_key/1000), 'FM0000') || '___\M' || v_melding_key || '\' || kkey || '\'); + END IF; + + + + + END; + + END CASE; + EXCEPTION + WHEN OTHERS + THEN + oracle_err_num := SQLCODE; + oracle_err_mes := SUBSTR (SQLERRM, 1, 200); + v_errormsg := v_errormsg || ' ORACLE (error ' || oracle_err_num || '/' || oracle_err_mes || ')'; + fac.writelog ('PROCESSEMAIL', 'E', 'BLOS_processemail afgebroken!', '[' || pfrom || '] ' || v_errormsg); + INSERT INTO fac_result (fac_result_sessionid, fac_result_naam, fac_result_waarde) + VALUES (psessionid, 'errormsg', 'Database fout - Neem contact op met uw systeembeheerder ('||oracle_err_num||')-'||oracle_err_mes); + COMMIT; + END; +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