TDNL#80795 -- Migratie CONN omgeving naar TDNL omgeving
svn path=/Customer/trunk/; revision=63174
This commit is contained in:
598
TDNL/TDNL.sql
598
TDNL/TDNL.sql
@@ -134,6 +134,562 @@ END;
|
||||
|
||||
|
||||
-- IMPORTS
|
||||
|
||||
-- Import meldingen uit CONN omgeveing
|
||||
CREATE OR REPLACE PROCEDURE TDNL_IMPORT_MELDINGEN(p_import_key IN NUMBER)
|
||||
AS
|
||||
BEGIN
|
||||
DELETE
|
||||
FROM fac_imp_csv
|
||||
WHERE fac_import_key = (SELECT MAX(fac_import_key)
|
||||
FROM fac_import_app fa,
|
||||
fac_import fi
|
||||
WHERE fa.fac_import_app_code='MELDINGEN'
|
||||
AND fi.fac_import_app_key=fa.fac_import_app_key);
|
||||
|
||||
fac_import_genericcsv(p_import_key);
|
||||
END;
|
||||
/
|
||||
|
||||
CREATE OR REPLACE PROCEDURE TDNL_UPDATE_MELDINGEN(p_import_key IN NUMBER)
|
||||
AS
|
||||
CURSOR c
|
||||
IS
|
||||
SELECT fac_imp_csv_col01 mld_melding_key,
|
||||
fac_imp_csv_col02 alg_locatie_code,
|
||||
fac_imp_csv_col03 alg_ruimte_nr,
|
||||
fac_imp_csv_col04 mld_stdmelding,
|
||||
TO_DATE(fac_imp_csv_col05,'DD-MM-YYYY HH24:MI:SS') mld_datum,
|
||||
TO_DATE(fac_imp_csv_col06,'DD-MM-YYYY HH24:MI:SS') mld_afmelddatum,
|
||||
fac_imp_csv_col07 mld_uitvoertijd,
|
||||
fac_imp_csv_col08 mld_uitvoertijd_eenheid,
|
||||
fac_imp_csv_col09 mld_onderwerp,
|
||||
fac_imp_csv_col10 mld_status_key,
|
||||
fac_imp_csv_col11 prs_aanvrager_email,
|
||||
fac_imp_csv_col12 prs_behandelaar_email,
|
||||
fac_imp_csv_col13 kostenplaats_code,
|
||||
fac_imp_csv_col14 mld_omschrijving
|
||||
from fac_imp_csv
|
||||
WHERE fac_import_key = p_import_key;
|
||||
|
||||
v_locatie_key NUMBER;
|
||||
v_ruimte_key NUMBER;
|
||||
v_aanvrager_key NUMBER;
|
||||
v_behandelaar_key NUMBER;
|
||||
v_stdmelding_key NUMBER;
|
||||
v_kostenplaats_key NUMBER;
|
||||
v_mld_meldbron_key NUMBER;
|
||||
v_error NUMBER;
|
||||
v_mldkey NUMBER;
|
||||
BEGIN
|
||||
v_stdmelding_key := 1; -- standaard worden alle migratie meldingen op de stdmelding overig gezet
|
||||
v_mld_meldbron_key :=5;
|
||||
FOR rec IN c
|
||||
LOOP
|
||||
BEGIN
|
||||
SELECT alg_locatie_key INTO v_locatie_key
|
||||
FROm alg_locatie l
|
||||
WHERE l.alg_locatie_code = rec.alg_locatie_code;
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND
|
||||
THEN
|
||||
-- wat wordt de fall back locatie
|
||||
v_error:=1;
|
||||
v_locatie_key:=0;
|
||||
END;
|
||||
|
||||
BEGIN
|
||||
SELECT a.alg_ruimte_key INTO v_ruimte_key
|
||||
FROm alg_v_ruimte_gegevens_all a
|
||||
WHERE a.alg_locatie_key = v_locatie_key
|
||||
AND a.ALG_RUIMTE_NR = rec.alg_ruimte_nr;
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND
|
||||
THEN
|
||||
-- wat wordt de fall back locatie
|
||||
v_error:=1;
|
||||
v_ruimte_key:=0;
|
||||
END;
|
||||
|
||||
|
||||
BEGIN
|
||||
SELECT prs_perslid_key into v_behandelaar_key
|
||||
FROM prs_perslid
|
||||
WHERE prs_perslid_email = rec.prs_behandelaar_email;
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND
|
||||
THEN
|
||||
-- Wat wordt de fallback aanvrager
|
||||
|
||||
v_error:=1;
|
||||
v_aanvrager_key:=0;
|
||||
END;
|
||||
BEGIN
|
||||
SELECT prs_perslid_key into v_aanvrager_key
|
||||
FROM prs_perslid
|
||||
WHERE prs_perslid_email = rec.prs_aanvrager_email;
|
||||
|
||||
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND
|
||||
THEN
|
||||
-- wat wordt de fallvback behandelaar
|
||||
v_error:=1;
|
||||
v_aanvrager_key:=0;
|
||||
END;
|
||||
BEGIN
|
||||
SELECT prs_kostenplaats_key into v_kostenplaats_key
|
||||
FROM prs_kostenplaats
|
||||
WHERE prs_KOSTENPLAATS_NR = rec.kostenplaats_code;
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND
|
||||
THEN
|
||||
-- wat wordt de fallvback behandelaar
|
||||
v_error:=0;
|
||||
v_kostenplaats_key:=0;
|
||||
END;
|
||||
|
||||
IF v_error=0 THEN
|
||||
INSERT INTO mld_melding (mld_melding_module,
|
||||
mld_meldbron_key,
|
||||
mld_alg_locatie_key,
|
||||
mld_alg_onroerendgoed_keys,
|
||||
mld_melding_datum,
|
||||
mld_melding_onderwerp,
|
||||
mld_melding_omschrijving,
|
||||
mld_melding_behandelaar_key,
|
||||
mld_melding_behandelaar2_key,
|
||||
mld_stdmelding_key,
|
||||
mld_melding_t_uitvoertijd,
|
||||
mld_melding_einddatum,
|
||||
prs_perslid_key,
|
||||
prs_perslid_key_voor,
|
||||
mld_melding_status,
|
||||
mld_melding_spoed,
|
||||
MLD_MELDING_EXTERNNR)
|
||||
VALUES ('MLD',
|
||||
v_mld_meldbron_key,
|
||||
v_locatie_key,
|
||||
NULL,
|
||||
rec.mld_datum,
|
||||
rec.mld_onderwerp,
|
||||
rec.mld_omschrijving,
|
||||
v_behandelaar_key, -- mld_melding_behandelaar_key
|
||||
NULL, -- mld_melding_behandelaar2_key
|
||||
v_stdmelding_key,
|
||||
MLD_T_UITVOERTIJD(rec.mld_uitvoertijd,rec.mld_uitvoertijd_eenheid),
|
||||
rec.mld_afmelddatum,
|
||||
v_aanvrager_key,
|
||||
v_aanvrager_key,
|
||||
rec.mld_status_key,
|
||||
3,
|
||||
rec.mld_melding_key
|
||||
)
|
||||
RETURNING mld_melding_key
|
||||
INTO v_mldkey;
|
||||
|
||||
INSERT INTO mld_melding_note (mld_melding_key,
|
||||
mld_melding_note_aanmaak,
|
||||
mld_melding_note_wijzigdatum,
|
||||
prs_perslid_key,
|
||||
mld_melding_note_omschrijving,
|
||||
mld_melding_note_flag)
|
||||
VALUES (v_mldkey,
|
||||
rec.mld_datum,
|
||||
SYSDATE,
|
||||
NULL, -- Facilitor
|
||||
'Migratie melding van Meldingnr ' || rec.mld_melding_key,
|
||||
0);
|
||||
|
||||
|
||||
END IF;
|
||||
|
||||
|
||||
END LOOP;
|
||||
|
||||
|
||||
|
||||
|
||||
END;
|
||||
/
|
||||
-- EINDE meldingen import
|
||||
|
||||
-- Import tracking
|
||||
CREATE OR REPLACE PROCEDURE TDNL_IMPORT_TRACKING(p_import_key IN NUMBER)
|
||||
AS
|
||||
BEGIN
|
||||
DELETE
|
||||
FROM fac_imp_csv
|
||||
WHERE fac_import_key = (SELECT MAX(fac_import_key)
|
||||
FROM fac_import_app fa,
|
||||
fac_import fi
|
||||
where fa.fac_import_app_code='TRACKING'
|
||||
AND fi.fac_import_app_key=fa.fac_import_app_key);
|
||||
|
||||
fac_import_genericcsv(p_import_key);
|
||||
END;
|
||||
/
|
||||
|
||||
CREATE OR REPLACE PROCEDURE TDNL_UPDATE_TRACKING(p_import_key IN NUMBER)
|
||||
AS
|
||||
CURSOR c
|
||||
IS
|
||||
SELECT fac_imp_csv_col01 module,
|
||||
fac_imp_csv_col02 entity_id,
|
||||
fac_imp_csv_col03 fac_tracking_oms,
|
||||
fac_imp_csv_col04 fac_srtnotificatie_key,
|
||||
fac_imp_csv_col05 fac_tracking_datum,
|
||||
fac_imp_csv_col06 prs_perslid_email,
|
||||
fac_imp_csv_col07 prs_perslid_oslogin
|
||||
from fac_imp_csv
|
||||
WHERE fac_import_key = p_import_key;
|
||||
|
||||
v_errormsg VARCHAR2 (1000);
|
||||
v_errorhint VARCHAR2 (1000);
|
||||
v_aanduiding VARCHAR2 (1000);
|
||||
oracle_err_num NUMBER;
|
||||
oracle_err_mes VARCHAR2 (200);
|
||||
v_error NUMBER;
|
||||
v_count NUMBER;
|
||||
v_entity_key NUMBER;
|
||||
v_prs_perslid_key NUMBER;
|
||||
BEGIN
|
||||
|
||||
FOR rec in c
|
||||
LOOP
|
||||
BEGIN
|
||||
v_errormsg:='Ophalen van '||rec.module||' met key '||rec.entity_id||' is mislukt';
|
||||
IF rec.module='CNT'
|
||||
THEN
|
||||
SElect cnt_contract_key into v_entity_key
|
||||
FROM cnt_contract c
|
||||
where c.cnt_contract_nummer=rec.entity_id
|
||||
AND c.cnt_contract_verwijder IS NULL;
|
||||
ELSIF rec.module='INS'
|
||||
THEN
|
||||
SELECT ins_deel_key
|
||||
INTO v_entity_key
|
||||
FROM ins_deel i
|
||||
WHERE i.ins_deel_omschrijving=rec.entity_id
|
||||
AND i.ins_deel_verwijder IS NULL;
|
||||
END IF;
|
||||
|
||||
v_errormsg:='Ophalen van '||rec.prs_perslid_email||'/'||rec.prs_perslid_oslogin||' is mislukt';
|
||||
|
||||
SELECT prs_perslid_key
|
||||
into v_prs_perslid_key
|
||||
FROM prs_perslid p
|
||||
where p.prs_perslid_email=rec.prs_perslid_email
|
||||
OR p.prs_perslid_oslogin=rec.prs_perslid_oslogin;
|
||||
|
||||
INSERT INTO fac_tracking( fac_tracking_refkey,
|
||||
fac_tracking_oms,
|
||||
fac_srtnotificatie_key,
|
||||
fac_tracking_datum,
|
||||
prs_perslid_key)
|
||||
VALUES( v_entity_key,
|
||||
rec.fac_tracking_oms,
|
||||
rec.fac_srtnotificatie_key,
|
||||
rec.fac_tracking_datum,
|
||||
v_prs_perslid_key);
|
||||
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND THEN
|
||||
v_error:=1;
|
||||
fac.imp_writelog (p_import_key,
|
||||
'E',
|
||||
v_errormsg,
|
||||
v_errorhint);
|
||||
|
||||
END;
|
||||
END LOOP;
|
||||
|
||||
END;
|
||||
/
|
||||
-- EINDE IMPORT MELDINGEN
|
||||
|
||||
-- IMPORT Opdrachten
|
||||
|
||||
CREATE OR REPLACE PROCEDURE TDNL_IMPORT_OPDRACHTEN(p_import_key IN NUMBER)
|
||||
AS
|
||||
BEGIN
|
||||
DELETE
|
||||
FROM fac_imp_csv
|
||||
WHERE fac_import_key = (SELECT MAX(fac_import_key)
|
||||
FROM fac_import_app fa,
|
||||
fac_import fi
|
||||
WHERE fa.fac_import_app_code='OPDRACHT'
|
||||
AND fi.fac_import_app_key=fa.fac_import_app_key);
|
||||
COMMIT;
|
||||
fac_import_genericcsv(p_import_key);
|
||||
END;
|
||||
/
|
||||
|
||||
CREATE OR REPLACE PROCEDURE TDNL_UPDATE_OPDRACHTEN(p_import_key IN NUMBER)
|
||||
AS
|
||||
CURSOR opd
|
||||
IS
|
||||
SELECT *
|
||||
FROM fac_imp_csv f
|
||||
WHERE f.fac_import_key = p_import_key;
|
||||
|
||||
|
||||
v_date DATE;
|
||||
BEGIN
|
||||
-- Om wat voor melding gaat het,
|
||||
-- Welk opdracht type is het,
|
||||
-- Welke relatie is het,
|
||||
-- Wat is de discipline key van de Overig vakgroep (mld_opdr_discipline_key)
|
||||
|
||||
SELECT SYSDATE INTO v_date FROM DUAL;
|
||||
END;
|
||||
/
|
||||
|
||||
|
||||
-- EINDE IMPORT OPDRACHTEN
|
||||
|
||||
|
||||
|
||||
-- Import taken uit CONN omgeving
|
||||
|
||||
CREATE OR REPLACE PROCEDURE TDNL_IMPORT_TAKEN(p_import_key IN NUMBER)
|
||||
AS
|
||||
BEGIN
|
||||
DELETE FROM fac_imp_csv WHERE fac_import_key = (SELECT MAX(fac_import_key) FROM fac_import_app fa, fac_import fi where fa.fac_import_app_code='TAKEN' AND fi.fac_import_app_key=fa.fac_import_app_key);
|
||||
COMMIT;
|
||||
fac_import_genericcsv(p_import_key);
|
||||
END;
|
||||
/
|
||||
|
||||
CREATE OR REPLACE PROCEDURE TDNL_UPDATE_TAKEN(p_import_key IN NUMBER)
|
||||
AS
|
||||
CURSOR c
|
||||
IS
|
||||
SELECT fac_imp_csv_col02 ins_deel_omschrijving,
|
||||
fac_imp_csv_col03 ins_deel_aanmtal,
|
||||
fac_imp_csv_col04 ins_deel_aanmaak,
|
||||
fac_imp_csv_col05 ins_discipline,
|
||||
fac_imp_csv_col06 ins_groep,
|
||||
fac_imp_csv_col07 ins_srtdeel_code,
|
||||
fac_imp_csv_col08 ins_srtdeel,
|
||||
fac_imp_csv_col09 ins_srtcontrole_key,
|
||||
fac_imp_csv_col10 ins_srtcontrole_omschrijving,
|
||||
fac_imp_csv_col11 ins_srtcontrole_niveau,
|
||||
fac_imp_csv_col13 ctr_disipline_omschrijving,
|
||||
fac_imp_csv_col14 ins_srtcontrole_cyclus,
|
||||
fac_imp_csv_col15 ins_srtcontrole_eenheid,
|
||||
fac_imp_csv_col16 ins_srtcontrole_eenheid_key,
|
||||
fac_imp_csv_col17 ins_deelsrtcontrole_key,
|
||||
fac_imp_csv_col18 ins_deelsrtcotrole_datum,
|
||||
fac_imp_csv_col20 ins_deelsrtcotrole_nextdatum,
|
||||
fac_imp_csv_col21 ins_deelsrtcotrole_status_key,
|
||||
fac_imp_csv_col23 ins_deelsrtcontrole_opm,
|
||||
fac_imp_csv_col24 prs_perslid_oslogin,
|
||||
fac_imp_csv_col25 prs_perslid_email
|
||||
from fac_imp_csv
|
||||
WHERE fac_import_key = p_import_key;
|
||||
|
||||
|
||||
v_errormsg VARCHAR2 (1000);
|
||||
v_errorhint VARCHAR2 (1000);
|
||||
v_aanduiding VARCHAR2 (1000);
|
||||
oracle_err_num NUMBER;
|
||||
oracle_err_mes VARCHAR2 (200);
|
||||
v_error NUMBER;
|
||||
v_count NUMBER;
|
||||
|
||||
v_ins_deel_key NUMBER;
|
||||
v_ins_srtdeel_key NUMBER;
|
||||
v_ins_srtcontrole_key NUMBER;
|
||||
v_srtcontrole_level NUMBER;
|
||||
v_srtcontrole_percentage NUMBER;
|
||||
v_srtcontrole_omschrijving VARCHAR2(60);
|
||||
v_taak_cyclus NUMBER;
|
||||
v_taak_eenheid NUMBER;
|
||||
v_taakcat_key NUMBER;
|
||||
v_taak_datum DATE;
|
||||
v_prs_perslid_key NUMBER;
|
||||
|
||||
BEGIN
|
||||
v_count:=0;
|
||||
|
||||
|
||||
|
||||
FOR rec IN c
|
||||
LOOP
|
||||
v_error:=0;
|
||||
v_count:=v_count+1;
|
||||
v_errormsg:='Object '||rec.ins_deel_omschrijving|| ' niet gevonden.';
|
||||
BEGIN
|
||||
SELECT i.ins_deel_key, i.ins_srtdeel_key
|
||||
INTO v_ins_deel_key, v_ins_srtdeel_key
|
||||
FROM ins_deel i
|
||||
WHERE i.ins_deel_omschrijving=rec.ins_deel_omschrijving;
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND THEN
|
||||
v_error:=1;
|
||||
fac.imp_writelog (p_import_key,
|
||||
'E',
|
||||
v_errormsg,
|
||||
v_errorhint);
|
||||
END;
|
||||
|
||||
|
||||
v_errormsg:='Taak categorie '||rec.ctr_disipline_omschrijving|| ' niet gevonden.';
|
||||
BEGIN
|
||||
SELECT ins_discipline_key
|
||||
INTO v_taakcat_key
|
||||
FROM ctr_v_aanwezigdiscipline
|
||||
WHERE UPPER(ins_discipline_omschrijving) = UPPER(rec.ctr_disipline_omschrijving)
|
||||
AND ins_discipline_module='CTR'
|
||||
AND ins_discipline_verwijder IS NULL;
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND THEN
|
||||
v_error:=1;
|
||||
fac.imp_writelog (p_import_key,
|
||||
'E',
|
||||
v_errormsg,
|
||||
v_errorhint);
|
||||
END;
|
||||
|
||||
v_errormsg:='Persoon '||rec.prs_perslid_email||'/'||rec.prs_perslid_oslogin||' niet gevonden.';
|
||||
BEGIN
|
||||
SELECT p.prs_perslid_key
|
||||
INTO v_prs_perslid_key
|
||||
FROM prs_perslid p
|
||||
WHERE p.prs_perslid_email = rec.prs_perslid_email
|
||||
OR p.prs_perslid_oslogin= rec.prs_perslid_oslogin;
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND THEN
|
||||
v_error:=1;
|
||||
fac.imp_writelog (p_import_key,
|
||||
'E',
|
||||
v_errormsg,
|
||||
v_errorhint);
|
||||
END;
|
||||
|
||||
IF (v_error=0)
|
||||
THEN
|
||||
v_srtcontrole_level := 10;
|
||||
v_srtcontrole_percentage:=0;
|
||||
v_srtcontrole_omschrijving:= rec.ins_srtcontrole_omschrijving;
|
||||
v_taak_cyclus := fac.safe_to_number(rec.ins_srtcontrole_cyclus);
|
||||
v_taak_eenheid := fac.safe_to_number(rec.ins_srtcontrole_eenheid_key);
|
||||
IF INSTR(rec.ins_deelsrtcotrole_datum,':') > 0
|
||||
THEN
|
||||
v_taak_datum := fac.safe_to_date(rec.ins_deelsrtcotrole_datum,'DD-MM-YYYY HH24:MI');
|
||||
ELSE
|
||||
v_taak_datum := fac.safe_to_date(rec.ins_deelsrtcotrole_datum,'DD-MM-YYYY');
|
||||
END IF;
|
||||
|
||||
IF v_taak_cyclus=0 THEN
|
||||
v_taak_cyclus:=99;
|
||||
END IF;
|
||||
|
||||
|
||||
v_errormsg:= 'Soorttaak is niet gevonden';
|
||||
|
||||
-- Hebben we al een srtcontrole onder dit objectsoort en deze omschrijving ?
|
||||
BEGIN
|
||||
SELECT isc.ins_srtcontrole_key
|
||||
INTO v_ins_srtcontrole_key
|
||||
FROM ins_srtcontrole isc
|
||||
WHERE isc.ins_srtcontrole_omschrijving = rec.ins_srtcontrole_omschrijving
|
||||
AND isc.ins_Srtcontrole_periode = v_taak_cyclus
|
||||
AND ins_srtcontrole_eenheid = v_taak_eenheid
|
||||
AND ins_srtcontrole_level=v_srtcontrole_level
|
||||
AND isc.ins_srtcontrole_niveau='S';
|
||||
|
||||
INSERT INTO ins_deelsrtcontrole(
|
||||
ins_deel_key,
|
||||
ins_srtcontrole_key,
|
||||
ins_deelsrtcontrole_datum,
|
||||
ins_deelsrtcontrole_datum_org,
|
||||
ins_controlemode_key,
|
||||
prs_perslid_key,
|
||||
ins_deelsrtcontrole_status,
|
||||
ins_scenario_key,
|
||||
ins_deelsrtcontrole_opmerking)
|
||||
VALUES(
|
||||
v_ins_deel_key,
|
||||
v_ins_srtcontrole_key,
|
||||
v_taak_datum,
|
||||
v_taak_datum,
|
||||
10,
|
||||
v_prs_perslid_key,
|
||||
6,
|
||||
1,
|
||||
rec.ins_deelsrtcontrole_opm);
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND
|
||||
THEN
|
||||
|
||||
v_errorhint := 'Aanmaken srtcontrole';
|
||||
fac.imp_writelog (p_import_key,
|
||||
'W',
|
||||
v_count||'-'||v_taak_cyclus,
|
||||
v_errorhint);
|
||||
|
||||
-- nu moet we een ins_srtcontrole aanmaken
|
||||
|
||||
INSERT INTO ins_srtcontrole (
|
||||
ins_srtinstallatie_key,
|
||||
ins_srtcontrole_niveau,
|
||||
ins_srtcontrole_omschrijving,
|
||||
ctr_discipline_key,
|
||||
ins_Srtcontrole_periode,
|
||||
ins_srtcontrole_eenheid,
|
||||
ins_srtcontrole_level
|
||||
)
|
||||
VALUES (
|
||||
v_ins_srtdeel_key,
|
||||
'S',
|
||||
v_srtcontrole_omschrijving,
|
||||
v_taakcat_key,
|
||||
v_taak_cyclus,
|
||||
v_taak_eenheid,
|
||||
v_srtcontrole_level
|
||||
)
|
||||
RETURNING ins_srtcontrole_key INTO v_ins_srtcontrole_key;
|
||||
|
||||
|
||||
INSERT INTO ins_deelsrtcontrole(
|
||||
ins_deel_key,
|
||||
ins_srtcontrole_key,
|
||||
ins_deelsrtcontrole_datum,
|
||||
ins_deelsrtcontrole_datum_org,
|
||||
ins_controlemode_key,
|
||||
prs_perslid_key,
|
||||
ins_deelsrtcontrole_status,
|
||||
ins_scenario_key,
|
||||
ins_deelsrtcontrole_opmerking)
|
||||
VALUES(
|
||||
v_ins_deel_key,
|
||||
v_ins_srtcontrole_key,
|
||||
v_taak_datum,
|
||||
v_taak_datum,
|
||||
10,
|
||||
v_prs_perslid_key,
|
||||
6,
|
||||
1,
|
||||
rec.ins_deelsrtcontrole_opm);
|
||||
END;
|
||||
END IF;
|
||||
END LOOP;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
v_errorhint := v_errormsg || ' - ' || v_aanduiding;
|
||||
oracle_err_num := SQLCODE;
|
||||
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
|
||||
v_errormsg := 'error ' || oracle_err_num || '/' || oracle_err_mes;
|
||||
fac.imp_writelog (p_import_key,
|
||||
'E',
|
||||
v_errormsg,
|
||||
v_errorhint);
|
||||
END;
|
||||
/
|
||||
|
||||
|
||||
-- Oprognose import MJOB
|
||||
CREATE OR REPLACE PROCEDURE TDNL_IMPORT_ASSETS_INI(p_import_key IN NUMBER)
|
||||
AS
|
||||
@@ -1628,22 +2184,32 @@ CREATE OR REPLACE VIEW tdnl_v_gebouw_xy
|
||||
waarde,
|
||||
tilte,
|
||||
regio,
|
||||
concessie
|
||||
concessie,
|
||||
color
|
||||
)
|
||||
AS
|
||||
SELECT alg_gebouw_key,
|
||||
alg_gebouw_naam,
|
||||
DECODE(SUBSTR(rg.ALG_REGIO_UPPER,1,2),'TA',5, 'AM',15, 'OP', 25, 35) waarde, -- TAxi : rood, Ambulance(witte lkruis) : oranje, Openbaarvervoer (OP) : Groen, Overige geen kleur
|
||||
l.alg_locatie_code waarde,
|
||||
--DECODE(SUBSTR(rg.ALG_REGIO_UPPER,1,2),'TA',5, 'AM',15, 'OP', 25, 35) waarde, -- TAxi : rood, Ambulance(witte lkruis) : oranje, Openbaarvervoer (OP) : Groen, Overige geen kleur
|
||||
bv.alg_gebouw_code,
|
||||
rg.alg_regio_omschrijving regio,
|
||||
d.alg_district_omschrijving concessie
|
||||
d.alg_district_omschrijving concessie,
|
||||
COALESCE((SELECT fud.fac_usrdata_omschr
|
||||
FROM FAC_USRTAB fut,
|
||||
FAC_USRDATA fud
|
||||
WHERE UPPER(fut.fac_usrtab_naam)=UPPER('ProdLijnKleur')
|
||||
AND fud.fac_usrtab_key = fut.fac_usrtab_key
|
||||
AND UPPER(fud.fac_usrdata_code)=UPPER(SUBSTR(rg.alg_regio_upper,1,2))),'#A3CAB8') color
|
||||
FROM alg_v_aanweziggebouw bv,
|
||||
alg_v_aanwezigdistrict d,
|
||||
alg_v_aanweziglocatie l,
|
||||
alg_v_aanwezigregio rg
|
||||
alg_v_aanwezigregio rg
|
||||
WHERE l.alg_locatie_key = bv.alg_locatie_key
|
||||
AND d.alg_district_key = l.alg_district_key
|
||||
AND rg.alg_regio_key=d.alg_regio_key;
|
||||
AND rg.alg_regio_key=d.alg_regio_key
|
||||
AND bv.alg_gebouw_x IS NOT NULL
|
||||
|
||||
|
||||
|
||||
CREATE OR REPLACE VIEW tdnl_v_concessie_locatie_matrix
|
||||
@@ -1864,6 +2430,28 @@ AS
|
||||
|
||||
-- EINDE VIEWS
|
||||
|
||||
-- COUPA EXPORT VIEWS/PROCEDURES
|
||||
|
||||
-- Bijlage view tbv export naar coupa
|
||||
CREATE OR REPLACE VIEW tdnl_v_coupa_bijlages
|
||||
AS
|
||||
SELECT o.mld_opdr_key,
|
||||
o.mld_opdr_externsyncdate extern_syncdate,
|
||||
(SELECT ko.mld_kenmerkopdr_waarde
|
||||
FROM mld_kenmerkopdr ko
|
||||
WHERE ko.mld_opdr_key = o.mld_opdr_key
|
||||
AND ko.mld_kenmerk_key=62 -- A=62 P=
|
||||
AND ko.mld_kenmerkopdr_waarde IS NOT NULL) coupa_id,
|
||||
fb.fac_bijlagen_filename bestand,
|
||||
fb.fac_bijlagen_disk_directory path,
|
||||
fb.fac_bijlagen_aanmaak bijlage_aanmaak
|
||||
FROM mld_opdr o, fac_v_bijlagen fb
|
||||
WHERE fb.fac_bijlagen_refkey=o.mld_opdr_key
|
||||
AND o.mld_statusopdr_key IN (4,5)
|
||||
AND fb.fac_bijlagen_kenmerk_key=64 -- A=64 P=
|
||||
AND fb.fac_bijlagen_module='MLD';
|
||||
|
||||
|
||||
-- NOTIFICATIE JOBS
|
||||
|
||||
-- Notificatie tbv rappeltermijn conrtracten
|
||||
|
||||
Reference in New Issue
Block a user