535 lines
22 KiB
SQL
535 lines
22 KiB
SQL
--
|
|
-- $Id$
|
|
--
|
|
-- Script containing customer specific sql statements for gemeente Den Helder (DHLD)
|
|
|
|
DEFINE thisfile = 'DHLD.SQL'
|
|
DEFINE dbuser = 'DHLD'
|
|
|
|
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 VIEW DHLD_V_RAP_MLD_QRC
|
|
(
|
|
FCLT_3D_LOCATIE_KEY,
|
|
FCLT_3D_DISCIPLINE_KEY,
|
|
FCLT_F_DISCIPLINE,
|
|
FCLT_F_SOORTMELDING,
|
|
FCLT_F_LOCATIE,
|
|
FCLT_F_GEBOUW,
|
|
FCLT_F_VERDIEPING,
|
|
PLAATS,
|
|
RUIMTE_KEY,
|
|
RUIMTEFUNCTIE,
|
|
FCLT_F_OBJECTDISCIPLINE,
|
|
FCLT_F_OBJECTGROEP,
|
|
OBJECTSOORT_KEY,
|
|
FCLT_F_OBJECTSOORT,
|
|
OBJECTSOORT_CODE,
|
|
INS_DEEL_KEY,
|
|
INS_DEEL_OMSCHRIJVING,
|
|
INS_DEEL_UPPER,
|
|
SERIENUMMER,
|
|
HIDE_F_BOOKMARK_ID,
|
|
URL
|
|
)
|
|
AS
|
|
SELECT l.alg_locatie_key,
|
|
disc.ins_discipline_key,
|
|
disc.ins_discipline_omschrijving,
|
|
msd.mld_stdmelding_omschrijving,
|
|
l.alg_locatie_omschrijving,
|
|
o.alg_gebouw_omschrijving,
|
|
o.alg_verdieping_omschrijving,
|
|
o.alg_plaatsaanduiding
|
|
plaats,
|
|
d.ins_alg_ruimte_key
|
|
ruimte_key,
|
|
sr.alg_srtruimte_omschrijving,
|
|
disc.ins_discipline_omschrijving,
|
|
sg.ins_srtgroep_omschrijving,
|
|
sd.ins_srtdeel_key,
|
|
sd.ins_srtdeel_omschrijving,
|
|
sd.ins_srtdeel_code,
|
|
d.ins_deel_key,
|
|
d.ins_deel_omschrijving,
|
|
d.ins_deel_upper,
|
|
(SELECT MAX (kmd.ins_kenmerkdeel_waarde)
|
|
FROM ins_kenmerkdeel kmd, ins_kenmerk km, ins_srtkenmerk skm
|
|
WHERE skm.ins_srtkenmerk_key = km.ins_srtkenmerk_key
|
|
AND km.ins_kenmerk_key = kmd.ins_kenmerk_key
|
|
AND skm.ins_srtkenmerk_key = 2 -- Serienummer
|
|
AND kmd.ins_deel_key = d.ins_deel_key)
|
|
AS serie_nummer,
|
|
b.fac_bookmark_id,
|
|
'https://dhld.facilitor.nl/?u='
|
|
|| b.fac_bookmark_id
|
|
|| CHR (38)
|
|
|| 'ins_key='
|
|
|| d.ins_deel_key
|
|
FROM (SELECT DECODE (
|
|
INSTR (
|
|
SUBSTR (
|
|
UPPER (fac_bookmark_query),
|
|
INSTR (UPPER (fac_bookmark_query), 'STDM_KEY=')),
|
|
'&'),
|
|
0, SUBSTR (
|
|
SUBSTR (
|
|
UPPER (fac_bookmark_query),
|
|
INSTR (UPPER (fac_bookmark_query), 'STDM_KEY=')),
|
|
10),
|
|
SUBSTR (
|
|
SUBSTR (
|
|
UPPER (fac_bookmark_query),
|
|
INSTR (UPPER (fac_bookmark_query), 'STDM_KEY=')),
|
|
10,
|
|
INSTR (
|
|
SUBSTR (
|
|
UPPER (fac_bookmark_query),
|
|
INSTR (UPPER (fac_bookmark_query),
|
|
'STDM_KEY=')),
|
|
'&')
|
|
- 10)) stdm_key,
|
|
fac_bookmark_id
|
|
FROM fac_bookmark
|
|
WHERE UPPER (fac_bookmark_path) = 'APPL/PDA/MELDING.ASP'
|
|
AND INSTR (UPPER (fac_bookmark_query), 'STDM_KEY') > 0) b, -- stdm_key-bookmarks
|
|
(SELECT sm.mld_stdmelding_key,
|
|
sm.mld_stdmelding_omschrijving,
|
|
si.ins_srtinstallatie_key ins_srtdeel_key
|
|
FROM mld_stdmelding sm, mld_stdmelding_srtinst si
|
|
WHERE sm.mld_stdmelding_key = si.mld_stdmelding_key
|
|
AND sm.mld_stdmelding_verwijder IS NULL
|
|
AND si.ins_srtinstallatie_niveau = 'S'
|
|
UNION ALL
|
|
SELECT sm.mld_stdmelding_key,
|
|
sm.mld_stdmelding_omschrijving,
|
|
sd.ins_srtdeel_key
|
|
FROM mld_stdmelding sm, mld_stdmelding_srtinst si, ins_srtdeel sd
|
|
WHERE sm.mld_stdmelding_key = si.mld_stdmelding_key
|
|
AND sm.mld_stdmelding_verwijder IS NULL
|
|
AND si.ins_srtinstallatie_niveau = 'G'
|
|
AND si.ins_srtinstallatie_key = sd.ins_srtgroep_key
|
|
UNION ALL
|
|
SELECT sm.mld_stdmelding_key,
|
|
sm.mld_stdmelding_omschrijving,
|
|
sd.ins_srtdeel_key
|
|
FROM mld_stdmelding sm,
|
|
mld_stdmelding_srtinst si,
|
|
ins_srtgroep sg,
|
|
ins_srtdeel sd
|
|
WHERE sm.mld_stdmelding_key = si.mld_stdmelding_key
|
|
AND sm.mld_stdmelding_verwijder IS NULL
|
|
AND si.ins_srtinstallatie_niveau = 'D'
|
|
AND si.ins_srtinstallatie_key = sg.ins_discipline_key
|
|
AND sg.ins_srtgroep_key = sd.ins_srtgroep_key) msd, -- object-meldingen
|
|
ins_v_aanwezigdeel d,
|
|
ins_srtdeel sd,
|
|
ins_srtgroep sg,
|
|
ins_discipline disc,
|
|
ins_v_alg_overzicht o,
|
|
alg_locatie l,
|
|
alg_ruimte r,
|
|
alg_srtruimte sr
|
|
WHERE fac.safe_to_number (b.stdm_key) = msd.mld_stdmelding_key
|
|
AND msd.ins_srtdeel_key = d.ins_srtdeel_key
|
|
AND d.ins_alg_ruimte_type IN ('T', 'R', 'W')
|
|
AND d.ins_deel_parent_key IS NULL
|
|
AND d.ins_srtdeel_key = sd.ins_srtdeel_key
|
|
AND sd.ins_srtgroep_key = sg.ins_srtgroep_key
|
|
AND sg.ins_discipline_key = disc.ins_discipline_key
|
|
AND d.ins_alg_ruimte_key = o.alg_onroerendgoed_keys
|
|
AND d.ins_alg_ruimte_type = o.alg_onroerendgoed_type
|
|
AND d.ins_alg_locatie_key = o.alg_locatie_key -- redundant?
|
|
AND o.alg_locatie_key = l.alg_locatie_key
|
|
AND d.ins_alg_ruimte_key = r.alg_ruimte_key
|
|
AND r.alg_srtruimte_key = sr.alg_srtruimte_key(+);
|
|
|
|
CREATE OR REPLACE PROCEDURE dhld_processemail (pfrom IN VARCHAR2,
|
|
pto IN VARCHAR2,
|
|
psubject IN VARCHAR2,
|
|
pbody IN VARCHAR2,
|
|
psessionid IN VARCHAR2,
|
|
pemailkey IN NUMBER)
|
|
AS
|
|
v_sender prs_perslid.prs_perslid_key%TYPE;
|
|
v_perslid_key prs_perslid.prs_perslid_key%TYPE;
|
|
v_kostenplaats prs_afdeling.prs_kostenplaats_key%TYPE;
|
|
v_kostenplaatsf prs_afdeling.prs_kostenplaats_key%TYPE;
|
|
v_kostenplaatsfa prs_afdeling.prs_kostenplaats_key%TYPE;
|
|
v_mldstat mld_melding.mld_melding_status%TYPE;
|
|
v_stdmelding mld_stdmelding.mld_stdmelding_key%TYPE;
|
|
v_behandelteam ins_tab_discipline.ins_discipline_key%TYPE;
|
|
v_stduitvoer mld_stdmelding.mld_stdmelding_t_uitvoertijd%TYPE;
|
|
v_errormsg fac_result.fac_result_waarde%TYPE;
|
|
v_from VARCHAR2 (4000);
|
|
v_from_key prs_perslid.prs_perslid_key%TYPE;
|
|
v_fromaddr VARCHAR2 (4000);
|
|
v_fromaddr_key prs_perslid.prs_perslid_key%TYPE;
|
|
v_body VARCHAR2 (4000);
|
|
m_body VARCHAR2 (4000);
|
|
v_mldkey mld_melding.mld_melding_key%TYPE;
|
|
v_mailorigin mld_kenmerk.mld_kenmerk_key%TYPE;
|
|
v_mailattach mld_kenmerk.mld_kenmerk_key%TYPE;
|
|
v_locatiekey alg_locatie.alg_locatie_key%TYPE;
|
|
v_stroming VARCHAR2 (255);
|
|
v_folder_kkey NUMBER (10);
|
|
v_opdracht_id VARCHAR2 (255);
|
|
v_opdracht_key NUMBER (10);
|
|
v_typeopdr_key NUMBER (10);
|
|
v_count NUMBER (10);
|
|
c_onbekend_key NUMBER (10) := 12141; -- Onbekend
|
|
-- v_van_email VARCHAR2 (255) := '';
|
|
BEGIN
|
|
v_sender := 3; --Standaard de persoon Facilitor
|
|
v_stdmelding := fac.safe_to_number (fac.getsetting ('defaultstdmelding'));
|
|
v_mailorigin := 362; --Kenmerk_key oorspronkelijke mail
|
|
v_mailattach := 1; --Kenmerk_key bijlagen bij vakgroeptype Meldingen (onderstaande 3 meldings-stromen vallen daar allen onder)
|
|
v_typeopdr_key := 5; --Opdrachttype Standaard
|
|
v_behandelteam := 175; --Default behandelteam Meldpunt
|
|
|
|
-- Bepalen Stroming: Facilitair of ICT (of anders)
|
|
CASE
|
|
WHEN UPPER (pto) LIKE 'MELDPUNT@%'
|
|
THEN
|
|
v_stdmelding := 242; --Overige meldingen Facilitair
|
|
v_behandelteam := 175; -- Behandelteam Meldpunt
|
|
v_stroming := 'melding';
|
|
WHEN UPPER (pto) LIKE 'HELPDESK@%'
|
|
THEN
|
|
v_stdmelding := 243; --Overige meldingen ICT
|
|
v_behandelteam := 167; -- Behandelteam Helpdesk
|
|
v_stroming := 'melding';
|
|
WHEN UPPER (pto) LIKE 'MELDINGEN-SYSTEEMBEHEER@%'
|
|
THEN
|
|
v_stdmelding := 341; --Overige meldingen ICT
|
|
v_behandelteam := 180; -- Behandelteam Systembeheer
|
|
v_stroming := 'melding';
|
|
WHEN UPPER (pto) LIKE 'REPLY_ORDERS@%'
|
|
THEN
|
|
v_stroming := 'opdracht';
|
|
ELSE
|
|
v_stdmelding :=
|
|
fac.safe_to_number (fac.getsetting ('defaultstdmelding'));
|
|
v_stroming := 'melding';
|
|
END CASE;
|
|
|
|
-- -- Verwijder de Bounce Address Tag Validation
|
|
--
|
|
-- v_errormsg := 'Verwijderen Bounce Address Tag';
|
|
--
|
|
-- IF pfrom LIKE 'prvs=%'
|
|
-- THEN
|
|
-- v_from := SUBSTR (pfrom, INSTR (pfrom, '=', -1) + 1);
|
|
-- ELSE
|
|
-- v_from := pfrom;
|
|
-- END IF;
|
|
|
|
SELECT fac_result_waarde
|
|
INTO v_from
|
|
FROM fac_result
|
|
WHERE fac_result_sessionid = psessionid AND fac_result_naam = 'from';
|
|
|
|
v_from := REPLACE (REPLACE (v_from, '>', ''), '<', '');
|
|
|
|
-- Valideer de sender in pfrom: kennen we deze?
|
|
v_errormsg := 'Valideren afzender';
|
|
|
|
SELECT COALESCE (MIN (p.prs_perslid_key), c_onbekend_key),
|
|
MIN (d.prs_kostenplaats_key)
|
|
INTO v_from_key, v_kostenplaatsf
|
|
FROM prs_perslid p, prs_afdeling d
|
|
WHERE p.prs_afdeling_key = d.prs_afdeling_key
|
|
AND p.prs_perslid_verwijder IS NULL
|
|
AND UPPER (prs_perslid_email) = UPPER (v_from);
|
|
|
|
-- Indien een mail is doorgestuurd, dan moet er teruggevallen worden op de v_fromaddr.
|
|
SELECT fac_result_waarde
|
|
INTO v_fromaddr
|
|
FROM fac_result
|
|
WHERE fac_result_sessionid = psessionid AND fac_result_naam = 'fromaddr';
|
|
|
|
v_fromaddr := REPLACE (REPLACE (v_fromaddr, '>', ''), '<', '');
|
|
|
|
SELECT MIN (p.prs_perslid_key), MIN (d.prs_kostenplaats_key)
|
|
INTO v_fromaddr_key, v_kostenplaatsfa
|
|
FROM prs_perslid p, prs_afdeling d
|
|
WHERE p.prs_afdeling_key = d.prs_afdeling_key
|
|
AND p.prs_perslid_verwijder IS NULL
|
|
AND UPPER (prs_perslid_email) = UPPER (v_fromaddr);
|
|
|
|
--Samenvoegen: afzender als deze bekend is (from), anders oorspronkelijke afzender bij doorgestuurd bericht (fromaddr)
|
|
SELECT COALESCE (v_fromaddr_key, v_from_key, c_onbekend_key),
|
|
COALESCE (v_kostenplaatsfa, v_kostenplaatsf)
|
|
INTO v_sender, v_kostenplaats
|
|
FROM DUAL;
|
|
|
|
v_body := pbody;
|
|
m_body := pbody;
|
|
|
|
CASE
|
|
WHEN v_stroming = 'melding'
|
|
THEN
|
|
--Hieronder de acties die gedaan moeten worden.
|
|
BEGIN
|
|
v_errormsg := 'Melding aanmaken' || pfrom || psubject;
|
|
v_mldstat := 2; -- Standaard de status in Nieuw (2).
|
|
v_stduitvoer :=
|
|
mld.getstduitvoer (v_stdmelding,
|
|
NULL,
|
|
NULL,
|
|
NULL);
|
|
|
|
INSERT INTO mld_melding (mld_melding_module,
|
|
mld_meldbron_key,
|
|
mld_melding_datum,
|
|
mld_melding_onderwerp,
|
|
mld_melding_omschrijving,
|
|
mld_melding_status,
|
|
mld_melding_t_uitvoertijd,
|
|
mld_stdmelding_key,
|
|
mld_ins_discipline_key,
|
|
mld_alg_locatie_key,
|
|
mld_melding_externnr,
|
|
prs_perslid_key,
|
|
prs_perslid_key_voor,
|
|
prs_kostenplaats_key,
|
|
mld_melding_spoed)
|
|
VALUES (
|
|
'MLD',
|
|
4, -- email
|
|
SYSDATE,
|
|
SUBSTR(psubject, 1, 200),
|
|
-- fac.safe_concat(
|
|
-- SUBSTR(psubject, 1, 200) || CHR(13) || CHR(10),
|
|
-- REPLACE(
|
|
-- pbody,
|
|
-- CHR(13) || CHR(10) || CHR(13) || CHR(10),
|
|
-- CHR(13) || CHR(10)
|
|
-- )
|
|
-- ),
|
|
fac.safe_concat(
|
|
'Mail van: ' || v_from || ':' || CHR(13) || CHR(10),
|
|
REPLACE(
|
|
v_body,
|
|
CHR(13) || CHR(10) || CHR(13) || CHR(10),
|
|
CHR(13) || CHR(10)
|
|
)
|
|
), -- verwijder onnodige witregels
|
|
v_mldstat,
|
|
NULL, -- v_stduitvoer
|
|
v_stdmelding,
|
|
v_behandelteam,
|
|
v_locatiekey, -- Locatie bepaald via standaardlocatie v_sender (indien ingesteld)
|
|
NULL,
|
|
v_sender,
|
|
v_sender,
|
|
v_kostenplaats,
|
|
3)
|
|
RETURNING mld_melding_key
|
|
INTO v_mldkey;
|
|
|
|
v_errormsg := 'Status melding';
|
|
mld.setmeldingstatus (v_mldkey, v_mldstat, v_sender);
|
|
|
|
INSERT INTO fac_result (fac_result_sessionid,
|
|
fac_result_naam,
|
|
fac_result_waarde)
|
|
VALUES (psessionid,
|
|
'maillog',
|
|
'Geregistreerd onder melding ' || v_mldkey);
|
|
END;
|
|
|
|
IF v_mldkey IS NOT NULL
|
|
THEN
|
|
BEGIN
|
|
-- Originele email wordt opgeslagen
|
|
v_errormsg :=
|
|
'Oorspronkelijke email opslaan'
|
|
|| v_mldkey
|
|
|| psubject;
|
|
|
|
INSERT INTO fac_result (fac_result_sessionid,
|
|
fac_result_naam,
|
|
fac_result_waarde)
|
|
VALUES (
|
|
psessionid,
|
|
'kenmerkorgmailpath',
|
|
'MLD\M'
|
|
|| TO_CHAR (TRUNC (v_mldkey / 1000),
|
|
'FM0000')
|
|
|| '___\M'
|
|
|| v_mldkey
|
|
|| '\'
|
|
|| v_mailorigin
|
|
|| '\');
|
|
END;
|
|
END IF;
|
|
|
|
|
|
v_errormsg := 'Fout toevoegen bijlage(n)';
|
|
|
|
IF v_mailattach IS NOT NULL
|
|
THEN
|
|
BEGIN
|
|
-- Toevoegen bijlage(n)
|
|
v_errormsg := 'Bijlagen opslaan' || v_mldkey || psubject;
|
|
|
|
INSERT INTO fac_result (fac_result_sessionid,
|
|
fac_result_naam,
|
|
fac_result_waarde)
|
|
VALUES (
|
|
psessionid,
|
|
'kenmerkpath',
|
|
'MLD\M'
|
|
|| TO_CHAR (TRUNC (v_mldkey / 1000),
|
|
'FM0000')
|
|
|| '___\M'
|
|
|| v_mldkey
|
|
|| '\'
|
|
|| v_mailattach
|
|
|| '\');
|
|
END;
|
|
END IF;
|
|
WHEN v_stroming = 'opdracht'
|
|
THEN
|
|
v_errormsg := 'Fout: de opdracht id kon niet worden bepaald';
|
|
v_opdracht_id := psubject;
|
|
|
|
IF REGEXP_INSTR (v_opdracht_id, '\d') > 0
|
|
THEN
|
|
v_opdracht_id :=
|
|
SUBSTR (v_opdracht_id,
|
|
REGEXP_INSTR (v_opdracht_id, '\d'))
|
|
|| ' '; -- Gedeelte vanaf eerste cijfer in v_exist_ticket plus ' '!
|
|
v_opdracht_id :=
|
|
SUBSTR (v_opdracht_id,
|
|
1,
|
|
REGEXP_INSTR (v_opdracht_id, '\s') - 1); -- Gedeelte tot eerste white space in v_exist_ticket!
|
|
END IF;
|
|
|
|
v_errormsg :=
|
|
'Fout: het opdrachtnummer kon niet worden bepaald'
|
|
|| v_opdracht_id;
|
|
|
|
SELECT mld_opdr_key, mld_typeopdr_key
|
|
INTO v_opdracht_key, v_typeopdr_key
|
|
FROM mld_opdr
|
|
WHERE TO_CHAR (mld_melding_key)
|
|
|| '/'
|
|
|| TO_CHAR (mld_opdr_bedrijfopdr_volgnr) =
|
|
SUBSTR (v_opdracht_id, REGEXP_INSTR (v_opdracht_id, '\d'));
|
|
|
|
v_errormsg := 'Fout toevoegen opdracht-notitie';
|
|
|
|
INSERT INTO mld_opdr_note (
|
|
mld_opdr_key,
|
|
prs_perslid_key,
|
|
mld_opdr_note_omschrijving
|
|
)
|
|
VALUES (
|
|
v_opdracht_key,
|
|
v_sender,
|
|
fac.safe_concat(
|
|
'Mail van: ' || NVL(v_from, '(onbekend)') || ':' || CHR(13) || CHR(10) ||
|
|
NVL(psubject, '') || CHR(13) || CHR(10),
|
|
REPLACE(
|
|
NVL(v_body, ''),
|
|
CHR(13) || CHR(10) || CHR(13) || CHR(10),
|
|
CHR(13) || CHR(10)
|
|
)
|
|
)
|
|
); -- verwijder onnodige witregels
|
|
|
|
-- Find the lowest volgnummer of the Folder-flexfield.
|
|
v_errormsg := 'Fout toevoegen opdracht-bijlage';
|
|
|
|
SELECT MIN (k1.mld_kenmerk_key)
|
|
INTO v_folder_kkey
|
|
FROM mld_kenmerk k1, mld_srtkenmerk sk1
|
|
WHERE k1.mld_typeopdr_key = v_typeopdr_key
|
|
AND k1.mld_kenmerk_verwijder IS NULL
|
|
AND k1.mld_kenmerk_niveau = 'O'
|
|
AND k1.mld_srtkenmerk_key = sk1.mld_srtkenmerk_key
|
|
AND sk1.mld_srtkenmerk_kenmerktype = 'M'
|
|
AND NOT EXISTS
|
|
(SELECT 1
|
|
FROM mld_kenmerk k2, mld_srtkenmerk sk2
|
|
WHERE k2.mld_typeopdr_key = v_typeopdr_key
|
|
AND k2.mld_kenmerk_verwijder IS NULL
|
|
AND k2.mld_kenmerk_niveau = 'O'
|
|
AND k2.mld_srtkenmerk_key =
|
|
sk2.mld_srtkenmerk_key
|
|
AND sk2.mld_srtkenmerk_kenmerktype = 'M'
|
|
AND k2.mld_kenmerk_volgnummer <
|
|
k1.mld_kenmerk_volgnummer);
|
|
|
|
IF v_folder_kkey IS NOT NULL
|
|
THEN
|
|
INSERT INTO fac_result (fac_result_sessionid,
|
|
fac_result_naam,
|
|
fac_result_waarde)
|
|
VALUES (
|
|
psessionid,
|
|
'kenmerkpath',
|
|
'MLD\O'
|
|
|| TO_CHAR (
|
|
TRUNC (v_opdracht_key / 1000),
|
|
'FM0000')
|
|
|| '___\O'
|
|
|| v_opdracht_key
|
|
|| '\'
|
|
|| v_folder_kkey
|
|
|| '\');
|
|
END IF;
|
|
END CASE;
|
|
EXCEPTION
|
|
WHEN OTHERS
|
|
THEN
|
|
INSERT INTO fac_result (fac_result_sessionid,
|
|
fac_result_naam,
|
|
fac_result_waarde)
|
|
VALUES (psessionid, 'maillog', SUBSTR(v_errormsg, 1, 4000));
|
|
|
|
fac.writelog(
|
|
'PROCESSEMAIL',
|
|
'E',
|
|
SUBSTR(
|
|
fac.safe_concat(
|
|
'Mail kon niet ingelezen worden afzender: ' || NVL(pfrom, '(onbekend)') || CHR(13) || CHR(10),
|
|
'[' || NVL(v_errormsg, '') || ' ' || NVL(v_mldkey, '') || ' ' || NVL(psubject, '') || ']'
|
|
),
|
|
1,
|
|
1000
|
|
),
|
|
'OTHERS (error ' || SQLCODE || '/' || SUBSTR(SQLERRM, 1, 100) || ')'
|
|
);
|
|
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
|