FSN#36519 -- Toevoegen factuurimport via mail
svn path=/Customer/trunk/; revision=30990
This commit is contained in:
508
DEMO/demo.sql
508
DEMO/demo.sql
@@ -4130,10 +4130,516 @@ AS
|
||||
ON tot.res_ruimte_key = ruimte.res_ruimte_key)
|
||||
WHERE tot IS NULL OR (SYSDATE BETWEEN tot AND drempel);
|
||||
|
||||
-- procedure om ontvangen emails te processen. De klant specifieke eigenschappen, keys e.d. moeten
|
||||
-- in de aanroep meegegeven worden.
|
||||
CREATE OR REPLACE PROCEDURE demo_processemail (
|
||||
pfrom IN VARCHAR2,
|
||||
pto IN VARCHAR2,
|
||||
psubject IN VARCHAR2,
|
||||
pbody IN VARCHAR2,
|
||||
psessionid IN VARCHAR2,
|
||||
puserkey IN NUMBER DEFAULT NULL)
|
||||
AS
|
||||
sender_key prs_perslid.prs_perslid_key%TYPE;
|
||||
melder_key prs_perslid.prs_perslid_key%TYPE;
|
||||
kostenplaats_key prs_afdeling.prs_kostenplaats_key%TYPE;
|
||||
mldkey mld_melding.mld_melding_key%TYPE;
|
||||
opdrkey mld_opdr.mld_opdr_key%TYPE;
|
||||
stdmelding mld_stdmelding.mld_stdmelding_key%TYPE;
|
||||
subject_regexp fac_setting.fac_setting_default%TYPE;
|
||||
kkey mld_kenmerk.mld_kenmerk_key%TYPE;
|
||||
errormsg fac_result.fac_result_waarde%TYPE;
|
||||
behandelaar_key mld_melding.mld_melding_behandelaar_key%TYPE;
|
||||
typeopdrkey mld_typeopdr.mld_typeopdr_key%TYPE;
|
||||
mldnum VARCHAR2 (4000);
|
||||
opdrnum VARCHAR2 (4000);
|
||||
opdrvolgnr NUMBER (10);
|
||||
srtdisc VARCHAR2 (4000);
|
||||
cnt NUMBER (10);
|
||||
v_flag_on_fenote NUMBER (10);
|
||||
v_flag_on_bonote NUMBER (10);
|
||||
v_from VARCHAR2 (4000);
|
||||
v_body VARCHAR2 (4000);
|
||||
v_subject VARCHAR2 (1000);
|
||||
v_pos NUMBER;
|
||||
v_factuur_key fin_factuur.fin_factuur_key%TYPE;
|
||||
BEGIN
|
||||
errormsg := '(0x143)';
|
||||
|
||||
-- de mailberichten worden doorgestuurd vanuit de AAFM exchange omgeving. Hierbij
|
||||
-- is het niet mogelijk de afzender te laten staan. Daarom wordt de afzender in het subject
|
||||
-- van de mail geplaatst. Scheidingsteken in de ';'.
|
||||
v_from := SUBSTR (psubject, 1, INSTR (psubject, ';') - 1);
|
||||
v_subject := SUBSTR (psubject, INSTR (psubject, ';') + 1);
|
||||
|
||||
-- Verwijder de Bounce Address Tag Validation
|
||||
IF v_from LIKE 'prvs=%'
|
||||
THEN
|
||||
v_from := SUBSTR (v_from, INSTR (v_from, '=', -1) + 1);
|
||||
END IF;
|
||||
|
||||
|
||||
v_body :=
|
||||
v_from || ': ' || CHR (13) || CHR (10)
|
||||
|| SUBSTR (
|
||||
v_subject || CHR (13) || CHR (10)
|
||||
|| REPLACE (SUBSTR (pbody, 1, 3900 - (LENGTH (v_subject) + 2)),
|
||||
CHR (13) || CHR (10) || CHR (13) || CHR (10),
|
||||
CHR (13) || CHR (10)),
|
||||
1,
|
||||
3900); -- verwijder onnodige witregels
|
||||
|
||||
-- DBMS_OUTPUT.PUT_LINE('v_from: '||v_from);
|
||||
|
||||
-- Valideer de sender in pfrom: kennen we deze?
|
||||
SELECT MIN (prs_perslid_key), MIN (d.prs_kostenplaats_key)
|
||||
INTO sender_key, kostenplaats_key
|
||||
FROM prs_perslid p, prs_afdeling d
|
||||
WHERE p.prs_afdeling_key = d.prs_afdeling_key
|
||||
AND prs_perslid_verwijder IS NULL
|
||||
AND UPPER (prs_perslid_email) = UPPER (v_from);
|
||||
|
||||
IF sender_key IS NULL
|
||||
THEN
|
||||
sender_key := 11; -- prs_perslid_key onbekend mail adres.
|
||||
|
||||
SELECT d.prs_kostenplaats_key
|
||||
INTO kostenplaats_key
|
||||
FROM prs_perslid p, prs_afdeling d
|
||||
WHERE p.prs_afdeling_key = d.prs_afdeling_key
|
||||
AND prs_perslid_verwijder IS NULL
|
||||
AND p.prs_perslid_key = sender_key;
|
||||
END IF;
|
||||
|
||||
CASE
|
||||
WHEN UPPER (pto) LIKE 'INVOICE@%'
|
||||
THEN
|
||||
INSERT INTO fin_factuur (fin_factuur_statuses_key,
|
||||
fin_factuur_datum,
|
||||
fin_factuur_totaal_btw,
|
||||
fin_factuur_nr)
|
||||
VALUES (3,
|
||||
SYSDATE,
|
||||
0,
|
||||
' ')
|
||||
RETURNING fin_factuur_key
|
||||
INTO v_factuur_key;
|
||||
|
||||
-- Zet kenmerk laatste factuur op Ja
|
||||
INSERT INTO fin_kenmerkfactuur (fin_factuur_key, fin_kenmerk_key, fin_kenmerkfactuur_waarde)
|
||||
VALUES (v_factuur_key, 2, 201);
|
||||
|
||||
INSERT INTO fac_result (fac_result_sessionid,
|
||||
fac_result_naam,
|
||||
fac_result_waarde)
|
||||
VALUES (psessionid,
|
||||
'kenmerkpath',
|
||||
'FIN\F'
|
||||
|| TO_CHAR (TRUNC (v_factuur_key / 1000), 'FM0000')
|
||||
|| '___\F'
|
||||
|| v_factuur_key
|
||||
|| '\'
|
||||
|| 1
|
||||
|| '\');
|
||||
WHEN UPPER (pto) LIKE 'SERVICEDESK@%'
|
||||
THEN
|
||||
errormsg := '(0x145)';
|
||||
|
||||
-- append (as a note?) to an existing melding if #key is found in the subject
|
||||
-- Alternatief was: scannen van fac_srtnotificatie_oms maar dat voelt ook niet echt lekker
|
||||
-- subject_regexp := fac.getsetting ('mld_reply_subject_regexp'); -- [[:alpha:]]*[[:digit:]]{3,}
|
||||
|
||||
-- hebben we een referentie naar een opdracht of naar een melding?
|
||||
subject_regexp := '[[:digit:]]{3,}/[[:digit:]]*';
|
||||
opdrnum :=
|
||||
REGEXP_SUBSTR (v_subject,
|
||||
subject_regexp,
|
||||
1,
|
||||
1,
|
||||
'i'); -- MA12345
|
||||
|
||||
DBMS_OUTPUT.put_line ('opdrnum: ' || opdrnum);
|
||||
|
||||
IF opdrnum IS NOT NULL
|
||||
THEN
|
||||
opdrvolgnr :=
|
||||
fac.safe_to_number (
|
||||
SUBSTR (opdrnum, INSTR (opdrnum, '/') + 1));
|
||||
DBMS_OUTPUT.put_line ('opdrvolgnr: ' || opdrvolgnr);
|
||||
|
||||
mldkey :=
|
||||
fac.safe_to_number (
|
||||
SUBSTR (opdrnum, 1, INSTR (opdrnum, '/') - 1));
|
||||
DBMS_OUTPUT.put_line ('mldkey: ' || mldkey);
|
||||
ELSE
|
||||
subject_regexp := '[[:alpha:]]*[[:digit:]]{3,}';
|
||||
mldnum :=
|
||||
REGEXP_SUBSTR (v_subject,
|
||||
subject_regexp,
|
||||
1,
|
||||
1,
|
||||
'i'); -- MA12345
|
||||
srtdisc :=
|
||||
REGEXP_SUBSTR (mldnum,
|
||||
'[[:alpha:]]*',
|
||||
1,
|
||||
1,
|
||||
'i'); -- MA
|
||||
mldkey :=
|
||||
fac.safe_to_number (SUBSTR (mldnum, LENGTH (srtdisc) + 1));
|
||||
END IF;
|
||||
|
||||
DBMS_OUTPUT.put_line ('mldnum: ' || mldnum);
|
||||
DBMS_OUTPUT.put_line ('srtdisc: ' || srtdisc);
|
||||
DBMS_OUTPUT.put_line ('mldkey: ' || mldkey);
|
||||
|
||||
-- We eisen
|
||||
-- - Goed meldingnummer
|
||||
-- - Goede srtdiscipline
|
||||
-- - Afzender is degene voor wie de melding was
|
||||
-- suggested extensions: ook collega's toestaan?
|
||||
SELECT MIN (mm.mld_stdmelding_key), MIN (prs_perslid_key_voor)
|
||||
INTO stdmelding, melder_key
|
||||
FROM mld_melding mm,
|
||||
mld_stdmelding msm,
|
||||
ins_tab_discipline insd,
|
||||
ins_srtdiscipline isd
|
||||
WHERE mm.mld_melding_key = mldkey
|
||||
AND mm.mld_stdmelding_key = msm.mld_stdmelding_key
|
||||
AND msm.mld_ins_discipline_key = insd.ins_discipline_key
|
||||
AND insd.ins_srtdiscipline_key = isd.ins_srtdiscipline_key;
|
||||
|
||||
-- Controle op srtdisc werkt niet goed. Mails worden na binnenkomst namelijk doorgezet
|
||||
-- naar de definitieve stdmelding(/discipline/srtdiscpline) en daarmee verandert de
|
||||
-- prefix letter
|
||||
--AND isd.ins_srtdiscipline_prefix = srtdisc
|
||||
--AND mm.prs_perslid_key_voor = sender; -- Mogen anderen ook reageren?
|
||||
|
||||
DBMS_OUTPUT.put_line (
|
||||
'mld_stdmelding_key: ' || TO_CHAR (stdmelding));
|
||||
|
||||
-- kijk of de referentie naar de opdracht wel correct is:
|
||||
IF opdrvolgnr IS NOT NULL
|
||||
THEN
|
||||
BEGIN
|
||||
SELECT mld_opdr_key, mld_typeopdr_key
|
||||
INTO opdrkey, typeopdrkey
|
||||
FROM mld_opdr
|
||||
WHERE mld_melding_key = mldkey
|
||||
AND mld_opdr_bedrijfopdr_volgnr = opdrvolgnr;
|
||||
EXCEPTION
|
||||
WHEN OTHERS
|
||||
THEN
|
||||
opdrkey := NULL;
|
||||
END;
|
||||
END IF;
|
||||
|
||||
BEGIN
|
||||
IF opdrkey IS NOT NULL
|
||||
THEN
|
||||
SELECT o.prs_perslid_key
|
||||
INTO behandelaar_key
|
||||
FROM mld_opdr o, prs_perslid p
|
||||
WHERE o.mld_opdr_key = opdrkey
|
||||
AND o.prs_perslid_key = p.prs_perslid_key
|
||||
AND p.prs_perslid_email IS NOT NULL
|
||||
AND p.prs_perslid_verwijder IS NULL;
|
||||
ELSE
|
||||
SELECT mld_melding_behandelaar_key
|
||||
INTO behandelaar_key
|
||||
FROM mld_melding m, prs_perslid p
|
||||
WHERE mld_melding_key = mldkey
|
||||
AND mld_melding_behandelaar_key = p.prs_perslid_key
|
||||
AND p.prs_perslid_email IS NOT NULL
|
||||
AND p.prs_perslid_verwijder IS NULL;
|
||||
END IF;
|
||||
EXCEPTION
|
||||
WHEN OTHERS
|
||||
THEN
|
||||
behandelaar_key := NULL;
|
||||
END;
|
||||
|
||||
IF (stdmelding IS NOT NULL)
|
||||
THEN -- Bestaande opdracht.
|
||||
IF opdrkey IS NOT NULL
|
||||
THEN
|
||||
INSERT INTO mld_opdr_note (mld_opdr_key,
|
||||
mld_opdr_note_omschrijving,
|
||||
prs_perslid_key)
|
||||
VALUES (opdrkey, v_body, sender_key);
|
||||
|
||||
fac.trackaction ('ORDUPD',
|
||||
opdrkey,
|
||||
sender_key,
|
||||
NULL,
|
||||
'#Notitie toegevoegd vanuit e-mail'); -- # voorkomt notificatie
|
||||
DBMS_OUTPUT.put_line ('Notitie toegevoegd.');
|
||||
ELSE
|
||||
INSERT INTO mld_melding_note (mld_melding_key,
|
||||
mld_melding_note_omschrijving,
|
||||
prs_perslid_key,
|
||||
mld_melding_note_flag)
|
||||
VALUES (mldkey,
|
||||
v_body,
|
||||
sender_key,
|
||||
DECODE (sender_key, melder_key, 1, 0)); -- 1 is zichtbaar FE want zelf ingevoerd.
|
||||
|
||||
fac.trackaction ('MLDNOT',
|
||||
mldkey,
|
||||
sender_key,
|
||||
NULL,
|
||||
'#Notitie toegevoegd vanuit e-mail'); -- # voorkomt notificatie
|
||||
DBMS_OUTPUT.put_line ('Notitie toegevoegd.');
|
||||
|
||||
INSERT INTO fac_result (fac_result_sessionid,
|
||||
fac_result_naam,
|
||||
fac_result_waarde)
|
||||
VALUES (psessionid,
|
||||
'maillog',
|
||||
'Als notitie toegevoegd aan melding ' || mldkey);
|
||||
|
||||
IF behandelaar_key IS NOT NULL
|
||||
THEN
|
||||
-- Notificatie naar behandelaar
|
||||
fac.putnotificationsrtprio (
|
||||
NULL,
|
||||
behandelaar_key,
|
||||
'MLDNOB',
|
||||
mldkey,
|
||||
'Melding ' || mldkey || ' is door de klant aangepast.',
|
||||
2,
|
||||
NULL,
|
||||
NULL,
|
||||
NULL,
|
||||
2,
|
||||
NULL);
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
-- Vlaggetjes zetten zoals mld_edit_note.asp dat doet
|
||||
BEGIN
|
||||
v_flag_on_fenote := fac.getsetting ('mld_flag_on_fenote');
|
||||
v_flag_on_bonote := fac.getsetting ('mld_flag_on_bonote');
|
||||
|
||||
IF v_flag_on_fenote <> 0 AND v_flag_on_fenote IS NOT NULL
|
||||
THEN
|
||||
UPDATE mld_melding
|
||||
SET mld_melding_flag =
|
||||
DECODE (opdrkey,
|
||||
NULL, v_flag_on_fenote,
|
||||
v_flag_on_bonote)
|
||||
WHERE mld_melding_key = mldkey
|
||||
AND ( (mld_melding_flag = v_flag_on_bonote)
|
||||
OR (mld_melding_flag = 0 OR mld_melding_flag IS NULL));
|
||||
|
||||
DBMS_OUTPUT.put_line ('Flag gezet.');
|
||||
END IF;
|
||||
EXCEPTION
|
||||
WHEN OTHERS
|
||||
THEN
|
||||
DBMS_OUTPUT.put_line( 'Niet gelukt om flag '
|
||||
|| v_flag_on_fenote
|
||||
|| ' te zetten.');
|
||||
END;
|
||||
ELSE
|
||||
-- suggested extensions:
|
||||
-- check for MLDUSE-write autorisations
|
||||
-- parse the subject to find an appropriate stdmelding, if uniquely possible
|
||||
errormsg := '(0x148)';
|
||||
|
||||
BEGIN
|
||||
stdmelding :=
|
||||
fac.safe_to_number (fac.getsetting ('defaultstdmelding'));
|
||||
|
||||
INSERT INTO mld_melding (mld_melding_module,
|
||||
mld_meldbron_key,
|
||||
mld_melding_datum,
|
||||
mld_melding_omschrijving,
|
||||
mld_melding_status,
|
||||
mld_melding_t_uitvoertijd,
|
||||
mld_stdmelding_key,
|
||||
prs_perslid_key,
|
||||
prs_perslid_key_voor,
|
||||
prs_kostenplaats_key,
|
||||
mld_melding_spoed)
|
||||
VALUES ('MLD',
|
||||
4, -- email
|
||||
SYSDATE,
|
||||
v_body,
|
||||
NULL,
|
||||
mld_t_uitvoertijd (2, 'D'),
|
||||
stdmelding,
|
||||
sender_key,
|
||||
sender_key,
|
||||
kostenplaats_key,
|
||||
3)
|
||||
RETURNING mld_melding_key
|
||||
INTO mldkey;
|
||||
|
||||
-- DBMS_OUTPUT.PUT_LINE('Melding toegevoegd: ' || mldkey);
|
||||
errormsg := '(0x165)';
|
||||
mld.setmeldingstatus (mldkey, 2, sender_key);
|
||||
|
||||
INSERT INTO fac_result (fac_result_sessionid,
|
||||
fac_result_naam,
|
||||
fac_result_waarde)
|
||||
VALUES (psessionid,
|
||||
'maillog',
|
||||
'Geregistreerd onder melding ' || mldkey);
|
||||
END;
|
||||
END IF;
|
||||
|
||||
IF opdrkey IS NULL
|
||||
THEN
|
||||
-- Zoek het laagste bijlagen kenmerk key (AAEN#34590) om de bijlagen onder te stoppen
|
||||
errormsg := '(0x151)';
|
||||
|
||||
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 = stdmelding
|
||||
AND std.mld_ins_discipline_key = d.ins_discipline_key
|
||||
AND ( (k.mld_stdmelding_key = std.mld_stdmelding_key
|
||||
AND k.mld_kenmerk_niveau = 'S')
|
||||
OR (k.mld_stdmelding_key = d.ins_discipline_key
|
||||
AND k.mld_kenmerk_niveau = 'D')
|
||||
OR (k.mld_stdmelding_key = d.ins_srtdiscipline_key
|
||||
AND k.mld_kenmerk_niveau = 'T'))
|
||||
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 = stdmelding
|
||||
AND std1.mld_ins_discipline_key =
|
||||
d1.ins_discipline_key
|
||||
AND ( (k1.mld_stdmelding_key =
|
||||
std1.mld_stdmelding_key
|
||||
AND k1.mld_kenmerk_niveau = 'S')
|
||||
OR (k1.mld_stdmelding_key = d1.ins_discipline_key
|
||||
AND k1.mld_kenmerk_niveau = 'D')
|
||||
OR (k1.mld_stdmelding_key =
|
||||
d1.ins_srtdiscipline_key
|
||||
AND k1.mld_kenmerk_niveau = 'T'))
|
||||
AND k1.mld_kenmerk_verwijder IS NULL
|
||||
AND k1.mld_kenmerk_key < k.mld_kenmerk_key);
|
||||
|
||||
errormsg := '(0x153)';
|
||||
|
||||
IF kkey IS NOT NULL
|
||||
THEN
|
||||
-- DBMS_OUTPUT.PUT_LINE('Bijlagen kenmerk: ' || kkey);
|
||||
errormsg := '(0x157)';
|
||||
|
||||
INSERT INTO fac_result (fac_result_sessionid,
|
||||
fac_result_naam,
|
||||
fac_result_waarde)
|
||||
VALUES (psessionid,
|
||||
'kenmerkpath',
|
||||
'MLD\M'
|
||||
|| TO_CHAR (TRUNC (mldkey / 1000), 'FM0000')
|
||||
|| '___\M'
|
||||
|| mldkey
|
||||
|| '\'
|
||||
|| kkey
|
||||
|| '\');
|
||||
END IF;
|
||||
ELSE
|
||||
-- Zoek het laagste bijlagen kenmerk om de bijlagen onder te stoppen
|
||||
errormsg := '(0x152)';
|
||||
|
||||
SELECT MIN (mld_kenmerk_key)
|
||||
INTO kkey
|
||||
FROM mld_kenmerk k, mld_srtkenmerk sk
|
||||
WHERE sk.mld_srtkenmerk_kenmerktype = 'M'
|
||||
AND sk.mld_srtkenmerk_key = k.mld_srtkenmerk_key
|
||||
AND k.mld_typeopdr_key = typeopdrkey
|
||||
AND k.mld_kenmerk_niveau = 'O'
|
||||
AND k.mld_kenmerk_verwijder IS NULL
|
||||
AND NOT EXISTS
|
||||
(SELECT mld_kenmerk_volgnummer
|
||||
FROM mld_kenmerk k1, mld_srtkenmerk sk1
|
||||
WHERE sk1.mld_srtkenmerk_kenmerktype = 'M'
|
||||
AND sk1.mld_srtkenmerk_key = k1.mld_srtkenmerk_key
|
||||
AND k1.mld_typeopdr_key = typeopdrkey
|
||||
AND k1.mld_kenmerk_niveau = 'O'
|
||||
AND k1.mld_kenmerk_verwijder IS NULL
|
||||
AND k1.mld_kenmerk_volgnummer <
|
||||
k.mld_kenmerk_volgnummer);
|
||||
|
||||
errormsg := '(0x154)';
|
||||
|
||||
IF kkey IS NOT NULL
|
||||
THEN
|
||||
-- DBMS_OUTPUT.PUT_LINE('Bijlagen kenmerk: ' || kkey);
|
||||
errormsg := '(0x157)';
|
||||
|
||||
INSERT INTO fac_result (fac_result_sessionid,
|
||||
fac_result_naam,
|
||||
fac_result_waarde)
|
||||
VALUES (psessionid,
|
||||
'kenmerkpath',
|
||||
'MLD\O'
|
||||
|| TO_CHAR (TRUNC (opdrkey / 1000), 'FM0000')
|
||||
|| '___\O'
|
||||
|| opdrkey
|
||||
|| '\'
|
||||
|| kkey
|
||||
|| '\');
|
||||
END IF;
|
||||
END IF;
|
||||
ELSE
|
||||
errormsg := '(0x188)';
|
||||
|
||||
INSERT INTO fac_result (fac_result_sessionid,
|
||||
fac_result_naam,
|
||||
fac_result_waarde)
|
||||
VALUES (psessionid,
|
||||
'errormsg',
|
||||
'Database fout - Neem contact op met uw systeembeheerder '
|
||||
|| errormsg);
|
||||
END CASE;
|
||||
EXCEPTION
|
||||
WHEN OTHERS
|
||||
THEN
|
||||
-- DBMS_OUTPUT.PUT_LINE('Mail niet geaccepteerd: ' || '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 '
|
||||
|| errormsg);
|
||||
|
||||
fac.writelog (
|
||||
'PROCESSEMAIL',
|
||||
'E',
|
||||
'Mail kon niet ingelezen worden afzender:'
|
||||
|| v_from
|
||||
|| '['
|
||||
|| errormsg
|
||||
|| ']'
|
||||
|| psubject,
|
||||
'OTHERS (error '
|
||||
|| SQLCODE
|
||||
|| '/'
|
||||
|| SUBSTR (SQLERRM, 1, 100)
|
||||
|| ')');
|
||||
END;
|
||||
/
|
||||
|
||||
BEGIN adm.systrackscriptId('$Id$'); END;
|
||||
/
|
||||
BEGIN fac.registercustversion('DEMO', 6); END;
|
||||
BEGIN fac.registercustversion('DEMO', 7); END;
|
||||
/
|
||||
|
||||
COMMIT;
|
||||
|
||||
Reference in New Issue
Block a user