245 lines
9.0 KiB
SQL
245 lines
9.0 KiB
SQL
-- Customer specific once-script RWSN#29012.
|
|
--
|
|
-- (c) 2014 SG|facilitor bv
|
|
--
|
|
-- Support: +31 53 4800700
|
|
SET ECHO ON
|
|
SPOOL xrwsn29012.lst
|
|
SET DEFINE OFF
|
|
|
|
/* Formatted on 22-8-2013 10:54:54 (QP5 v5.115.810.9015) */
|
|
CREATE OR REPLACE PROCEDURE rwsn_update_did_status (p_import_key IN NUMBER)
|
|
AS
|
|
-- Cursor loopt - in volgorde! - over alle ingelezen DID statusberichten.
|
|
CURSOR c1
|
|
IS
|
|
SELECT imp_log_timestamp,
|
|
msg_type,
|
|
opdrachtnr,
|
|
externnr,
|
|
DECODE (
|
|
mld_info,
|
|
NULL,
|
|
NULL,
|
|
TO_CHAR (imp_log_timestamp, 'dd-mm-yyyy hh24:mi:ss')
|
|
|| CHR (13)
|
|
|| CHR (10)
|
|
|| mld_info
|
|
)
|
|
mld_info,
|
|
mld_einddatum
|
|
FROM rwsn_imp_didstatusmulti
|
|
WHERE imp_log_run = TO_CHAR (p_import_key)
|
|
ORDER BY 1, 2 DESC, 3;
|
|
|
|
--c_externnr_kenmerk_key NUMBER (10) := 1577;
|
|
c_externnr_ksrtkey NUMBER (10) := 321;
|
|
v_errormsg VARCHAR2 (1000);
|
|
oracle_err_num NUMBER;
|
|
oracle_err_mes VARCHAR2 (200);
|
|
v_aanduiding VARCHAR2 (200);
|
|
v_count_tot NUMBER (10);
|
|
v_count NUMBER (10);
|
|
v_mld_key NUMBER (10);
|
|
v_opdr_key NUMBER (10);
|
|
v_typeopdr_key NUMBER (10);
|
|
v_opdr_status NUMBER (10);
|
|
v_externnr_kkey NUMBER (10);
|
|
BEGIN
|
|
-- Loop door alle geimporteerde DID statusberichten en verwerk deze.
|
|
v_count_tot := 0;
|
|
|
|
FOR rec IN c1
|
|
LOOP
|
|
BEGIN
|
|
v_aanduiding := '[' || rec.msg_type || '|' || rec.opdrachtnr || '] ';
|
|
v_count_tot := v_count_tot + 1;
|
|
v_count := 0;
|
|
v_mld_key := -1;
|
|
v_opdr_key := -1;
|
|
|
|
-- Key van melding/opdracht bepalen (alleen DID en GPO gerelateerd!).
|
|
IF (rec.opdrachtnr IS NOT NULL)
|
|
THEN
|
|
v_errormsg := 'Fout bij bepalen melding/opdracht.';
|
|
|
|
SELECT o.mld_melding_key,
|
|
o.mld_opdr_key,
|
|
o.mld_typeopdr_key,
|
|
o.mld_statusopdr_key
|
|
INTO v_mld_key,
|
|
v_opdr_key,
|
|
v_typeopdr_key,
|
|
v_opdr_status
|
|
FROM mld_opdr o,
|
|
mld_melding m,
|
|
mld_stdmelding sm,
|
|
mld_discipline md
|
|
WHERE o.mld_melding_key = m.mld_melding_key
|
|
AND m.mld_stdmelding_key = sm.mld_stdmelding_key
|
|
AND sm.mld_ins_discipline_key = md.ins_discipline_key
|
|
AND md.ins_srtdiscipline_key IN (21, 101, 121, 181) -- ICT/VWM/GPO/WVO
|
|
AND o.mld_melding_key
|
|
|| '/'
|
|
|| o.mld_opdr_bedrijfopdr_volgnr = rec.opdrachtnr;
|
|
END IF;
|
|
|
|
-- Alleen iets doen als melding/opdracht succesvol is bepaald.
|
|
IF (v_mld_key > 0 AND v_opdr_key > 0)
|
|
THEN
|
|
-- Externnr-kenmerk initieel opslaan bij opdracht (met externnr).
|
|
IF (rec.externnr IS NOT NULL)
|
|
THEN
|
|
v_errormsg := 'Fout bij bepalen externnr-bestaan.';
|
|
|
|
SELECT COUNT ( * )
|
|
INTO v_count
|
|
FROM mld_kenmerk
|
|
WHERE mld_kenmerk_verwijder IS NULL
|
|
AND mld_srtkenmerk_key = c_externnr_ksrtkey
|
|
AND mld_typeopdr_key = v_typeopdr_key
|
|
AND mld_kenmerk_niveau = 'O';
|
|
|
|
IF (v_count = 1)
|
|
THEN
|
|
v_errormsg := 'Fout bij bepalen externnr-key.';
|
|
|
|
SELECT mld_kenmerk_key
|
|
INTO v_externnr_kkey
|
|
FROM mld_kenmerk
|
|
WHERE mld_kenmerk_verwijder IS NULL
|
|
AND mld_srtkenmerk_key = c_externnr_ksrtkey
|
|
AND mld_typeopdr_key = v_typeopdr_key
|
|
AND mld_kenmerk_niveau = 'O';
|
|
|
|
v_errormsg := 'Fout bij toevoegen externr-waarde.';
|
|
|
|
SELECT COUNT ( * )
|
|
INTO v_count
|
|
FROM mld_v_aanwezigkenmerkopdr ok, mld_kenmerk k
|
|
WHERE ok.mld_opdr_key = v_opdr_key
|
|
AND ok.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND k.mld_srtkenmerk_key = c_externnr_ksrtkey;
|
|
|
|
IF (v_count = 0)
|
|
THEN
|
|
INSERT INTO mld_kenmerkopdr (
|
|
mld_kenmerkopdr_waarde,
|
|
mld_kenmerk_key,
|
|
mld_opdr_key
|
|
)
|
|
VALUES (rec.externnr, v_externnr_kkey, v_opdr_key);
|
|
END IF;
|
|
END IF;
|
|
END IF;
|
|
|
|
-- Bijwerken Opmerking met mld_info (bovenin melding en opdracht).
|
|
IF (rec.mld_info IS NOT NULL)
|
|
THEN
|
|
v_errormsg := 'Fout bij bijwerken opdracht-opmerking.';
|
|
|
|
v_count := LENGTH (rec.mld_info) + 5; -- Beetje speling qua lengte!
|
|
|
|
UPDATE mld_opdr
|
|
SET mld_opdr_opmerking =
|
|
DECODE (
|
|
mld_opdr_opmerking,
|
|
NULL,
|
|
rec.mld_info,
|
|
rec.mld_info || CHR (13) || CHR (10)
|
|
|| SUBSTR (mld_opdr_opmerking,
|
|
1,
|
|
(4000 - v_count))
|
|
)
|
|
WHERE mld_opdr_key = v_opdr_key
|
|
AND mld_statusopdr_key IN (5, 8);
|
|
|
|
IF (rec.msg_type <> 'NOK') -- NOK voor DID - nog - ongedefinieerd!
|
|
THEN
|
|
v_errormsg := 'Fout bij bijwerken melding-opmerking.';
|
|
|
|
UPDATE mld_melding
|
|
SET mld_melding_opmerking =
|
|
DECODE (
|
|
mld_melding_opmerking,
|
|
NULL,
|
|
rec.mld_info,
|
|
rec.mld_info || CHR (13) || CHR (10)
|
|
|| SUBSTR (mld_melding_opmerking,
|
|
1,
|
|
(4000 - v_count))
|
|
)
|
|
WHERE mld_melding_key = v_mld_key
|
|
AND mld_melding_status IN (4, 7);
|
|
END IF;
|
|
|
|
COMMIT;
|
|
END IF;
|
|
|
|
-- Plandatum van melding bijwerken volgens mld_einddatum (alleen naar
|
|
-- achteren en als msg_type=UPD).
|
|
IF (rec.msg_type = 'UPD' AND rec.mld_einddatum IS NOT NULL)
|
|
THEN
|
|
v_errormsg := 'Fout bij bijwerken einddatum volgens UPD.';
|
|
|
|
UPDATE mld_melding
|
|
SET mld_melding_einddatum = rec.mld_einddatum
|
|
WHERE mld_melding_key = v_mld_key
|
|
AND mld_melding_status IN (4, 7)
|
|
AND rec.mld_einddatum > mld_melding_einddatum;
|
|
|
|
COMMIT;
|
|
END IF;
|
|
|
|
-- Sluit opdracht (als msg_type=AFM); de bovenliggende melding wordt
|
|
-- eventueel gesloten tijdens db-procedure: rwsn_export_did_opdr!
|
|
IF (rec.msg_type = 'AFM')
|
|
THEN
|
|
-- Sluit opdracht!
|
|
IF (v_opdr_status = 5 OR v_opdr_status = 8)
|
|
THEN
|
|
v_errormsg := 'Fout bij sluiten opdracht.';
|
|
|
|
MLD.setopdrachtstatus (v_opdr_key, 6, 4); -- Facilitor
|
|
|
|
COMMIT;
|
|
END IF;
|
|
END IF;
|
|
END IF;
|
|
EXCEPTION
|
|
WHEN OTHERS
|
|
THEN
|
|
oracle_err_num := SQLCODE;
|
|
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
|
|
v_errormsg :=
|
|
v_errormsg
|
|
|| ' ORACLE (error '
|
|
|| oracle_err_num
|
|
|| '/'
|
|
|| oracle_err_mes
|
|
|| ')';
|
|
fac.imp_writelog (p_import_key,
|
|
'E',
|
|
v_aanduiding || v_errormsg,
|
|
'Fout bij verwerken DID statusbericht.');
|
|
END;
|
|
END LOOP;
|
|
|
|
fac.imp_writelog (
|
|
p_import_key,
|
|
'S',
|
|
'Proces: '
|
|
|| TO_CHAR (v_count_tot)
|
|
|| ' DID statusberichten afgehandeld.',
|
|
''
|
|
);
|
|
COMMIT;
|
|
END;
|
|
/
|
|
|
|
COMMIT;
|
|
|
|
BEGIN adm.systrackscript('$Workfile: rwsn#27292.sql $', '$Revision$', 0); END;
|
|
/
|
|
SPOOL OFF
|