GVBA#15515 Importfunctie toevoegen
svn path=/Customer/trunk/; revision=13840
This commit is contained in:
424
GVBA/Once/GVBA3.sql
Normal file
424
GVBA/Once/GVBA3.sql
Normal file
@@ -0,0 +1,424 @@
|
||||
-- GVBA3
|
||||
--
|
||||
--
|
||||
SET ECHO ON
|
||||
SPOOL xgvba3.lst
|
||||
PROMPT $Revision: 1 $
|
||||
|
||||
|
||||
drop table gvba_conv_mld;
|
||||
|
||||
CREATE TABLE gvba_conv_mld (
|
||||
o_ins_srtdiscipline_omschr VARCHAR2 (100),
|
||||
o_ins_srtdiscipline_key NUMBER (10),
|
||||
o_ins_discipline_omschrijving VARCHAR2 (100),
|
||||
o_ins_discipline_key NUMBER (10),
|
||||
o_mld_stdmelding_omschrijving VARCHAR2 (100),
|
||||
o_mld_stdmelding_key NUMBER (10),
|
||||
n_ins_srtdiscipline_omschr VARCHAR2 (100),
|
||||
n_ins_srtdiscipline_key NUMBER (10),
|
||||
n_ins_discipline_omschrijving VARCHAR2 (100),
|
||||
n_ins_discipline_key NUMBER (10),
|
||||
n_mld_stdmelding_omschrijving VARCHAR2 (100),
|
||||
n_mld_stdmelding_key NUMBER (10)
|
||||
);
|
||||
|
||||
CREATE OR REPLACE PROCEDURE GVBA.gvba_import_mld (
|
||||
p_applname IN VARCHAR2 ,
|
||||
p_applrun IN VARCHAR2 ,
|
||||
p_filedir IN VARCHAR2 ,
|
||||
p_filename IN VARCHAR2
|
||||
)
|
||||
AS
|
||||
c_fielddelimitor VARCHAR2 (1) := ';';
|
||||
v_newline VARCHAR2 (1000); -- Input line
|
||||
v_errormsg VARCHAR2 (1000);
|
||||
oracle_err_num NUMBER;
|
||||
oracle_err_mes VARCHAR2 (200);
|
||||
header_is_valid NUMBER;
|
||||
v_count_tot NUMBER (10);
|
||||
v_count_import NUMBER (10);
|
||||
v_ongeldig NUMBER (1);
|
||||
v_aanduiding VARCHAR2 (200);
|
||||
-- De importvelden:
|
||||
v_srtdiscipline_omschrijving VARCHAR2 (255); -- C30
|
||||
v_srtdiscipline_prefix VARCHAR2 (255); -- C3
|
||||
v_srtdiscipline_alg VARCHAR2 (255); -- N1
|
||||
v_srtdiscipline_ins VARCHAR2 (255); -- N1
|
||||
v_srtdiscipline_bes VARCHAR2 (255); -- N1
|
||||
v_discipline_omschrijving VARCHAR2 (255); -- C30
|
||||
v_stdmelding_omschrijving VARCHAR2 (255); -- C30
|
||||
v_stdmelding_groep VARCHAR2 (255); -- C20
|
||||
v_stdmelding_kostensoort VARCHAR2 (255); -- C60
|
||||
v_stdmelding_urgentie VARCHAR2 (255); -- N4,2
|
||||
v_stdmelding_uitvoertijd VARCHAR2 (255); -- N3
|
||||
v_stdmelding_streeftijd VARCHAR2 (255); -- N3
|
||||
v_discipline_directklaar VARCHAR2 (255); -- N1
|
||||
v_o_srtdiscipline_omschrijving VARCHAR2 (255); -- C30
|
||||
v_o_discipline_omschrijving VARCHAR2 (255); -- C30
|
||||
v_o_stdmelding_omschrijving VARCHAR2 (255); -- C30
|
||||
v_o_srtdiscipline_key NUMBER (10); -- N10
|
||||
v_o_discipline_key NUMBER (10); -- N10
|
||||
v_o_stdmelding_key NUMBER (10); -- N10
|
||||
v_srtdiscipline_key NUMBER (10); -- N10
|
||||
v_discipline_key NUMBER (10); -- N10
|
||||
v_stdmelding_key NUMBER (10); -- N10
|
||||
v_hint VARCHAR (1000);
|
||||
|
||||
-- Overige velden:
|
||||
v_stdmelding_urgentie_n mld_stdmelding.mld_stdmelding_urgentie%TYPE;
|
||||
v_stdmelding_uitvoertijd_n mld_stdmelding.mld_stdmelding_uitvoertijd%TYPE;
|
||||
v_stdmelding_streeftijd_n mld_stdmelding.mld_stdmelding_streeftijd%TYPE;
|
||||
CURSOR c1
|
||||
IS
|
||||
SELECT *
|
||||
FROM fac_imp_file
|
||||
WHERE fac_imp_file_applicatie = p_applname
|
||||
ORDER BY fac_imp_file_index;
|
||||
BEGIN
|
||||
-- Eerst opruiming
|
||||
DELETE FROM imp_log
|
||||
WHERE imp_log_applicatie = p_applname;
|
||||
|
||||
v_count_tot := 0;
|
||||
v_count_import := 0;
|
||||
header_is_valid := 0;
|
||||
COMMIT;
|
||||
FOR rec1 IN c1
|
||||
loop
|
||||
BEGIN
|
||||
v_newline := rec1.fac_imp_file_line;
|
||||
v_errormsg := 'Fout opvragen te importeren rij';
|
||||
v_aanduiding := '';
|
||||
v_ongeldig := 0;
|
||||
-- Lees alle veldwaarden
|
||||
fac.imp_getfield (v_newline, c_fielddelimitor, v_srtdiscipline_omschrijving);
|
||||
fac.imp_getfield (v_newline, c_fielddelimitor, v_srtdiscipline_prefix);
|
||||
fac.imp_getfield (v_newline, c_fielddelimitor, v_srtdiscipline_alg);
|
||||
fac.imp_getfield (v_newline, c_fielddelimitor, v_srtdiscipline_ins);
|
||||
fac.imp_getfield (v_newline, c_fielddelimitor, v_srtdiscipline_bes);
|
||||
fac.imp_getfield (v_newline, c_fielddelimitor, v_discipline_omschrijving);
|
||||
fac.imp_getfield (v_newline, c_fielddelimitor, v_stdmelding_omschrijving);
|
||||
fac.imp_getfield (v_newline, c_fielddelimitor, v_stdmelding_groep);
|
||||
fac.imp_getfield (v_newline, c_fielddelimitor, v_stdmelding_kostensoort);
|
||||
fac.imp_getfield (v_newline, c_fielddelimitor, v_stdmelding_urgentie);
|
||||
fac.imp_getfield (v_newline, c_fielddelimitor, v_stdmelding_uitvoertijd);
|
||||
fac.imp_getfield (v_newline, c_fielddelimitor, v_stdmelding_streeftijd);
|
||||
fac.imp_getfield (v_newline, c_fielddelimitor, v_discipline_directklaar);
|
||||
fac.imp_getfield (v_newline, c_fielddelimitor, v_o_srtdiscipline_omschrijving);
|
||||
fac.imp_getfield (v_newline, c_fielddelimitor, v_o_discipline_omschrijving);
|
||||
fac.imp_getfield (v_newline, c_fielddelimitor, v_o_stdmelding_omschrijving);
|
||||
v_aanduiding :=
|
||||
'|'
|
||||
|| v_srtdiscipline_omschrijving
|
||||
|| '|'
|
||||
|| v_srtdiscipline_prefix
|
||||
|| '|'
|
||||
|| v_srtdiscipline_alg
|
||||
|| '|'
|
||||
|| v_srtdiscipline_ins
|
||||
|| '|'
|
||||
|| v_srtdiscipline_bes
|
||||
|| '|'
|
||||
|| v_discipline_omschrijving
|
||||
|| '|'
|
||||
|| v_stdmelding_omschrijving
|
||||
|| '|'
|
||||
|| v_stdmelding_kostensoort
|
||||
|| '|'
|
||||
|| v_stdmelding_urgentie
|
||||
|| '|'
|
||||
|| v_stdmelding_uitvoertijd
|
||||
|| '|'
|
||||
|| v_stdmelding_streeftijd
|
||||
|| '|'
|
||||
|| v_discipline_directklaar
|
||||
|| '| ';
|
||||
-- Ik controleer of ik een geldige header heb, dat is: in de juiste kolommen
|
||||
-- de juiste kolomkop. Ik controleer alleen de verplichte kolommen, ik zou ze ook
|
||||
-- allemaal kunnen doen..
|
||||
-- Ik negeer alles totdat ik een geldige header gepasseerd ben
|
||||
IF (header_is_valid = 0)
|
||||
THEN
|
||||
IF UPPER (v_srtdiscipline_omschrijving) = 'VAKGROEPTYPE'
|
||||
AND UPPER (v_discipline_omschrijving) = 'VAKGROEP'
|
||||
AND UPPER (v_stdmelding_omschrijving) = 'STANDAARDMELDING'
|
||||
THEN
|
||||
header_is_valid := 1;
|
||||
END IF;
|
||||
ELSE
|
||||
v_count_tot := v_count_tot + 1;
|
||||
-- Controleer alle veldwaarde
|
||||
v_srtdiscipline_omschrijving := TRIM (v_srtdiscipline_omschrijving);
|
||||
IF LENGTH (v_srtdiscipline_omschrijving) > 30
|
||||
THEN
|
||||
v_srtdiscipline_omschrijving := SUBSTR (TRIM (v_srtdiscipline_omschrijving), 1, 30);
|
||||
fac.imp_writelog (p_applname,
|
||||
p_applrun,
|
||||
'W',
|
||||
v_aanduiding,
|
||||
'Vakgroeptype wordt afgebroken tot [' || v_srtdiscipline_omschrijving || ']'
|
||||
);
|
||||
END IF;
|
||||
BEGIN
|
||||
SELECT ins_srtdiscipline_key INTO v_srtdiscipline_key FROM ins_srtdiscipline WHERE ins_srtdiscipline_omschrijving = v_srtdiscipline_omschrijving;
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND THEN
|
||||
v_srtdiscipline_key := -1;
|
||||
END;
|
||||
--
|
||||
v_discipline_omschrijving := TRIM (v_discipline_omschrijving);
|
||||
IF LENGTH (v_discipline_omschrijving) > 30
|
||||
THEN
|
||||
v_discipline_omschrijving := SUBSTR (v_discipline_omschrijving, 1, 30);
|
||||
fac.imp_writelog (p_applname,
|
||||
p_applrun,
|
||||
'W',
|
||||
v_aanduiding,
|
||||
'Vakgroep wordt afgebroken tot [' || v_discipline_omschrijving || ']'
|
||||
);
|
||||
END IF;
|
||||
BEGIN
|
||||
SELECT ins_discipline_key INTO v_discipline_key FROM mld_discipline WHERE ins_srtdiscipline_key = v_srtdiscipline_key AND ins_discipline_omschrijving = v_discipline_omschrijving;
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND THEN
|
||||
v_discipline_key := -1;
|
||||
END;
|
||||
--
|
||||
v_stdmelding_omschrijving := TRIM (v_stdmelding_omschrijving);
|
||||
IF LENGTH (v_stdmelding_omschrijving) > 60
|
||||
THEN
|
||||
v_stdmelding_omschrijving := SUBSTR (v_stdmelding_omschrijving, 1, 60);
|
||||
fac.imp_writelog (p_applname,
|
||||
p_applrun,
|
||||
'W',
|
||||
v_aanduiding,
|
||||
'Standaardmelding wordt afgebroken tot [' || v_stdmelding_omschrijving || ']'
|
||||
);
|
||||
END IF;
|
||||
BEGIN
|
||||
SELECT mld_stdmelding_key INTO v_stdmelding_key FROM mld_stdmelding WHERE mld_ins_discipline_key = v_discipline_key AND mld_stdmelding_omschrijving = v_stdmelding_omschrijving;
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND THEN
|
||||
v_stdmelding_key := -1;
|
||||
END;
|
||||
-- OLD
|
||||
IF LENGTH (v_o_srtdiscipline_omschrijving) > 30
|
||||
THEN
|
||||
v_o_srtdiscipline_omschrijving := SUBSTR (TRIM (v_o_srtdiscipline_omschrijving), 1, 30);
|
||||
fac.imp_writelog (p_applname,
|
||||
p_applrun,
|
||||
'W',
|
||||
v_aanduiding,
|
||||
'Vakgroeptype wordt afgebroken tot [' || v_o_srtdiscipline_omschrijving || ']'
|
||||
);
|
||||
END IF;
|
||||
BEGIN
|
||||
SELECT ins_srtdiscipline_key INTO v_o_srtdiscipline_key FROM ins_srtdiscipline WHERE ins_srtdiscipline_omschrijving = v_o_srtdiscipline_omschrijving;
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND THEN
|
||||
v_o_srtdiscipline_key := -1;
|
||||
END;
|
||||
--
|
||||
v_o_discipline_omschrijving := TRIM (v_o_discipline_omschrijving);
|
||||
IF LENGTH (v_o_discipline_omschrijving) > 30
|
||||
THEN
|
||||
v_o_discipline_omschrijving := SUBSTR (v_o_discipline_omschrijving, 1, 30);
|
||||
fac.imp_writelog (p_applname,
|
||||
p_applrun,
|
||||
'W',
|
||||
v_aanduiding,
|
||||
'Vakgroep wordt afgebroken tot [' || v_o_discipline_omschrijving || ']'
|
||||
);
|
||||
END IF;
|
||||
BEGIN
|
||||
SELECT ins_discipline_key INTO v_o_discipline_key FROM mld_discipline WHERE ins_srtdiscipline_key = v_o_srtdiscipline_key AND ins_discipline_omschrijving = v_o_discipline_omschrijving;
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND THEN
|
||||
v_o_discipline_key := -1;
|
||||
END;
|
||||
--
|
||||
v_o_stdmelding_omschrijving := TRIM (v_o_stdmelding_omschrijving);
|
||||
IF LENGTH (v_o_stdmelding_omschrijving) > 30
|
||||
THEN
|
||||
v_o_stdmelding_omschrijving := SUBSTR (v_o_stdmelding_omschrijving, 1, 30);
|
||||
fac.imp_writelog (p_applname,
|
||||
p_applrun,
|
||||
'W',
|
||||
v_aanduiding,
|
||||
'Standaardmelding wordt afgebroken tot [' || v_o_stdmelding_omschrijving || ']'
|
||||
);
|
||||
END IF;
|
||||
BEGIN
|
||||
SELECT mld_stdmelding_key INTO v_o_stdmelding_key FROM mld_stdmelding WHERE mld_ins_discipline_key = v_o_discipline_key AND mld_stdmelding_omschrijving = v_o_stdmelding_omschrijving;
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND THEN
|
||||
v_o_stdmelding_key := -1;
|
||||
END;
|
||||
-- Insert geformatteerde import record
|
||||
IF v_ongeldig = 0
|
||||
THEN
|
||||
BEGIN
|
||||
INSERT INTO gvba_conv_mld
|
||||
(n_ins_srtdiscipline_omschr,
|
||||
n_ins_srtdiscipline_key,
|
||||
n_ins_discipline_omschrijving,
|
||||
n_ins_discipline_key,
|
||||
n_mld_stdmelding_omschrijving,
|
||||
n_mld_stdmelding_key,
|
||||
o_ins_srtdiscipline_omschr,
|
||||
o_ins_srtdiscipline_key,
|
||||
o_ins_discipline_omschrijving,
|
||||
o_ins_discipline_key,
|
||||
o_mld_stdmelding_omschrijving,
|
||||
o_mld_stdmelding_key
|
||||
)
|
||||
VALUES (v_srtdiscipline_omschrijving,
|
||||
v_srtdiscipline_key,
|
||||
v_discipline_omschrijving,
|
||||
v_discipline_key,
|
||||
v_stdmelding_omschrijving,
|
||||
v_stdmelding_key,
|
||||
v_o_srtdiscipline_omschrijving,
|
||||
v_o_srtdiscipline_key,
|
||||
v_o_discipline_omschrijving,
|
||||
v_o_discipline_key,
|
||||
v_o_stdmelding_omschrijving,
|
||||
v_o_stdmelding_key
|
||||
);
|
||||
v_count_import := v_count_import + 1;
|
||||
EXCEPTION
|
||||
WHEN OTHERS
|
||||
THEN
|
||||
oracle_err_num := SQLCODE;
|
||||
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
|
||||
v_errormsg := ' ORACLE (error ' || oracle_err_num || '/' || oracle_err_mes || ')';
|
||||
fac.imp_writelog
|
||||
(p_applname,
|
||||
p_applrun,
|
||||
'E',
|
||||
v_aanduiding,
|
||||
'Fout bij toevoegen regel aan importtabel FAC_IMP_MLD. '
|
||||
|| v_errormsg
|
||||
);
|
||||
END;
|
||||
END IF;
|
||||
END IF;
|
||||
END;
|
||||
end loop;
|
||||
IF (header_is_valid = 0)
|
||||
THEN
|
||||
fac.imp_writelog (p_applname, p_applrun, 'E', v_aanduiding || 'Ongeldig importbestand', 'Toelichting: ... ');
|
||||
ELSE
|
||||
fac.imp_writelog (p_applname,
|
||||
p_applrun,
|
||||
'S',
|
||||
'Servicedesk: aantal ingelezen regels: ' || TO_CHAR (v_count_tot),
|
||||
''
|
||||
);
|
||||
fac.imp_writelog (p_applname,
|
||||
p_applrun,
|
||||
'S',
|
||||
'Servicedesk: aantal ongeldige niet ingelezen importregels: <b>'
|
||||
|| TO_CHAR (v_count_tot - v_count_import),
|
||||
''
|
||||
);
|
||||
END IF;
|
||||
|
||||
v_hint := 'Aanmaken kenmerk 41';
|
||||
INSERT INTO mld_kenmerk
|
||||
(
|
||||
mld_srtkenmerk_key, mld_stdmelding_key, mld_kenmerk_niveau, mld_kenmerk_verplicht, mld_kenmerk_volgnummer
|
||||
)
|
||||
(SELECT 41, ins_discipline_key, 'D', 1, 101
|
||||
FROM mld_discipline
|
||||
WHERE ins_discipline_key NOT IN (SELECT mld_stdmelding_key
|
||||
FROM mld_kenmerk
|
||||
WHERE mld_srtkenmerk_key = 41));
|
||||
|
||||
v_hint := 'Aanmaken kenmerk 61';
|
||||
INSERT INTO mld_kenmerk
|
||||
(
|
||||
mld_srtkenmerk_key, mld_stdmelding_key, mld_kenmerk_niveau, mld_kenmerk_verplicht, mld_kenmerk_volgnummer
|
||||
)
|
||||
(SELECT 61, ins_discipline_key, 'D', 1, 101
|
||||
FROM mld_discipline
|
||||
WHERE ins_discipline_key NOT IN (SELECT mld_stdmelding_key
|
||||
FROM mld_kenmerk
|
||||
WHERE mld_srtkenmerk_key = 61)
|
||||
AND ins_discipline_key NOT IN
|
||||
(SELECT ins_discipline_key
|
||||
FROM ins_tab_discipline d, ins_srtdiscipline sd
|
||||
WHERE d.ins_srtdiscipline_key = sd.ins_srtdiscipline_key
|
||||
AND sd.ins_srtdiscipline_prefix = 'FZ')
|
||||
AND ins_discipline_aanmaak > SYSDATE - 1);
|
||||
|
||||
v_hint:= 'Aanpassen melding aan nieuwe stdmelding en discipline';
|
||||
UPDATE mld_melding m
|
||||
SET mld_ins_discipline_key =
|
||||
(SELECT n_ins_discipline_key
|
||||
FROM gvba_conv_mld c
|
||||
WHERE c.o_mld_stdmelding_key = m.mld_stdmelding_key),
|
||||
mld_stdmelding_key =
|
||||
(SELECT n_mld_stdmelding_key
|
||||
FROM gvba_conv_mld c
|
||||
WHERE c.o_mld_stdmelding_key = m.mld_stdmelding_key)
|
||||
WHERE EXISTS (SELECT n_mld_stdmelding_key
|
||||
FROM gvba_conv_mld c
|
||||
WHERE c.o_mld_stdmelding_key = m.mld_stdmelding_key);
|
||||
|
||||
v_hint := 'Overzetten kenmerken stdmelding';
|
||||
UPDATE mld_kenmerk m
|
||||
SET mld_stdmelding_key =
|
||||
(SELECT n_mld_stdmelding_key
|
||||
FROM gvba_conv_mld c
|
||||
WHERE c.o_mld_stdmelding_key = m.mld_stdmelding_key)
|
||||
WHERE EXISTS (SELECT n_mld_stdmelding_key
|
||||
FROM gvba_conv_mld c
|
||||
WHERE c.o_mld_stdmelding_key = m.mld_stdmelding_key)
|
||||
AND mld_kenmerk_niveau = 'S';
|
||||
|
||||
v_hint := 'Overzetten kenmerken discipline';
|
||||
UPDATE mld_kenmerkmelding km
|
||||
SET mld_kenmerk_key =
|
||||
(SELECT k2.mld_kenmerk_key
|
||||
FROM mld_kenmerk k1, mld_srtkenmerk sk, mld_kenmerk k2, mld_melding m
|
||||
WHERE k1.mld_srtkenmerk_key = sk.mld_srtkenmerk_key
|
||||
AND km.mld_melding_key = m.mld_melding_key
|
||||
AND m.mld_ins_discipline_key = k2.mld_stdmelding_key
|
||||
AND k2.mld_kenmerk_niveau = 'D'
|
||||
AND k2.mld_srtkenmerk_key = sk.mld_srtkenmerk_key
|
||||
AND km.mld_kenmerk_key = k1.mld_kenmerk_key)
|
||||
WHERE km.mld_kenmerk_key IN
|
||||
(SELECT k1.mld_kenmerk_key
|
||||
FROM mld_kenmerk k1,
|
||||
mld_srtkenmerk sk,
|
||||
mld_kenmerk k2,
|
||||
mld_melding m
|
||||
WHERE k1.mld_srtkenmerk_key = sk.mld_srtkenmerk_key
|
||||
AND km.mld_melding_key = m.mld_melding_key
|
||||
AND m.mld_ins_discipline_key = k2.mld_stdmelding_key
|
||||
AND k2.mld_kenmerk_niveau = 'D'
|
||||
AND k2.mld_srtkenmerk_key = sk.mld_srtkenmerk_key
|
||||
AND km.mld_kenmerk_key = k1.mld_kenmerk_key);
|
||||
|
||||
|
||||
COMMIT;
|
||||
EXCEPTION
|
||||
WHEN OTHERS
|
||||
THEN
|
||||
oracle_err_num := SQLCODE;
|
||||
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
|
||||
v_hint := v_errormsg;
|
||||
v_errormsg := 'OTHERS (error ' || oracle_err_num || '/' || oracle_err_mes || ')';
|
||||
fac.imp_writelog (p_applname, p_applrun, 'E', v_errormsg, v_hint);
|
||||
END gvba_import_mld;
|
||||
/
|
||||
|
||||
|
||||
-- begin gvba_import_mld('MLD', 'now', '',''); end;
|
||||
|
||||
commit;
|
||||
|
||||
SPOOL OFF
|
||||
|
||||
Reference in New Issue
Block a user