1307 lines
53 KiB
SQL
1307 lines
53 KiB
SQL
--
|
||
-- $Id$
|
||
--
|
||
-- Script containing customer specific sql statements for the FACILITOR database
|
||
-- Voor dbuser invullen: - indien script voor 1 klant is: 'AADS' (de klantcode, zoals vermeld in fac_version_cust)
|
||
-- - script is voor meerdere klanten: 'AAXX' (de groepcode, zoals vermeld in fac_version_group)
|
||
-- - script is voor meerdere klanten met naam volgens een bepaald patroon: '^AA|^ASMS|^GULU|^NMMS|^RABO|^ZKHM'
|
||
-- Ook als het script gedraaid wordt voor de verkeerde cust wordt er een logfile gemaakt.
|
||
-- (dit in tegenstelling tot sample_xxxx.sql)
|
||
|
||
DEFINE thisfile = 'FZKH.SQL'
|
||
DEFINE dbuser = 'FZKH'
|
||
|
||
SET ECHO ON
|
||
SET DEFINE ON
|
||
COLUMN fcltlogfile NEW_VALUE fcltlogfile NOPRINT;
|
||
COLUMN fcltcusttxt NEW_VALUE fcltcusttxt NOPRINT;
|
||
WHENEVER SQLERROR CONTINUE;
|
||
SELECT adm.getscriptspoolfile('&thisfile') AS fcltlogfile FROM DUAL;
|
||
SPOOL &fcltlogfile
|
||
WHENEVER SQLERROR EXIT;
|
||
SELECT adm.checkscriptcust('&dbuser') AS fcltcusttxt FROM DUAL;
|
||
WHENEVER SQLERROR CONTINUE;
|
||
---------------------------------------
|
||
PROMPT &fcltcusttxt
|
||
---------------------------------------
|
||
SET DEFINE OFF
|
||
|
||
------ payload begin ------
|
||
|
||
CREATE OR REPLACE PROCEDURE FZKH_IMPORT_INSPECTIES(p_import_key IN NUMBER)
|
||
AS
|
||
BEGIN
|
||
fac_import_inspectie(p_import_key);
|
||
END;
|
||
/
|
||
|
||
CREATE OR REPLACE PROCEDURE FZKH_UPDATE_INSPECTIES(p_import_key IN NUMBER)
|
||
AS
|
||
v_errormsg VARCHAR2 (1000);
|
||
oracle_err_num NUMBER;
|
||
oracle_err_mes VARCHAR2 (200);
|
||
header_is_valid NUMBER;
|
||
v_count_error NUMBER (10);
|
||
v_count NUMBER (10);
|
||
v_count_tot NUMBER (10);
|
||
v_count_import NUMBER (10);
|
||
v_ongeldig NUMBER (1);
|
||
v_aanduiding VARCHAR2 (200);
|
||
v_errorhint VARCHAR2 (1000);
|
||
|
||
v_ins_srtinstallatie_key NUMBER (10);
|
||
v_ins_srtcontrole_niveau VARCHAR (1);
|
||
|
||
v_week_bits NUMBER (10);
|
||
v_maand_bits NUMBER (10);
|
||
|
||
v_ctr_ins_discipline_key NUMBER;
|
||
|
||
CURSOR c_inspecties
|
||
IS
|
||
SELECT * FROM fac_imp_inspectie;
|
||
-- MAIN
|
||
BEGIN
|
||
FOR rec_ins IN c_inspecties
|
||
LOOP
|
||
BEGIN
|
||
v_count_tot := v_count_tot + 1;
|
||
v_aanduiding :=
|
||
rec_ins.ins_discipline_omschrijving
|
||
|| ' - '
|
||
|| rec_ins.ins_srtgroep_omschrijving
|
||
|| '-'
|
||
|| rec_ins.ins_srtdeel_code;
|
||
v_errorhint := 'Fout bij bepalen discipline';
|
||
|
||
IF rec_ins.ins_discipline_omschrijving IS NULL
|
||
THEN
|
||
fac.imp_writelog (
|
||
p_import_key,
|
||
'E',
|
||
v_aanduiding,
|
||
'Discipline mag niet leeg zijn: inspectie wordt niet toegevoegd.');
|
||
ELSE
|
||
SELECT ins_discipline_key, 'D'
|
||
INTO v_ins_srtinstallatie_key, v_ins_srtcontrole_niveau
|
||
FROM ins_tab_discipline
|
||
WHERE UPPER (ins_discipline_omschrijving) =
|
||
UPPER (rec_ins.ins_discipline_omschrijving)
|
||
AND ins_discipline_module = 'INS'
|
||
AND ins_discipline_verwijder IS NULL;
|
||
|
||
IF rec_ins.ins_srtgroep_omschrijving IS NOT NULL
|
||
THEN
|
||
SELECT ins_srtgroep_key, 'G'
|
||
INTO v_ins_srtinstallatie_key, v_ins_srtcontrole_niveau
|
||
FROM ins_srtgroep
|
||
WHERE UPPER (ins_srtgroep_omschrijving) =
|
||
UPPER (rec_ins.ins_srtgroep_omschrijving)
|
||
AND ins_srtgroep_module = 'INS'
|
||
AND ins_srtgroep_verwijder IS NULL
|
||
AND ins_discipline_key = v_ins_srtinstallatie_key;
|
||
|
||
IF rec_ins.ins_srtdeel_code IS NOT NULL
|
||
THEN
|
||
SELECT ins_srtdeel_key, 'S'
|
||
INTO v_ins_srtinstallatie_key, v_ins_srtcontrole_niveau
|
||
FROM ins_srtdeel
|
||
WHERE UPPER (ins_srtdeel_code) = UPPER (rec_ins.ins_srtdeel_code)
|
||
AND ins_srtdeel_module = 'INS'
|
||
AND ins_srtdeel_verwijder IS NULL
|
||
AND ins_srtgroep_key = v_ins_srtinstallatie_key;
|
||
END IF;
|
||
END IF;
|
||
|
||
-- Alleen de gezette bits van de dagen van de week.
|
||
SELECT COALESCE(BITAND(rec_ins.ins_srtcontrole_bits, 127), 0)
|
||
INTO v_week_bits
|
||
FROM DUAL;
|
||
-- Alleen de gezette bits van de y-ste xxxdag van de maand.
|
||
SELECT COALESCE(BITAND(rec_ins.ins_srtcontrole_bits, 256 + 512 + 1024) / 256, 0)
|
||
INTO v_maand_bits
|
||
FROM DUAL;
|
||
|
||
v_aanduiding:='Taak categorie '||rec_ins.ins_srtcontrole_info||' niet gevonden';
|
||
SELECT ctr_ins_discipline_key
|
||
INTO v_ctr_ins_discipline_key
|
||
FROM ctr_disc_params csp,
|
||
ctr_discipline i
|
||
WHERE i.ins_discipline_omschrijving=rec_ins.ins_srtcontrole_info
|
||
AND i.ins_discipline_verwijder IS NULL
|
||
AND csp.ctr_ins_discipline_key = i.ins_discipline_key
|
||
AND csp.ctr_disc_params_controle_type=1 ;
|
||
|
||
IF rec_ins.ins_srtcontrole_omschrijving IS NOT NULL AND
|
||
rec_ins.ins_srtcontrole_periode IS NOT NULL AND
|
||
((rec_ins.ins_srtcontrole_eenheid = 0)
|
||
OR (rec_ins.ins_srtcontrole_eenheid > 0 AND MOD(rec_ins.ins_srtcontrole_periode, 1) = 0)) AND
|
||
rec_ins.ins_srtcontrole_eenheid IS NOT NULL AND
|
||
rec_ins.ins_srtcontrole_mode IS NOT NULL AND
|
||
(rec_ins.ins_srtcontrole_mode = 1 OR (1=1))
|
||
THEN
|
||
|
||
|
||
|
||
INSERT INTO ins_srtcontrole (ins_srtinstallatie_key,
|
||
ins_srtcontrole_niveau,
|
||
ins_srtcontrole_omschrijving,
|
||
ins_srtcontrole_info,
|
||
ins_srtcontrole_periode,
|
||
ins_srtcontrole_eenheid,
|
||
ins_srtcontrole_mode,
|
||
ins_srtcontrole_bits,
|
||
ctr_discipline_key
|
||
)
|
||
VALUES (v_ins_srtinstallatie_key,
|
||
v_ins_srtcontrole_niveau,
|
||
rec_ins.ins_srtcontrole_omschrijving,
|
||
rec_ins.ins_srtcontrole_info,
|
||
rec_ins.ins_srtcontrole_periode,
|
||
rec_ins.ins_srtcontrole_eenheid,
|
||
rec_ins.ins_srtcontrole_mode,
|
||
rec_ins.ins_srtcontrole_bits,
|
||
v_ctr_ins_discipline_key
|
||
);
|
||
ELSE
|
||
IF rec_ins.ins_srtcontrole_mode = 0 AND (v_week_bits = 0 OR v_maand_bits = 0)
|
||
THEN v_errorhint := 'Het verplichte veld "Moment" is niet (goed) ingevuld: inspectie wordt niet toegevoegd.';
|
||
ELSIF rec_ins.ins_srtcontrole_eenheid > 0 AND MOD(rec_ins.ins_srtcontrole_periode, 1) > 0
|
||
THEN v_errorhint := 'Periode moet een geheel getal zijn voor dagelijkse, wekelijkse, maandelijkse en jaarlijkse taken: inspectie wordt niet toegevoegd.';
|
||
ELSE v_errorhint := '<EFBFBD><EFBFBD>n of meerdere van de verplichte velden "Omschrijving", "Period", "Eenheid" of "Mode" zijn niet ingevuld: inspectie wordt niet toegevoegd.';
|
||
END IF;
|
||
fac.imp_writelog (
|
||
p_import_key,
|
||
'E',
|
||
v_aanduiding,
|
||
v_errorhint);
|
||
END IF;
|
||
END IF;
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
v_count_error := v_count_error + 1;
|
||
oracle_err_num := SQLCODE;
|
||
oracle_err_mes := SUBSTR (SQLERRM, 1, 200);
|
||
v_errormsg := 'OTHERS (error ' || oracle_err_num || '/' || oracle_err_mes || ')';
|
||
fac.imp_writelog (p_import_key,
|
||
'E',
|
||
v_aanduiding || v_errormsg,
|
||
v_errorhint);
|
||
COMMIT;
|
||
END;
|
||
END LOOP;
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
oracle_err_num := SQLCODE;
|
||
oracle_err_mes := SUBSTR (SQLERRM, 1, 150);
|
||
v_errormsg :=
|
||
v_errormsg || 'ORACLE (error ' || oracle_err_num || '/' || oracle_err_mes || ')';
|
||
fac.imp_writelog (p_import_key,
|
||
'E',
|
||
'Importproces inspecties afgebroken!',
|
||
v_errormsg);
|
||
END FZKH_UPDATE_INSPECTIES;
|
||
/
|
||
|
||
CREATE OR REPLACE PROCEDURE FZKH_IMPORT_SLEUTELS (p_import_key IN NUMBER)
|
||
AS
|
||
|
||
CURSOR c1
|
||
IS
|
||
SELECT *
|
||
FROM fac_imp_ins;
|
||
|
||
v_count NUMBER;
|
||
v_vervaldatum DATE;
|
||
BEGIN
|
||
|
||
fac_import_ins(p_import_key);
|
||
|
||
FOR rec in c1
|
||
LOOP
|
||
|
||
IF rec.prs_perslid_matchcode='4'
|
||
THEN
|
||
SELECT COUNT(*)
|
||
INTO v_count
|
||
FROM prs_perslid p
|
||
WHERE p.prs_perslid_nr = rec.prs_perslid_matchwaarde
|
||
AND p.prs_perslid_verwijder IS NULL
|
||
AND ( p.prs_perslid_inactief IS NULL
|
||
OR p.prs_perslid_inactief > SYSDATE);
|
||
ELSIF rec.prs_perslid_matchcode='3'
|
||
THEN
|
||
SELECT COUNT(*)
|
||
INTO v_count
|
||
FROM prs_v_perslid_fullnames p
|
||
WHERE p.prs_perslid_naam_full = rec.prs_perslid_matchwaarde;
|
||
ELSE
|
||
v_count:=0;
|
||
END IF;
|
||
|
||
v_vervaldatum := NULL;
|
||
IF UPPER(rec.ins_kenmerkwaarde1) = 'VERMIST'
|
||
THEN
|
||
v_vervaldatum := fac.safe_to_date(rec.ins_kenmerkwaarde2,'DD-MM-YYYY');
|
||
END IF;
|
||
IF v_count=0
|
||
THEN
|
||
UPDATE fac_imp_ins
|
||
SET alg_locatie_code = 'FZKH',
|
||
alg_gebouw_code = 'FZKH',
|
||
alg_verdieping_volgnr = '2',
|
||
alg_ruimte_nr = 'F201',
|
||
prs_perslid_matchcode = NULL,
|
||
prs_perslid_matchwaarde = NULL,
|
||
ins_deel_vervaldatum = v_vervaldatum
|
||
WHERE ins_deel_omschrijving=rec.ins_deel_omschrijving
|
||
AND ins_kenmerkwaarde3=rec.ins_kenmerkwaarde3;
|
||
|
||
END IF;
|
||
END LOOP;
|
||
|
||
END;
|
||
/
|
||
|
||
CREATE OR REPLACE PROCEDURE FZKH_UPDATE_SLEUTELS (p_import_key IN NUMBER)
|
||
AS
|
||
|
||
BEGIN
|
||
fac_update_ins (p_import_key);
|
||
END;
|
||
/
|
||
|
||
CREATE OR REPLACE PROCEDURE FZKH_IMPORT_MT_KENMERKEN (p_import_key IN NUMBER)
|
||
AS
|
||
|
||
BEGIN
|
||
NULL;
|
||
END;
|
||
/
|
||
|
||
CREATE OR REPLACE PROCEDURE FZKH_UPDATE_MT_KENMERKEN (p_import_key IN NUMBER)
|
||
AS
|
||
CURSOR sel
|
||
IS
|
||
SELECT fac_imp_csv_col01 ins_deel_omschrijving,
|
||
fac_imp_csv_col03 ins_kenmerk_label,
|
||
fac_imp_csv_col08 ins_kenmerk_waarde
|
||
FROM fac_imp_csv
|
||
WHERE fac_import_key=p_import_key
|
||
ORDER BY fac_imp_csv_key;
|
||
|
||
v_ins_deel_key NUMBER;
|
||
v_ins_kenmerk_key NUMBER;
|
||
|
||
v_errormsg VARCHAR2 (1000) := '-';
|
||
oracle_err_num NUMBER;
|
||
oracle_err_mes VARCHAR2 (200);
|
||
v_aanduiding VARCHAR2 (200);
|
||
BEGIN
|
||
FOR rec IN sel
|
||
LOOP
|
||
IF rec.ins_deel_omschrijving<>'eqmid'
|
||
THEN
|
||
BEGIN
|
||
v_aanduiding := 'Object '||rec.ins_deel_omschrijving||' is niet gevonden en wordt overgeslagen';
|
||
SELECT ins_deel_key
|
||
INTO v_ins_deel_key
|
||
FROM ins_deel
|
||
WHERE ins_deel_omschrijving=rec.ins_deel_omschrijving
|
||
AND ins_deel_verwijder IS NULL;
|
||
|
||
IF v_ins_deel_key >0
|
||
THEN
|
||
v_aanduiding:='kenmerk : ' || TO_CHAR (rec.ins_kenmerk_label)||' voor object '||rec.ins_deel_omschrijving||' is niet gevonden en wordt overgeslagen';
|
||
SELECT ins_kenmerk_key
|
||
INTO v_ins_kenmerk_key
|
||
FROM ins_kenmerk
|
||
WHERE UPPER(ins_kenmerk_omschrijving) = UPPER(rec.ins_kenmerk_label)
|
||
AND ins_kenmerk_niveau='D'
|
||
AND ins_kenmerk_verwijder IS NULL;
|
||
IF v_ins_kenmerk_key>0 AND rec.ins_kenmerk_waarde <>'NULL'
|
||
THEN
|
||
flx.setflex('INS',v_ins_kenmerk_key,v_ins_deel_key,rec.ins_kenmerk_waarde);
|
||
END IF;
|
||
|
||
END IF;
|
||
EXCEPTION
|
||
WHEN NO_DATA_FOUND
|
||
THEN
|
||
fac.imp_writelog (p_import_key,
|
||
'W',
|
||
v_aanduiding,
|
||
'');
|
||
END;
|
||
END IF;
|
||
|
||
END LOOP;
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
oracle_err_num := SQLCODE;
|
||
oracle_err_mes := SUBSTR (SQLERRM, 1, 150);
|
||
v_errormsg :=
|
||
v_errormsg || 'ORACLE (error ' || oracle_err_num || '/' || oracle_err_mes || ')';
|
||
fac.imp_writelog (p_import_key,
|
||
'E',
|
||
'Importproces MT Kenmerken afgebroken!',
|
||
v_errormsg);
|
||
|
||
END;
|
||
/
|
||
|
||
CREATE OR REPLACE PROCEDURE FZKH_IMPORT_RESERVERINGEN (p_import_key IN NUMBER)
|
||
AS
|
||
|
||
BEGIN
|
||
NULL;
|
||
END;
|
||
/
|
||
|
||
CREATE OR REPLACE PROCEDURE FZKH_UPDATE_RESERVERINGEN (p_import_key IN NUMBER)
|
||
AS
|
||
CURSOR sel
|
||
IS
|
||
SELECT fac_imp_csv_col01 ultimo_code,
|
||
fac_imp_csv_col03 res_ruimte_nr,
|
||
fac_imp_csv_col06 res_startdatum,
|
||
fac_imp_csv_col07 res_einddatum,
|
||
fac_imp_csv_col08 res_status,
|
||
fac_imp_csv_col09 res_aanvrager,
|
||
fac_imp_csv_col10 res_omschrijving
|
||
FROM fac_imp_csv
|
||
WHERE fac_import_key=p_import_key
|
||
ORDER BY fac_imp_csv_key;
|
||
v_res_startdatum DATE;
|
||
v_res_einddatum DATE;
|
||
v_prs_perslid_key NUMBER;
|
||
v_res_ruimte_key NUMBER;
|
||
|
||
v_count NUMBER;
|
||
v_errormsg VARCHAR2 (1000) := '-';
|
||
oracle_err_num NUMBER;
|
||
oracle_err_mes VARCHAR2 (200);
|
||
v_aanduiding VARCHAR2 (200);
|
||
BEGIN
|
||
|
||
FOR rec IN sel
|
||
LOOP
|
||
v_res_startdatum := fac.safe_to_date(rec.res_startdatum,'DD-MM-YYYY HH24:MI');
|
||
v_res_einddatum := fac.safe_to_date(rec.res_einddatum,'DD-MM-YYYY HH24:MI');
|
||
BEGIN
|
||
SELECT prs_perslid_key
|
||
INTO v_prs_perslid_key
|
||
FROM prs_v_perslid_fullnames p
|
||
WHERE UPPER(p.prs_perslid_naam_full) = UPPER(rec.res_aanvrager);
|
||
EXCEPTION
|
||
WHEN NO_DATA_FOUND THEN
|
||
v_prs_perslid_key:=3;
|
||
END;
|
||
|
||
v_aanduiding := 'Reservering '||rec.ultimo_code||' voor ruimte met ruimte Nr :'||rec.res_ruimte_nr||' is niet gevonden';
|
||
SELECT res_ruimte_key
|
||
INTO v_res_ruimte_key
|
||
from res_ruimte
|
||
WHERE res_ruimte_verwijder IS NULL
|
||
AND res_ruimte_nr LIKE rec.res_ruimte_nr||'%';
|
||
|
||
-- Insert in res_reservering
|
||
-- Insert ito res-sv_ruimte
|
||
-- voeg tracking toe.
|
||
-- fac.trackaction ('RESNEW', v_res_rsv_ruimte_key, NULL, SYSDATE, 'Gemigreerd vanuit Ultimo');
|
||
|
||
|
||
END LOOP;
|
||
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
oracle_err_num := SQLCODE;
|
||
oracle_err_mes := SUBSTR (SQLERRM, 1, 150);
|
||
v_errormsg :=
|
||
v_errormsg || 'ORACLE (error ' || oracle_err_num || '/' || oracle_err_mes || ')';
|
||
fac.imp_writelog (p_import_key,
|
||
'E',
|
||
'Importproces Ultimo reserveringen afgebroken!',
|
||
v_errormsg);
|
||
END;
|
||
/
|
||
|
||
CREATE OR REPLACE PROCEDURE FZKH_IMPORT_ULTIMO_MLD(p_import IN NUMBER)
|
||
AS
|
||
BEGIN
|
||
NULL;
|
||
END;
|
||
/
|
||
|
||
CREATE OR REPLACE PROCEDURE FZKH_UPDATE_ULTIMO_MLD(p_import_key IN NUMBER)
|
||
AS
|
||
|
||
CURSOR sel
|
||
IS
|
||
SELECT fac_imp_csv_col01 ultimo_nr,
|
||
fac_imp_csv_col02 mld_onderwerp,
|
||
fac_imp_csv_col03 prs_perslid_behandelaar,
|
||
fac_imp_csv_col05 mld_melding_datum,
|
||
fac_imp_csv_col05 prs_afdeling,
|
||
fac_imp_csv_col07 mld_note,
|
||
fac_imp_csv_col08 ins_deel_omschrijving,
|
||
fac_imp_csv_col08 ins_deel_serienummer,
|
||
fac_imp_csv_col11 ins_deel_leverancier,
|
||
fac_imp_csv_col12 mld_stdmelding,
|
||
fac_imp_csv_col13 mld_status,
|
||
fac_imp_csv_col14 mld_substatus,
|
||
fac_imp_csv_col15 mld_melding_gereeddatum,
|
||
fac_imp_csv_col17 prs_perslid_melder,
|
||
fac_imp_csv_col19 prs_kostenplaats_nr
|
||
FROM fac_imp_csv
|
||
WHERE fac_import_key=p_import_key
|
||
ORDER BY fac_imp_csv_key;
|
||
v_errormsg VARCHAR2 (1000) := '-';
|
||
oracle_err_num NUMBER;
|
||
oracle_err_mes VARCHAR2 (200);
|
||
v_aanduiding VARCHAR2 (200);
|
||
|
||
v_counter NUMBER;
|
||
v_count_deel_ok NUMBER;
|
||
v_count_deel NUMBER;
|
||
v_stdmelding_key NUMBER;
|
||
v_alg_onrgoed_niveau VARCHAR2(1);
|
||
v_prs_perslid_melder NUMBER;
|
||
v_mld_meldbron_key NUMBER;
|
||
v_kenmerk_key NUMBER;
|
||
v_ins_deel_key NUMBER;
|
||
v_prs_perslid_behandelaar NUMBER;
|
||
v_meldingsdatum DATE;
|
||
v_melding_gereeddatum DATE;
|
||
v_mld_key NUMBER;
|
||
v_status_key NUMBER;
|
||
BEGIN
|
||
v_stdmelding_key := 1; -- standaard worden alle migratie meldingen op de stdmelding overig gezet
|
||
v_mld_meldbron_key :=5;
|
||
v_counter:=0;
|
||
|
||
v_aanduiding :='Ophalen melding kenmerk key met code=ULTIMO_MLD_KEY is muslukt';
|
||
SELECT mld_kenmerk_key
|
||
INTO v_kenmerk_key
|
||
FROM mld_kenmerk
|
||
WHERE mld_kenmerk_code='ULTIMO_NR';
|
||
|
||
FOR rec IN sel
|
||
LOOP
|
||
IF rec.ultimo_nr<>'Code'
|
||
THEN
|
||
BEGIN
|
||
v_aanduiding:='Ophalen std melding gaat fout :'|| rec.mld_stdmelding;
|
||
SELECT ms.mld_stdmelding_key, ms.alg_onrgoed_niveau
|
||
INTO v_stdmelding_key, v_alg_onrgoed_niveau
|
||
FROM mld_stdmelding ms , ins_srtdiscipline vgt, MLD_DISCIPLINE vg
|
||
WHERE vgt.ins_srtdiscipline_omschrijving='Medische Techniek'
|
||
AND vg.ins_srtdiscipline_key = vgt.ins_srtdiscipline_key
|
||
AND vg.ins_discipline_key = ms.mld_ins_discipline_key
|
||
AND ms.mld_stdmelding_omschrijving=rec.mld_stdmelding
|
||
AND ms.MLD_STDMELDING_VERWIJDER IS NULL;
|
||
|
||
EXCEPTION
|
||
WHEN NO_DATA_FOUND
|
||
THEN
|
||
SELECT ms.mld_stdmelding_key, ms.alg_onrgoed_niveau
|
||
INTO v_stdmelding_key, v_alg_onrgoed_niveau
|
||
FROM mld_stdmelding ms , ins_srtdiscipline vgt, MLD_DISCIPLINE vg
|
||
WHERE vgt.ins_srtdiscipline_omschrijving='Medische Techniek'
|
||
AND vg.ins_srtdiscipline_key = vgt.ins_srtdiscipline_key
|
||
AND vg.ins_discipline_key = ms.mld_ins_discipline_key
|
||
AND UPPER(ms.mld_stdmelding_omschrijving)='MIGRATIE'
|
||
AND ms.MLD_STDMELDING_VERWIJDER IS NULL;
|
||
END;
|
||
|
||
v_aanduiding:= 'Ophalen van het asset '||rec.ins_deel_omschrijving || ' is mislukt.';
|
||
BEGIN
|
||
SELECT ins_deel_key
|
||
INTO v_ins_deel_key
|
||
FROM ins_deel
|
||
WHERE ins_deel_omschrijving=rec.ins_deel_omschrijving
|
||
AND ins_deel_verwijder IS NULL;
|
||
v_count_deel_ok:=v_count_deel_ok+1;
|
||
EXCEPTION
|
||
WHEN NO_DATA_FOUND
|
||
THEN
|
||
v_ins_deel_key:=NULL;
|
||
v_count_deel:=v_count_deel+1;
|
||
END;
|
||
|
||
-- Opahlen aanvrger
|
||
BEGIN
|
||
SELECT prs_perslid_key
|
||
INTO v_prs_perslid_melder
|
||
FROM prs_v_aanwezigperslid
|
||
WHERE prs_perslid_naam=rec.prs_perslid_melder;
|
||
|
||
|
||
EXCEPTION
|
||
WHEN NO_DATA_FOUND
|
||
THEN
|
||
v_prs_perslid_melder:=3;
|
||
END;
|
||
|
||
BEGIN
|
||
SELECT prs_perslid_key
|
||
INTO v_prs_perslid_behandelaar
|
||
FROM prs_v_aanwezigperslid
|
||
WHERE prs_perslid_naam=rec.prs_perslid_behandelaar;
|
||
|
||
|
||
EXCEPTION
|
||
WHEN NO_DATA_FOUND
|
||
THEN
|
||
v_prs_perslid_behandelaar:=NULL;
|
||
END;
|
||
|
||
-- Status
|
||
SELECT DECODE(rec.mld_status,'Gesloten',6,'Nieuw',2,'In behandeling',4,'Afgemeld',5,6)
|
||
INTO v_status_key
|
||
FROM DUAL; -- Historie is default
|
||
|
||
|
||
v_meldingsdatum:= fac.safe_to_date(rec.mld_melding_datum,'DD-MM-YYYY HH24:MI.SS');
|
||
IF rec.mld_melding_gereeddatum IS NOT NULL
|
||
THEN
|
||
v_melding_gereeddatum := fac.safe_to_date(rec.mld_melding_gereeddatum,'DD-MM-YYYY HH24:MI.SS');
|
||
ELSE
|
||
v_melding_gereeddatum:=NULL;
|
||
END IF;
|
||
|
||
IF v_stdmelding_key>-1
|
||
THEN
|
||
v_counter:=v_counter+1;
|
||
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_opmerking,
|
||
mld_melding_behandelaar_key,
|
||
mld_melding_behandelaar2_key,
|
||
mld_ins_discipline_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,
|
||
NULL,
|
||
NULL,
|
||
v_meldingsdatum,
|
||
rec.mld_onderwerp,
|
||
rec.mld_onderwerp,
|
||
rec.mld_note,
|
||
v_prs_perslid_behandelaar, -- mld_melding_behandelaar_key
|
||
TO_NUMBER(NULL), -- mld_melding_behandelaar2_key
|
||
TO_NUMBER(NULL),
|
||
v_stdmelding_key,
|
||
NULL,
|
||
v_melding_gereeddatum,
|
||
v_prs_perslid_melder,
|
||
v_prs_perslid_melder,
|
||
v_status_key,
|
||
3,
|
||
rec.ultimo_nr
|
||
)
|
||
RETURNING mld_melding_key
|
||
INTO v_mld_key;
|
||
|
||
|
||
|
||
flx.setflex('MLD',v_kenmerk_key,v_mld_key,rec.ultimo_nr);
|
||
IF v_status_key = 2
|
||
THEN
|
||
fac.trackaction ('MLDNEW', v_mld_key, NULL, v_meldingsdatum, 'Ultimo melding '||rec.ultimo_nr||' aangemaakt');
|
||
ELSIF v_status_key = 4
|
||
THEN
|
||
fac.trackaction ('MLDNEW', v_mld_key, NULL, v_meldingsdatum, 'Ultimo melding '||rec.ultimo_nr||' aangemaakt.');
|
||
fac.trackaction ('MLDACP', v_mld_key, NULL, v_meldingsdatum, 'Ultimo melding '||rec.ultimo_nr||' geaccepteerd.');
|
||
ELSIF v_status_key = 6
|
||
THEN
|
||
fac.trackaction ('MLDNEW', v_mld_key, NULL, v_meldingsdatum, 'Ultimo melding '||rec.ultimo_nr||' aangemaakt.');
|
||
fac.trackaction ('MLDACP', v_mld_key, NULL, v_meldingsdatum, 'Ultimo melding '||rec.ultimo_nr||' geaccepteerd.');
|
||
fac.trackaction ('MLDAFM', v_mld_key, NULL, v_melding_gereeddatum, 'Ultimo melding '||rec.ultimo_nr||' afgemeld');
|
||
ELSE
|
||
fac.trackaction ('MLDTRK', v_mld_key, NULL, NULL, 'Ultimo melding '||rec.ultimo_nr||' gemigreerd.');
|
||
END IF;
|
||
|
||
IF v_mld_key>1 AND LENGTH(rec.mld_note)>0
|
||
THEN
|
||
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_mld_key,
|
||
v_meldingsdatum,
|
||
SYSDATE,
|
||
3, -- Facilitor
|
||
'Migratie melding Ultimo melding: ' || rec.ultimo_nr||CHR(10)||'Aanvrager: '|| rec.prs_perslid_melder,
|
||
0);
|
||
END IF;
|
||
|
||
IF v_ins_deel_key > 0
|
||
THEN
|
||
INSERT INTO mld_melding_object(ins_deel_key,
|
||
mld_melding_key,
|
||
mld_melding_object_aanmaak)
|
||
VALUES(v_ins_deel_key,
|
||
v_mld_key,
|
||
v_meldingsdatum);
|
||
|
||
END IF;
|
||
|
||
|
||
|
||
|
||
END IF;
|
||
|
||
|
||
END IF;
|
||
|
||
-- haal het object op
|
||
-- haal de melder op
|
||
-- haal de evt hebandelar op
|
||
-- haal de stdmelding op,
|
||
-- haal de status op,
|
||
|
||
|
||
END LOOP;
|
||
|
||
fac.imp_writelog (p_import_key,
|
||
'I',
|
||
'Er zijn in totaal '||v_counter||' meldingen aangemaakt.',
|
||
'Ultimo meldingen aanmaak');
|
||
fac.imp_writelog (p_import_key,
|
||
'I',
|
||
'Daar zijn intotaal '||v_count_deel_ok||' objecten aangekoppeld.',
|
||
'Ultimo meldingen aanmaak');
|
||
fac.imp_writelog (p_import_key,
|
||
'I',
|
||
'In totaal zijn '||v_count_deel||' objecten niet gevonden.',
|
||
'Ultimo meldingen aanmaak');
|
||
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
oracle_err_num := SQLCODE;
|
||
oracle_err_mes := SUBSTR (SQLERRM, 1, 150);
|
||
v_errormsg :=
|
||
v_errormsg || 'ORACLE (error ' || oracle_err_num || '/' || oracle_err_mes || ')';
|
||
fac.imp_writelog (p_import_key,
|
||
'E',
|
||
'Importproces Ultimo meldingen afgebroken!'||v_aanduiding,
|
||
v_errormsg);
|
||
END;
|
||
/
|
||
|
||
|
||
|
||
CREATE OR REPLACE PROCEDURE FZKH_IMPORT_AOC_CODES(p_import IN NUMBER)
|
||
AS
|
||
BEGIN
|
||
NULL;
|
||
END;
|
||
/
|
||
-- AOC structuur "ID";"Descr";"ValidFromDate";"LastMutationDate";"MainGroupAocId";"GroupAocId";"Level"
|
||
|
||
CREATE OR REPLACE PROCEDURE FZKH_UPDATE_AOC_CODES(p_import_key IN NUMBER)
|
||
AS
|
||
CURSOR sel
|
||
IS
|
||
SELECT fac_imp_csv_col01 id,
|
||
fac_imp_csv_col02 Omschrijving,
|
||
fac_imp_csv_col03 ValidFrom,
|
||
fac_imp_csv_col04 MutationDate,
|
||
fac_imp_csv_col05 aoc_disciplne_code,
|
||
fac_imp_csv_col06 aoc_groep_code,
|
||
fac_imp_csv_col07 aoc_level,
|
||
fac_imp_csv_key csv_key
|
||
FROM fac_imp_csv
|
||
WHERE fac_import_key=p_import_key
|
||
AND fac_imp_csv_col01<>'ID'
|
||
ORDER by fac_imp_csv_key;
|
||
|
||
v_ins_discipline_key NUMBER;
|
||
v_srtgroep_key NUMBER;
|
||
v_srtdeel_key NUMBER;
|
||
v_groep_count NUMBER;
|
||
v_srtdeel_count NUMBER;
|
||
v_groep_totalcount NUMBER;
|
||
v_srtdeel_totalcount NUMBER;
|
||
v_csv_key NUMBER;
|
||
|
||
v_errormsg VARCHAR2 (1000) := '-';
|
||
oracle_err_num NUMBER;
|
||
oracle_err_mes VARCHAR2 (200);
|
||
v_aanduiding VARCHAR2 (200);
|
||
BEGIN
|
||
v_srtdeel_count:=0;
|
||
v_groep_count:=0;
|
||
|
||
v_aanduiding:='Ophalen discipline Medische Techniek is mislukt. Import wordt afgebroken';
|
||
SELECT ins_discipline_key
|
||
INTO v_ins_discipline_key
|
||
FROM ins_discipline
|
||
WHERE UPPER(ins_discipline_omschrijving)=UPPER('Medische Techniek')
|
||
AND ins_discipline_module='INS'
|
||
AND ins_discipline_verwijder IS NULL;
|
||
|
||
|
||
FOR rec in sel
|
||
LOOP
|
||
v_csv_key:=rec.csv_key;
|
||
|
||
IF rec.aoc_level='2'
|
||
THEN
|
||
BEGIN
|
||
SELECT ins_srtgroep_key
|
||
INTO v_srtgroep_key
|
||
from ins_srtgroep
|
||
WHERE UPPER(ins_srtgroep_omschrijving)=UPPER(SUBSTR(rec.aoc_groep_code||' '||rec.omschrijving,1,60))
|
||
AND ins_discipline_key=v_ins_discipline_key
|
||
AND ins_srtgroep_module='INS'
|
||
AND ins_srtgroep_verwijder IS NULL;
|
||
v_groep_totalcount:=v_groep_totalcount+1;
|
||
EXCEPTION
|
||
WHEN NO_DATA_FOUND THEN
|
||
|
||
INSERT INTO ins_srtgroep (ins_discipline_key,
|
||
ins_srtgroep_module,
|
||
ins_srtgroep_omschrijving
|
||
)
|
||
VALUES (v_ins_discipline_key,
|
||
'INS',
|
||
SUBSTR (TRIM (rec.aoc_groep_code||' '||rec.omschrijving), 1, 60)
|
||
)
|
||
RETURNING ins_srtgroep_key
|
||
INTO v_srtgroep_key;
|
||
v_groep_count:=v_groep_count+1;
|
||
END;
|
||
END IF;
|
||
IF rec.aoc_level=3
|
||
THEN
|
||
BEGIN
|
||
v_aanduiding:='Objectgroep niet gevonden :'||rec.aoc_groep_code;
|
||
SELECT ins_srtgroep_key
|
||
INTO v_srtgroep_key
|
||
FROM ins_srtgroep
|
||
WHERE SUBSTR(ins_srtgroep_omschrijving,1,5)=rec.aoc_groep_code
|
||
AND ins_srtgroep_verwijder IS NULL;
|
||
v_aanduiding:='Objectsoort niet gevonden :'||rec.aoc_groep_code;
|
||
EXCEPTION
|
||
WHEN NO_DATA_FOUND
|
||
THEN
|
||
v_srtgroep_key:=-1;
|
||
fac.imp_writelog (p_import_key,
|
||
'W',
|
||
'Objectgroep niet gevonden :'||rec.aoc_groep_code,'');
|
||
END;
|
||
|
||
IF v_srtgroep_key>0
|
||
THEN
|
||
BEGIN
|
||
SELECT ins_srtdeel_key
|
||
INTO v_srtdeel_key
|
||
FROM ins_srtdeel
|
||
WHERE ins_srtdeel_code=rec.Id
|
||
AND ins_srtgroep_key=v_srtgroep_key
|
||
AND ins_srtdeel_verwijder IS NULL;
|
||
v_srtdeel_totalcount:=v_srtdeel_totalcount+1;
|
||
EXCEPTION
|
||
WHEN NO_DATA_FOUND THEN
|
||
INSERT INTO ins_srtdeel (ins_srtgroep_key,
|
||
ins_srtdeel_module,
|
||
ins_srtdeel_code,
|
||
ins_srtdeel_omschrijving,
|
||
ins_srtdeel_binding)
|
||
VALUES (v_srtgroep_key,
|
||
'INS',
|
||
rec.id,
|
||
rec.omschrijving,
|
||
9); -- aan ruimte en organisatie
|
||
v_srtdeel_count:=v_srtdeel_count+1;
|
||
END;
|
||
ELSE
|
||
fac.imp_writelog (p_import_key,
|
||
'W',
|
||
'Objectsrtdeel '||rec.id||' '||rec.omschrijving||'niet aangemaakt om bovenliggende groep niet is gevonden','');
|
||
END IF;
|
||
END IF;
|
||
|
||
|
||
END LOOP;
|
||
fac.imp_writelog (p_import_key,
|
||
'S',
|
||
'Objectsoorten/aantal toegevoegd: ' || TO_CHAR (v_groep_count)||'/'||TO_CHAR (v_groep_totalcount),
|
||
'');
|
||
fac.imp_writelog (p_import_key,
|
||
'S',
|
||
'Objectsoorten/aantal toegevoegd: ' || TO_CHAR (v_srtdeel_count)||'/'||TO_CHAR (v_srtdeel_totalcount),
|
||
'');
|
||
COMMIT;
|
||
|
||
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
oracle_err_num := SQLCODE;
|
||
oracle_err_mes := SUBSTR (SQLERRM, 1, 200);
|
||
v_errormsg :=
|
||
v_errormsg || ' (error ' || oracle_err_num || '/' || oracle_err_mes || ') ('||v_csv_key||')';
|
||
fac.imp_writelog (p_import_key,
|
||
'E',
|
||
v_errormsg,
|
||
'Importproces AOC codering afgebroken!');
|
||
|
||
END;
|
||
/
|
||
|
||
CREATE OR REPLACE PROCEDURE FZKH_IMPORT_LANSWEEPER(p_import IN NUMBER)
|
||
AS
|
||
BEGIN
|
||
NULL;
|
||
END;
|
||
/
|
||
|
||
CREATE OR REPLACE PROCEDURE FZKH_UPDATE_LANSWEEPER(p_import IN NUMBER)
|
||
AS
|
||
BEGIN
|
||
NULL;
|
||
END;
|
||
/
|
||
|
||
CREATE OR REPLACE PROCEDURE FZKH_IMPORT_MT_ASSETS(p_import_key IN NUMBER)
|
||
AS
|
||
CURSOR sel
|
||
IS
|
||
SELECT fac_imp_csv_col01 ins_discipline,
|
||
fac_imp_csv_col04 ins_groep,
|
||
fac_imp_csv_col05 ins_srtdeel_code,
|
||
fac_imp_csv_col06 ins_srtdeel_omschrijving,
|
||
fac_imp_csv_col07 ins_deel_opmerking,
|
||
fac_imp_csv_col08 ins_deel_omschrijving,
|
||
fac_imp_csv_col25 ins_kenm_eigenaar,
|
||
fac_imp_csv_col14 ins_kenm_locatie,
|
||
fac_imp_csv_col17 ins_kenm_ruimtenr,
|
||
fac_imp_csv_col18 ins_kenm_ruimtenaam,
|
||
fac_imp_csv_col33 ins_kenm_model,
|
||
fac_imp_csv_col34 ins_kenm_type,
|
||
fac_imp_csv_col35 ins_kenm_serienr,
|
||
fac_imp_csv_col36 ins_kenm_bouwjaar,
|
||
fac_imp_csv_col38 ins_kenm_leverancier,
|
||
fac_imp_csv_col40 ins_kenm_service_leverancier,
|
||
fac_imp_csv_col42 ins_kenm_fabrikant,
|
||
fac_imp_csv_col43 ins_kenm_mdd_clas,
|
||
fac_imp_csv_col46 ins_kenm_garantie,
|
||
fac_imp_csv_col50 ins_kenm_status,
|
||
fac_imp_csv_col12 ins_kenm_aanschafprijs,
|
||
fac_imp_csv_col27 ins_kenm_instaldatum,
|
||
fac_imp_csv_col48 ins_onderhoud_datum
|
||
FROM fac_imp_csv
|
||
WHERE fac_import_key=p_import_key
|
||
ORDER BY fac_imp_csv_key;
|
||
|
||
|
||
v_count NUMBER;
|
||
v_locatie_code VARCHAR2(10);
|
||
v_gebouw_code VARCHAR2(10);
|
||
v_verdieping_nr VARCHAR2(10);
|
||
v_ruimte_nr VARCHAR2(25);
|
||
v_huidige_locatie VARCHAR2(100);
|
||
v_installdatum DATE;
|
||
BEGIN
|
||
|
||
fac_import_file2csv(p_import_key);
|
||
|
||
v_locatie_code:='FZKH';
|
||
v_gebouw_code:='FZKH';
|
||
v_verdieping_nr:='0';
|
||
v_ruimte_nr := '_MT_MIGRATIE';
|
||
|
||
DELETE FROM fac_imp_ins;
|
||
COMMIT;
|
||
|
||
FOR rec in sel
|
||
LOOP
|
||
IF UPPER(rec.ins_discipline) <>'VAKGROEP'
|
||
THEN
|
||
v_huidige_locatie:='';
|
||
IF rec.ins_kenm_locatie IS NOT NULL
|
||
THEN
|
||
v_huidige_locatie:=rec.ins_kenm_locatie;
|
||
ELSE
|
||
v_huidige_locatie:='';
|
||
END IF;
|
||
IF rec.ins_kenm_ruimtenr IS NOT NULL
|
||
THEN
|
||
v_huidige_locatie:=rec.ins_kenm_ruimtenr||'-'||rec.ins_kenm_ruimtenaam;
|
||
ELSE
|
||
v_huidige_locatie:='';
|
||
END IF;
|
||
|
||
IF LENGTH(rec.ins_kenm_instaldatum)>1
|
||
THEN
|
||
v_installdatum := fac.safe_to_date(rec.ins_kenm_instaldatum,'DD-MM-YYYY');
|
||
ELSE
|
||
v_installdatum:=TRUNC(SYSDATE);
|
||
END IF;
|
||
|
||
SELECT COUNT(*) INTO v_count
|
||
FROM ins_deel
|
||
WHERE ins_deel_omschrijving=rec.ins_deel_omschrijving
|
||
AND ins_deel_verwijder IS NULL;
|
||
IF v_count=0 THEN
|
||
|
||
INSERT INTO fac_imp_ins (ins_discipline_omschrijving,
|
||
ins_srtgroep_omschrijving,
|
||
ins_srtdeel_code,
|
||
ins_srtdeel_omschrijving,
|
||
ins_deel_omschrijving,
|
||
ins_deel_opmerking,
|
||
ins_deel_aanmaak,
|
||
alg_locatie_code,
|
||
alg_gebouw_code,
|
||
alg_verdieping_volgnr,
|
||
alg_ruimte_nr,
|
||
ins_deel_aantal,
|
||
ins_kenmerkwaarde1,
|
||
ins_kenmerkwaarde2,
|
||
ins_kenmerkwaarde3,
|
||
ins_kenmerkwaarde4,
|
||
ins_kenmerkwaarde5,
|
||
ins_kenmerkwaarde6,
|
||
ins_kenmerkwaarde7,
|
||
ins_kenmerkwaarde8,
|
||
ins_kenmerkwaarde9,
|
||
ins_kenmerkwaarde10,
|
||
ins_kenmerkwaarde11,
|
||
ins_kenmerkwaarde12,
|
||
ins_kenmerkwaarde13,
|
||
ins_kenmerkwaarde14,
|
||
ins_kenmerkwaarde15)
|
||
VALUES (rec.ins_discipline,
|
||
rec.ins_groep,
|
||
SUBSTR(rec.ins_srtdeel_code,1,8),
|
||
rec.ins_srtdeel_omschrijving,
|
||
rec.ins_deel_omschrijving,
|
||
rec.ins_deel_opmerking,
|
||
v_installdatum,
|
||
v_locatie_code,
|
||
v_gebouw_code,
|
||
v_verdieping_nr,
|
||
v_ruimte_nr,
|
||
1,
|
||
'Eigenaar|0='||rec.ins_kenm_eigenaar,
|
||
'Locatie|0='||v_huidige_locatie,
|
||
'Model|0='||rec.ins_kenm_model,
|
||
'TypeNr|0='||rec.ins_kenm_type,
|
||
'Serienummer|0='||rec.ins_kenm_serienr,
|
||
'Bouwjaar|0='||rec.ins_kenm_bouwjaar,
|
||
'Leverancier|0='||rec.ins_kenm_leverancier,
|
||
'ServiceLeverancier|0='||rec.ins_kenm_service_leverancier,
|
||
'Fabrikant|0='||rec.ins_kenm_fabrikant,
|
||
'MDD-Classificatie|0='||TRIM(rec.ins_kenm_mdd_clas),
|
||
'Einde Garantie|0='||rec.ins_kenm_garantie,
|
||
'Status|0='||rec.ins_kenm_status,
|
||
'Aanschafprijs|0='||TRIM(rec.ins_kenm_aanschafprijs),
|
||
'Installatie datum|0='||rec.ins_kenm_instaldatum,
|
||
'Onderhouddatum|0='||rec.ins_onderhoud_datum
|
||
);
|
||
ELSE
|
||
fac.imp_writelog (p_import_key,
|
||
'W',
|
||
'Object : '||rec.ins_deel_omschrijving || ' is al bekend en wordt dus overgeslagen','');
|
||
END IF;
|
||
END IF;
|
||
END LOOP;
|
||
|
||
|
||
END;
|
||
/
|
||
|
||
CREATE OR REPLACE PROCEDURE FZKH_UPDATE_MT_ASSETS(p_import_key IN NUMBER)
|
||
AS
|
||
|
||
CURSOR sel
|
||
IS
|
||
SELECT fac_imp_csv_col08 ins_deel_omschrijving,
|
||
fac_imp_csv_col24 prs_afdeling_code
|
||
FROM fac_imp_csv
|
||
WHERE fac_import_key=p_import_key
|
||
ORDER BY fac_imp_csv_key;
|
||
|
||
|
||
CURSOR sel_controle
|
||
IS
|
||
SELECT fac_imp_csv_col08 ins_deel_omschrijving,
|
||
fac_imp_csv_col48 ctr_onderhoud_datum
|
||
FROM fac_imp_csv
|
||
WHERE fac_import_key=p_import_key
|
||
AND fac_imp_csv_col45='ONWAAR'
|
||
AND fac_imp_csv_col48 IS NOT NULL
|
||
AND fac_imp_csv_col50='Actief'
|
||
ORDER BY fac_imp_csv_key;
|
||
|
||
CURSOR sel_controle_skip(p_ins_srtdeel_key IN NUMBER, p_ins_srtcontrole_key IN NUMBER)
|
||
IS
|
||
SELECT ins_srtcontrole_key
|
||
from ins_srtcontrole isc
|
||
WHERE isc.ins_srtinstallatie_key=p_ins_srtdeel_key
|
||
AND isc.ins_srtcontrole_key <> p_ins_srtcontrole_key;
|
||
|
||
v_errormsg VARCHAR2 (1000) := '-';
|
||
oracle_err_num NUMBER;
|
||
oracle_err_mes VARCHAR2 (200);
|
||
v_aanduiding VARCHAR2 (200);
|
||
|
||
v_ins_deel_key NUMBER;
|
||
v_prs_afdeling_key NUMBER;
|
||
v_ins_srtdeel_key NUMBER;
|
||
v_srtcontrole_key NUMBER;
|
||
v_count NUMBER;
|
||
v_counter NUMBER;
|
||
v_ins_deelsrtcontrole_key NUMBER;
|
||
|
||
v_maand VARChar2(15);
|
||
|
||
BEGIN
|
||
fac_update_ins(p_import_key);
|
||
|
||
|
||
v_counter:=0;
|
||
-- Gaan we nu de objecten aan de juiste afdeling koppelen
|
||
FOR rec IN sel
|
||
LOOP
|
||
BEGIN
|
||
SELECT ins_deel_key
|
||
INTO v_ins_deel_key
|
||
FROM ins_deel
|
||
WHERE ins_deel_omschrijving=rec.ins_deel_omschrijving
|
||
AND ins_deel_verwijder IS NULL;
|
||
EXCEPTION
|
||
WHEN NO_DATA_FOUND THEN
|
||
v_ins_deel_key:=-1;
|
||
fac.imp_writelog (
|
||
p_import_key,
|
||
'W',
|
||
'Objecten niet gevonden :'||rec.ins_deel_omschrijving,'');
|
||
END;
|
||
|
||
SELECT COUNT(*)
|
||
INTO v_count
|
||
FROM prs_afdeling a, prs_kostenplaats k
|
||
WHERE k.prs_kostenplaats_nr = rec.prs_afdeling_code
|
||
and a.prs_kostenplaats_key = k.prs_kostenplaats_key
|
||
AND prs_afdeling_verwijder IS NULL;
|
||
|
||
IF v_count=1
|
||
THEN
|
||
SELECT prs_afdeling_key
|
||
INTO v_prs_afdeling_key
|
||
FROM prs_afdeling a,
|
||
prs_kostenplaats k
|
||
WHERE k.prs_kostenplaats_nr = rec.prs_afdeling_code
|
||
AND a.prs_kostenplaats_key = k.prs_kostenplaats_key
|
||
AND prs_afdeling_verwijder IS NULL;
|
||
ELSIF v_count>1
|
||
THEN
|
||
SELECT MIN(prs_afdeling_key)
|
||
INTO v_prs_afdeling_key
|
||
FROM prs_afdeling a,
|
||
prs_kostenplaats k
|
||
WHERE k.prs_kostenplaats_nr = rec.prs_afdeling_code
|
||
AND a.prs_kostenplaats_key = k.prs_kostenplaats_key
|
||
AND UPPER(a.prs_afdeling_omschrijving) NOT LIKE 'T-%' -- Pakken we de teamleiders afdeling
|
||
AND UPPER(a.prs_afdeling_omschrijving) NOT LIKE 'STAGIARE%' -- Pakken we de teamleiders afdeling
|
||
AND prs_afdeling_verwijder IS NULL;
|
||
ELSE
|
||
|
||
v_prs_afdeling_key:=-1;
|
||
fac.imp_writelog (p_import_key,
|
||
'W',
|
||
'Afdeling niet gevonden :'||rec.prs_afdeling_code||' voor object :'||rec.ins_deel_omschrijving,'');
|
||
END IF;
|
||
|
||
|
||
IF v_ins_deel_key>0 AND v_prs_afdeling_key>0
|
||
THEN
|
||
UPDATE ins_deel
|
||
SET ins_alg_ruimte_key=v_prs_afdeling_key,
|
||
ins_alg_ruimte_type='A'
|
||
WHERE ins_deel_key=v_ins_deel_key;
|
||
END IF;
|
||
|
||
|
||
END LOOP;
|
||
|
||
-- gaan we nu de periodiek taken maken en aan de xcp records met de juiste taak start datum
|
||
v_counter:=0;
|
||
FOR c IN sel_controle
|
||
LOOP
|
||
v_counter:=v_counter+1;
|
||
-- Welk maand met het onderhoud plaats vinden
|
||
SELECT CASE TO_CHAR(TO_DATE(c.ctr_onderhoud_datum,'DD-MM-YYYY'),'MM')
|
||
WHEN '01' THEN 'Januari'
|
||
WHEN '02' THEN 'Februari'
|
||
WHEN '03' THEN 'Maart'
|
||
WHEN '04' THEN 'April'
|
||
WHEN '05' THEN 'Mei'
|
||
WHEN '06' THEN 'Juni'
|
||
WHEN '07' THEN 'Juli'
|
||
WHEN '08' THEN 'Augustus'
|
||
WHEN '09' THEN 'September'
|
||
WHEN '10' THEN 'Oktober'
|
||
WHEN '11' THEN 'November'
|
||
WHEN '12' THEN 'December'
|
||
ELSE 'ONBEKEND'
|
||
END
|
||
INTO v_maand
|
||
FROM DUAL;
|
||
|
||
BEGIN
|
||
v_aanduiding := 'Ophalen van srtcontrole voor object '|| c.ins_deel_omschrijving||' in '||v_maand||' gaat fout. - '||v_counter;
|
||
select MIN(isc.ins_srtcontrole_key),
|
||
i.ins_deel_key,
|
||
i.ins_srtdeel_key
|
||
INTO v_srtcontrole_key,
|
||
v_ins_deel_key,
|
||
v_ins_srtdeel_key
|
||
from ins_srtcontrole isc,
|
||
ins_deel i,
|
||
ins_srtdeel isd,
|
||
ins_srtgroep isg,
|
||
ins_discipline id
|
||
WHERE i.ins_deel_omschrijving=c.ins_deel_omschrijving
|
||
AND isd.ins_srtdeel_key=i.INS_SRTDEEL_KEY
|
||
AND isg.ins_srtgroep_key = isd.ins_srtgroep_key
|
||
AND id.ins_discipline_key=isg.ins_discipline_key
|
||
AND UPPER(id.ins_discipline_omschrijving)=UPPER('Medische Techniek')
|
||
AND isc.ins_srtinstallatie_key=i.ins_srtdeel_key
|
||
AND UPPER(isc.ins_srtcontrole_omschrijving) like UPPER('Onderhoud %'||v_maand||'%')
|
||
GROUP BY i.ins_deel_key,i.ins_srtdeel_key;
|
||
|
||
EXCEPTION
|
||
WHEN NO_DATA_FOUND
|
||
THEN
|
||
v_srtcontrole_key:=-1;
|
||
fac.imp_writelog (p_import_key,
|
||
'W',
|
||
v_aanduiding,
|
||
'Taak niet toegevoegd');
|
||
END;-- v_aanduiding:='Uitzonderingstaak niet gevonden';
|
||
-- v_count:=0;
|
||
-- SELECT count(*)
|
||
-- INTO v_count
|
||
-- from ins_srtcontroledl_xcp isx
|
||
-- WHERE isx.ins_srtcontrole_key=v_srtcontrole_key
|
||
-- AND ins_deel_key=v_ins_deel_key;
|
||
|
||
-- IF v_count=0
|
||
-- THEN
|
||
-- INSERT INTO ins_srtcontroledl_xcp (ins_deel_key,
|
||
-- ins_srtcontrole_key,
|
||
-- ins_srtcontroledl_xcp_startdat)
|
||
-- VALUES (v_ins_deel_key,
|
||
-- v_srtcontrole_key,
|
||
-- fac.safe_to_date(c.ctr_onderhoud_datum,'DD-MM-YYYY'));
|
||
-- END IF;
|
||
|
||
|
||
-- Gaan we nu de srtcontrole die niet gelden voor dit asset een xcp record aanmaken met einddatum
|
||
FOR c2 IN sel_controle_skip(v_ins_srtdeel_key, v_srtcontrole_key)
|
||
LOOP
|
||
SELECT count(*)
|
||
INTO v_count
|
||
from ins_srtcontroledl_xcp isx
|
||
WHERE isx.ins_srtcontrole_key=c2.ins_srtcontrole_key
|
||
AND ins_deel_key=v_ins_deel_key;
|
||
|
||
IF v_count=0
|
||
THEN
|
||
INSERT INTO ins_srtcontroledl_xcp (ins_deel_key,
|
||
ins_srtcontrole_key,
|
||
ins_srtcontroledl_xcp_eind)
|
||
VALUES (v_ins_deel_key,
|
||
c2.ins_srtcontrole_key,
|
||
fac.safe_to_date('31-12-2024','DD-MM-YYYY'));
|
||
END IF;
|
||
END LOOP;
|
||
|
||
|
||
|
||
-- gaan we hem ook gelijk inplannen
|
||
IF v_ins_deel_key>0 AND v_srtcontrole_key>0
|
||
THEN
|
||
|
||
SELECT COUNT(*)
|
||
INTO v_count
|
||
FROM ins_deelsrtcontrole
|
||
WHERE ins_deel_key=v_ins_deel_key
|
||
AND ins_srtcontrole_key = v_srtcontrole_key
|
||
AND ins_deelsrtcontrole_plandatum = fac.safe_to_date(c.ctr_onderhoud_datum,'DD-MM-YYYY')
|
||
AND ins_scenario_key=1;
|
||
|
||
IF v_count=0
|
||
THEN
|
||
INSERT INTO ins_deelsrtcontrole( ins_deel_key,
|
||
ins_srtcontrole_key,
|
||
ins_deelsrtcontrole_plandatum,
|
||
ins_deelsrtcontrole_status,
|
||
ins_scenario_key,
|
||
prs_perslid_key)
|
||
VALUES(v_ins_deel_key,
|
||
v_srtcontrole_key,
|
||
fac.safe_to_date(c.ctr_onderhoud_datum,'DD-MM-YYYY'),
|
||
0, --status ingepland
|
||
1, -- sceario
|
||
3); -- Facilitor
|
||
END IF;
|
||
END IF;
|
||
|
||
|
||
|
||
|
||
END LOOP;
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
oracle_err_num := SQLCODE;
|
||
oracle_err_mes := SUBSTR (SQLERRM, 1, 150);
|
||
v_errormsg :=
|
||
v_errormsg || 'ORACLE (error ' || oracle_err_num || '/' || oracle_err_mes || ')';
|
||
fac.imp_writelog (p_import_key,
|
||
'E',
|
||
'Importproces MT assets afgebroken! ('||v_counter||')',
|
||
v_errormsg);
|
||
|
||
|
||
END;
|
||
/
|
||
|
||
------ payload end ------
|
||
|
||
SET DEFINE OFF
|
||
BEGIN adm.systrackscriptId ('$Id$', 0); END;
|
||
/
|
||
|
||
COMMIT;
|
||
SET ECHO OFF
|
||
SPOOL OFF
|
||
SET DEFINE ON
|
||
PROMPT Logfile of this upgrade is: &fcltlogfile
|