VENR#31245 Strukton-koppeling (voor HTC!)
svn path=/Customer/trunk/; revision=25273
This commit is contained in:
517
VENR/venr.sql
517
VENR/venr.sql
@@ -2073,6 +2073,523 @@ AS
|
||||
TO_CHAR (o.mld_melding_key),
|
||||
b2a.prs_afdeling_key;
|
||||
|
||||
-- Import vanuit Strukton
|
||||
/* Formatted on 22-5-2015 11:52:44 (QP5 v5.136.908.31019) */
|
||||
CREATE OR REPLACE PROCEDURE venr_import_opdrstat_strukton (p_import_key IN NUMBER)
|
||||
AS
|
||||
c_delim VARCHAR2 (1) := ';';
|
||||
v_newline VARCHAR2 (4000); -- Input line
|
||||
v_errormsg VARCHAR2 (1000);
|
||||
oracle_err_num NUMBER;
|
||||
oracle_err_mes VARCHAR2 (200);
|
||||
v_aanduiding VARCHAR2 (1000) := '';
|
||||
header_is_valid NUMBER := 0;
|
||||
v_count_tot NUMBER (10) := 0;
|
||||
v_count_import NUMBER (10) := 0;
|
||||
v_ongeldig NUMBER (1) := 0;
|
||||
-- De importvelden
|
||||
v_mld_opdr_key_tekst VARCHAR2 (100);
|
||||
v_mld_opdr_key NUMBER (10);
|
||||
v_mld_opdr_opmerking VARCHAR2 (4000);
|
||||
v_extern_nummer VARCHAR2 (100);
|
||||
v_status_code VARCHAR2 (100);
|
||||
v_status NUMBER (10);
|
||||
v_datumtijd_tekst VARCHAR2 (100);
|
||||
v_datumtijd DATE;
|
||||
v_status_tekst VARCHAR2 (100);
|
||||
v_opmerking VARCHAR2 (4000);
|
||||
|
||||
-- Overige velden:
|
||||
CURSOR c1
|
||||
IS
|
||||
SELECT *
|
||||
FROM fac_imp_file
|
||||
WHERE fac_import_key = p_import_key
|
||||
ORDER BY fac_imp_file_index;
|
||||
BEGIN
|
||||
-- Eerst opruiming
|
||||
DELETE FROM venr_imp_opdrstat_strukton;
|
||||
|
||||
COMMIT;
|
||||
|
||||
FOR rec1 IN c1
|
||||
LOOP
|
||||
BEGIN
|
||||
v_newline := rec1.fac_imp_file_line;
|
||||
v_errormsg := 'Fout bij opvragen importregel';
|
||||
v_aanduiding := '';
|
||||
v_ongeldig := 0;
|
||||
|
||||
-- Lees alle veldwaarden
|
||||
fac.imp_getfield (v_newline, c_delim, v_mld_opdr_key_tekst);
|
||||
fac.imp_getfield (v_newline, c_delim, v_extern_nummer);
|
||||
fac.imp_getfield (v_newline, c_delim, v_status_code); -- typeID
|
||||
fac.imp_getfield (v_newline, c_delim, v_datumtijd_tekst);
|
||||
fac.imp_getfield (v_newline, c_delim, v_status_tekst);
|
||||
fac.imp_getfield (v_newline, c_delim, v_opmerking);
|
||||
v_opmerking := SUBSTR (v_opmerking, 1, 1000);
|
||||
-- Verwijder de markering voor cr/lf die in stylesheet is toegevoegd.
|
||||
v_opmerking := REPLACE (v_opmerking, '@@', CHR (13));
|
||||
v_aanduiding :=
|
||||
'['
|
||||
|| v_mld_opdr_key_tekst
|
||||
|| '|'
|
||||
|| v_extern_nummer
|
||||
|| '|'
|
||||
|| v_status_code
|
||||
|| '|'
|
||||
|| v_datumtijd_tekst
|
||||
|| '|'
|
||||
|| v_status_tekst
|
||||
|| '] ';
|
||||
|
||||
-- Ik controleer of ik een geldige header heb, dat is: in de juiste kolommen
|
||||
-- de juiste kolomkop. Ik controleer daarbij ALLE kolommen!
|
||||
-- Ik negeer alles totdat ik een geldige header ben gepasseerd.
|
||||
IF (header_is_valid = 0)
|
||||
THEN
|
||||
IF UPPER (TRIM (v_mld_opdr_key_tekst)) = 'REFERENCEID'
|
||||
AND UPPER (TRIM (v_extern_nummer)) = 'SERVICEREQUESTID'
|
||||
AND UPPER (TRIM (v_status_code)) = 'TYPEID'
|
||||
AND UPPER (TRIM (v_datumtijd_tekst)) = 'DATETIME'
|
||||
AND UPPER (TRIM (v_opmerking)) = 'REMARKS'
|
||||
THEN
|
||||
header_is_valid := 1;
|
||||
END IF;
|
||||
ELSE
|
||||
v_count_tot := v_count_tot + 1;
|
||||
-- Controleer alle veldwaarden
|
||||
v_errormsg := 'Fout bepalen opdracht';
|
||||
v_mld_opdr_key := TRIM (v_mld_opdr_key);
|
||||
|
||||
BEGIN
|
||||
SELECT o.mld_opdr_key, o.mld_opdr_opmerking
|
||||
INTO v_mld_opdr_key, v_mld_opdr_opmerking
|
||||
FROM mld_opdr o,
|
||||
mld_melding m,
|
||||
ins_tab_discipline d,
|
||||
ins_srtdiscipline sd,
|
||||
mld_stdmelding std
|
||||
WHERE o.mld_melding_key = m.mld_melding_key
|
||||
AND m.mld_stdmelding_key = std.mld_stdmelding_key
|
||||
AND std.mld_ins_discipline_key = d.ins_discipline_key
|
||||
AND d.ins_srtdiscipline_key = sd.ins_srtdiscipline_key
|
||||
AND sd.ins_srtdiscipline_prefix
|
||||
|| m.mld_melding_key
|
||||
|| '/'
|
||||
|| o.mld_opdr_bedrijfopdr_volgnr =
|
||||
v_mld_opdr_key_tekst;
|
||||
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 (p_import_key,
|
||||
'W',
|
||||
v_aanduiding || v_errormsg,
|
||||
'');
|
||||
END;
|
||||
|
||||
IF v_ongeldig = 0
|
||||
THEN
|
||||
v_errormsg := 'Fout bepalen status';
|
||||
|
||||
CASE
|
||||
WHEN v_status_code = '5'
|
||||
THEN
|
||||
v_status := 5; -- uitgegeven
|
||||
WHEN v_status_code = '10'
|
||||
THEN
|
||||
v_status := 8; -- geaccepteerd
|
||||
WHEN v_status_code = '20' -- monteur gereed
|
||||
THEN
|
||||
v_status := 6; -- afgemeld
|
||||
WHEN v_status_code = '25' -- specialist gereed
|
||||
THEN
|
||||
v_status := 6; -- afgemeld
|
||||
WHEN v_status_code = '30' -- technisch gereed
|
||||
THEN
|
||||
v_status := 6; -- afgemeld
|
||||
-- For future use
|
||||
-- WHEN v_status_code = '40' -- uitgeprijst
|
||||
-- THEN
|
||||
-- v_status := 6; -- afgemeld
|
||||
WHEN v_status_code = '70'
|
||||
THEN
|
||||
v_status := 1; -- geannuleerd
|
||||
WHEN v_status_code = '80'
|
||||
THEN
|
||||
v_status := 1; -- afgewezen
|
||||
ELSE
|
||||
v_status := NULL;
|
||||
v_ongeldig := 1; -- nog te bezien
|
||||
END CASE;
|
||||
END IF;
|
||||
|
||||
IF v_ongeldig = 0
|
||||
THEN
|
||||
v_errormsg := 'Fout converteren datumtijd';
|
||||
|
||||
IF INSTR (v_datumtijd_tekst, '.') > 0
|
||||
THEN
|
||||
v_datumtijd :=
|
||||
fac.safe_to_date (
|
||||
REPLACE (
|
||||
SUBSTR (v_datumtijd_tekst,
|
||||
1,
|
||||
INSTR (v_datumtijd_tekst, '.') - 1),
|
||||
'T',
|
||||
' '),
|
||||
'yyyy-mm-dd hh24:mi:ss');
|
||||
ELSE
|
||||
v_datumtijd :=
|
||||
fac.safe_to_date (v_datumtijd_tekst,
|
||||
'yyyy-mm-dd hh24:mi:ss');
|
||||
END IF;
|
||||
|
||||
IF v_datumtijd = NULL
|
||||
THEN
|
||||
v_ongeldig := 0; -- Moet dat niet 1 zijn?
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
IF v_ongeldig = 0
|
||||
THEN
|
||||
v_errormsg := 'Fout aanvullen opmerking';
|
||||
|
||||
-- controleer of de opmerking niet leeg is en of dezelfde opmerking al bij een eerdere statusovergang
|
||||
-- gemeld is.
|
||||
IF v_opmerking IS NOT NULL
|
||||
AND INSTR (v_mld_opdr_opmerking, v_opmerking) = 0
|
||||
THEN
|
||||
v_opmerking :=
|
||||
'['
|
||||
|| v_datumtijd_tekst
|
||||
|| '] - '
|
||||
|| v_status_tekst
|
||||
|| CHR (13)
|
||||
|| CHR (10)
|
||||
|| v_opmerking;
|
||||
ELSE
|
||||
v_opmerking :=
|
||||
'[' || v_datumtijd_tekst || '] - ' || v_status_tekst;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
-- Insert geformatteerde import record
|
||||
IF (v_ongeldig = 0)
|
||||
THEN
|
||||
BEGIN
|
||||
v_errormsg := 'Fout wegschrijven statusbericht';
|
||||
|
||||
INSERT INTO venr_imp_opdrstat_strukton (mld_opdr_key,
|
||||
extern_nummer,
|
||||
status,
|
||||
datumtijd,
|
||||
opmerking)
|
||||
VALUES (v_mld_opdr_key,
|
||||
v_extern_nummer,
|
||||
v_status,
|
||||
v_datumtijd,
|
||||
v_opmerking);
|
||||
|
||||
v_count_import := v_count_import + 1;
|
||||
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.imp_writelog (
|
||||
p_import_key,
|
||||
'E',
|
||||
v_aanduiding || v_errormsg,
|
||||
'');
|
||||
END;
|
||||
ELSE
|
||||
IF v_status_code <> '40' AND v_status_code <> '45'
|
||||
THEN
|
||||
fac.imp_writelog (p_import_key,
|
||||
'E',
|
||||
v_aanduiding || v_errormsg,
|
||||
'');
|
||||
END IF;
|
||||
END IF;
|
||||
END IF;
|
||||
END;
|
||||
END LOOP;
|
||||
|
||||
IF (header_is_valid = 0)
|
||||
THEN
|
||||
fac.imp_writelog (p_import_key,
|
||||
'E',
|
||||
'Ongeldig importbestand',
|
||||
'Geen header of header niet volgens specificatie!');
|
||||
ELSE
|
||||
fac.imp_writelog (
|
||||
p_import_key,
|
||||
'S',
|
||||
'Inleesproces/#ingelezen statusberichten: ' || TO_CHAR (v_count_tot),
|
||||
'');
|
||||
fac.imp_writelog (
|
||||
p_import_key,
|
||||
'S',
|
||||
'Inleesproces/#ongeldige niet ingelezen statusberichten: '
|
||||
|| TO_CHAR (v_count_tot - v_count_import),
|
||||
'');
|
||||
END IF;
|
||||
|
||||
COMMIT;
|
||||
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.imp_writelog (p_import_key,
|
||||
'E',
|
||||
v_aanduiding || v_errormsg,
|
||||
'Inleesproces statusberichten afgebroken!');
|
||||
END;
|
||||
/
|
||||
|
||||
CREATE OR REPLACE PROCEDURE venr_update_opdrstat_strukton (p_import_key IN NUMBER)
|
||||
AS
|
||||
-- Cursor loopt - in volgorde! - over alle ingelezen statusberichten.
|
||||
CURSOR c1
|
||||
IS
|
||||
SELECT mld_opdr_key,
|
||||
extern_nummer,
|
||||
datumtijd,
|
||||
status,
|
||||
opmerking
|
||||
FROM venr_imp_opdrstat_strukton
|
||||
ORDER BY 1, 3;
|
||||
|
||||
c_user_key NUMBER (10) := 5; -- _STRUKTON-user
|
||||
c_refnr_srtkkey NUMBER (10) := 141; -- Refnr. Leverancier
|
||||
v_errormsg VARCHAR2 (1000);
|
||||
oracle_err_num NUMBER;
|
||||
oracle_err_mes VARCHAR2 (200);
|
||||
v_aanduiding VARCHAR2 (200);
|
||||
v_count_tot NUMBER (10) := 0;
|
||||
v_count NUMBER (10) := 0;
|
||||
v_mld_key NUMBER (10) := 0;
|
||||
v_opdr_key NUMBER (10) := 0;
|
||||
v_opdr_status NUMBER (10) := 0;
|
||||
v_mld_typeopdr_key NUMBER (10);
|
||||
v_mld_kenmerk_key NUMBER (10);
|
||||
v_mld_kenmerkopdr_key NUMBER (10);
|
||||
BEGIN
|
||||
-- Loop over alle ingelezen Strukton-statusberichten.
|
||||
FOR rec IN c1
|
||||
LOOP
|
||||
BEGIN
|
||||
v_aanduiding :=
|
||||
'['
|
||||
|| rec.mld_opdr_key
|
||||
|| '|'
|
||||
|| SUBSTR (rec.opmerking, 1, 100)
|
||||
|| '] ';
|
||||
v_count_tot := v_count_tot + 1;
|
||||
|
||||
-- Key van melding/opdracht bepalen en Refnr. bij opdracht opslaan.
|
||||
IF (rec.mld_opdr_key IS NOT NULL)
|
||||
THEN
|
||||
v_errormsg := 'Fout bepalen opdracht.';
|
||||
|
||||
SELECT mld_melding_key,
|
||||
mld_opdr_key,
|
||||
mld_statusopdr_key,
|
||||
mld_typeopdr_key
|
||||
INTO v_mld_key,
|
||||
v_opdr_key,
|
||||
v_opdr_status,
|
||||
v_mld_typeopdr_key
|
||||
FROM mld_opdr
|
||||
WHERE mld_opdr_key = rec.mld_opdr_key;
|
||||
|
||||
v_errormsg := 'Fout bepalen Refnr-kenmerk.';
|
||||
|
||||
SELECT k.mld_kenmerk_key
|
||||
INTO v_mld_kenmerk_key
|
||||
FROM mld_kenmerk k
|
||||
WHERE k.mld_srtkenmerk_key = c_refnr_srtkkey
|
||||
AND k.mld_typeopdr_key = v_mld_typeopdr_key;
|
||||
|
||||
v_errormsg := 'Fout bepalen Refnr-kenmerkopdracht.';
|
||||
|
||||
SELECT MAX (ko.mld_kenmerkopdr_key)
|
||||
INTO v_mld_kenmerkopdr_key
|
||||
FROM mld_kenmerkopdr ko
|
||||
WHERE ko.mld_opdr_key = v_opdr_key
|
||||
AND v_mld_kenmerk_key = ko.mld_kenmerk_key;
|
||||
|
||||
IF v_mld_kenmerkopdr_key IS NULL
|
||||
THEN
|
||||
-- Kenmerk toevoegen
|
||||
v_errormsg := 'Fout toevoegen Refnr-kenmerkopdracht.';
|
||||
|
||||
INSERT INTO mld_kenmerkopdr (mld_kenmerk_key,
|
||||
mld_opdr_key,
|
||||
mld_kenmerkopdr_waarde)
|
||||
VALUES (v_mld_kenmerk_key, v_opdr_key, rec.extern_nummer);
|
||||
ELSE
|
||||
-- Kenmerk bijwerken
|
||||
v_errormsg := 'Fout bijwerken Refnr-kenmerkopdracht.';
|
||||
|
||||
UPDATE mld_kenmerkopdr
|
||||
SET mld_kenmerkopdr_waarde = rec.extern_nummer
|
||||
WHERE mld_kenmerkopdr_key = v_mld_kenmerkopdr_key;
|
||||
END IF;
|
||||
|
||||
v_errormsg := 'Fout bijwerken Opmerking (opdracht).';
|
||||
|
||||
v_count := LENGTH (rec.opmerking) + 5; -- Beetje speling qua lengte!
|
||||
|
||||
UPDATE mld_opdr
|
||||
SET mld_opdr_opmerking =
|
||||
DECODE (
|
||||
mld_opdr_opmerking,
|
||||
NULL,
|
||||
rec.opmerking,
|
||||
rec.opmerking
|
||||
|| CHR (13)
|
||||
|| CHR (10)
|
||||
|| SUBSTR (mld_opdr_opmerking, 1, (4000 - v_count)))
|
||||
WHERE mld_opdr_key = v_opdr_key;
|
||||
|
||||
v_errormsg := 'Fout bijwerken Status.';
|
||||
|
||||
IF v_opdr_status <> rec.status
|
||||
THEN
|
||||
IF rec.status = 8 AND v_opdr_status = 5
|
||||
THEN
|
||||
-- Accepteer opdracht als de opdracht uitgegeven was
|
||||
MLD.setopdrachtstatus (v_opdr_key, 8, c_user_key); -- Strukton
|
||||
ELSIF rec.status = 6 AND v_opdr_status = 5
|
||||
THEN
|
||||
-- Meld de opdracht af als deze uitgegeven was
|
||||
MLD.setopdrachtstatus (v_opdr_key, 8, c_user_key); -- Strukton, eerst accepteren
|
||||
MLD.setopdrachtstatus (v_opdr_key, 6, c_user_key); -- Strukton
|
||||
ELSIF rec.status = 6 AND v_opdr_status = 8
|
||||
THEN
|
||||
-- Meld de opdracht af als deze geaccepteerd was
|
||||
MLD.setopdrachtstatus (v_opdr_key, 6, c_user_key); -- Strukton
|
||||
ELSIF rec.status = 1 AND v_opdr_status IN (5, 8)
|
||||
THEN
|
||||
-- Wijs de opdracht af als deze niet/wel geaccepteerd was
|
||||
MLD.setopdrachtstatus (v_opdr_key, 1, c_user_key); -- Strukton
|
||||
MLD.updatemeldingstatusAV (v_mld_key,
|
||||
0,
|
||||
c_user_key,
|
||||
0);
|
||||
END IF;
|
||||
|
||||
IF rec.status = 6 AND v_opdr_status <> 6
|
||||
THEN
|
||||
v_errormsg := 'Fout bijwerken Opmerking (melding).';
|
||||
|
||||
UPDATE mld_melding m
|
||||
SET mld_melding_opmerking =
|
||||
DECODE (
|
||||
mld_melding_opmerking,
|
||||
NULL,
|
||||
rec.opmerking,
|
||||
rec.opmerking || 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)
|
||||
AND NOT EXISTS
|
||||
( -- Afhandeling in melding niet aanpassen voor projecten
|
||||
SELECT std.mld_stdmelding_key
|
||||
FROM mld_stdmelding std,
|
||||
ins_tab_discipline d,
|
||||
ins_srtdiscipline sd
|
||||
WHERE m.mld_stdmelding_key =
|
||||
std.mld_stdmelding_key
|
||||
AND std.mld_ins_discipline_key =
|
||||
d.ins_discipline_key
|
||||
AND d.ins_srtdiscipline_key =
|
||||
sd.ins_srtdiscipline_key
|
||||
AND sd.ins_srtdiscipline_prefix =
|
||||
'PR');
|
||||
|
||||
v_errormsg := 'Fout sluiten melding.';
|
||||
|
||||
SELECT COUNT ( * )
|
||||
INTO v_count
|
||||
FROM (SELECT m.mld_melding_key,
|
||||
(SELECT COUNT ( * )
|
||||
FROM mld_opdr o
|
||||
WHERE mld_melding_key = m.mld_melding_key)
|
||||
aanw_opdr,
|
||||
(SELECT COUNT ( * )
|
||||
FROM mld_opdr o
|
||||
WHERE mld_melding_key = m.mld_melding_key
|
||||
AND o.mld_statusopdr_key NOT IN
|
||||
(1, 2, 6, 7, 9))
|
||||
open_opdr
|
||||
FROM mld_melding m
|
||||
WHERE m.mld_melding_key = v_mld_key
|
||||
AND m.mld_melding_status IN (4, 7))
|
||||
niet_opgelost
|
||||
WHERE aanw_opdr > 0 AND open_opdr = 0;
|
||||
|
||||
-- Sinds AADO#30922 wordt de melding niet meer automatisch afgemeld.
|
||||
MLD.updatemeldingstatusAV (v_mld_key,
|
||||
0,
|
||||
c_user_key,
|
||||
0);
|
||||
END IF;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
COMMIT;
|
||||
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.imp_writelog (p_import_key,
|
||||
'E',
|
||||
v_aanduiding || v_errormsg,
|
||||
'Statusbericht-loop');
|
||||
END;
|
||||
END LOOP;
|
||||
|
||||
COMMIT;
|
||||
END;
|
||||
/
|
||||
|
||||
BEGIN adm.systrackscriptId('$Id$', 0); END;
|
||||
/
|
||||
BEGIN fac.registercustversion('VENR', 4); END;
|
||||
|
||||
Reference in New Issue
Block a user