800 lines
31 KiB
SQL
800 lines
31 KiB
SQL
--
|
|
-- $Id$
|
|
--
|
|
-- Script containing customer specific sql statements for the FACILITOR database
|
|
|
|
DEFINE thisfile = 'kmmo.sql'
|
|
DEFINE dbuser = 'KMMO'
|
|
|
|
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 ------
|
|
|
|
-- Dagelijkse taak
|
|
CREATE OR REPLACE PROCEDURE kmmo_daily
|
|
AS
|
|
BEGIN
|
|
|
|
IF user = 'KMMO_TEST'
|
|
THEN
|
|
-- pas de kleuren voor de testomgeving aan (blauw naar rood)
|
|
UPDATE fac_setting
|
|
SET fac_setting_pvalue = REPLACE(fac_setting_pvalue, '#0085c4', '#e20035')
|
|
WHERE fac_setting_name = 'csstemplate';
|
|
|
|
UPDATE fac_setting
|
|
SET fac_setting_pvalue = REPLACE(fac_setting_pvalue, '#0085c4', '#e20035')
|
|
WHERE fac_setting_name = 'csscust';
|
|
|
|
UPDATE fac_setting
|
|
SET fac_setting_pvalue = REPLACE(fac_setting_pvalue, 'banner.png', 'banner_rood.png')
|
|
WHERE fac_setting_name = 'csstemplate';
|
|
|
|
|
|
END IF;
|
|
|
|
END;
|
|
/
|
|
|
|
-- view om QR codes voor een deel te genereren.
|
|
CREATE OR REPLACE VIEW kmmo_v_rap_qr_deel
|
|
AS
|
|
SELECT fac_bookmark_naam,
|
|
fac_bookmark_id,
|
|
ins_discipline_omschrijving,
|
|
ins_srtgroep_omschrijving,
|
|
ins_srtdeel_omschrijving,
|
|
ins_deel_omschrijving,
|
|
alg_locatie_key,
|
|
alg_gebouw_omschrijving,
|
|
ins_deel_aanmaak,
|
|
ins_deel_key
|
|
FROM fac_bookmark b, ins_v_deel_gegevens d
|
|
WHERE fac_bookmark_expire IS NULL
|
|
AND fac_bookmark_id = 'eYD435Vl666lZdkU';
|
|
|
|
-- view om QR codes voor een ruimte te genereren.
|
|
-- Ieder srtruimte krijgt een eigen bookmark
|
|
-- Om een link tussen bookmark en srtuimte te maken
|
|
-- wordt de omschrijving van de bookmark als volgt gevuld:
|
|
-- QR bij verkeersruimte key:30
|
|
-- De key is dan de key van de srtruimte.
|
|
CREATE OR REPLACE VIEW kmmo_v_rap_qr_ruimte
|
|
AS
|
|
SELECT b.fac_bookmark_naam,
|
|
b.fac_bookmark_id,
|
|
sr.alg_srtruimte_omschrijving,
|
|
rg.alg_ruimte_omschrijving,
|
|
rg.alg_ruimte_nr,
|
|
rg.alg_ruimte_key,
|
|
alg_locatie_omschrijving,
|
|
alg_gebouw_omschrijving,
|
|
alg_verdieping_omschrijving
|
|
FROM fac_bookmark b, alg_srtruimte sr, alg_v_ruimte_gegevens rg
|
|
WHERE b.fac_bookmark_expire IS NULL
|
|
AND COALESCE(FAC.safe_to_number(TRIM(SUBSTR(b.fac_bookmark_naam, INSTR(b.fac_bookmark_naam, ':')+1))),-1) = sr.alg_srtruimte_key
|
|
AND sr.alg_srtruimte_key = rg.alg_srtruimte_key;
|
|
|
|
CREATE OR REPLACE FORCE VIEW kmmo_v_thema_bouwdeel
|
|
(
|
|
ALG_RUIMTE_KEY,
|
|
WAARDE
|
|
)
|
|
AS
|
|
SELECT alg_onrgoed_key, SUBSTR (alg_onrgoedkenmerk_waarde, 1, 1) waarde
|
|
FROM alg_onrgoedkenmerk
|
|
WHERE alg_kenmerk_key = 1003 AND alg_onrgoedkenmerk_verwijder IS NULL;
|
|
|
|
CREATE OR REPLACE FORCE VIEW kmmo_v_thema_openstelling
|
|
(
|
|
ALG_RUIMTE_KEY,
|
|
WAARDE
|
|
)
|
|
AS
|
|
SELECT alg_onrgoed_key, alg_onrgoedkenmerk_waarde waarde
|
|
FROM alg_onrgoedkenmerk
|
|
WHERE alg_kenmerk_key = 1004 AND alg_onrgoedkenmerk_verwijder IS NULL;
|
|
|
|
|
|
-- View om de resultaten van de inspecties te tonen
|
|
CREATE OR REPLACE VIEW kmmo_v_rap_keuring_resultaat
|
|
AS
|
|
SELECT dsc.ins_deelsrtcontrole_datum,
|
|
dsc.ins_deelsrtcontrole_datum_org,
|
|
dsc.ins_deelsrtcontrole_status,
|
|
pf.prs_perslid_naam_full,
|
|
sc.ins_srtcontrole_omschrijving,
|
|
dg.ins_discipline_omschrijving,
|
|
dg.ins_srtgroep_omschrijving,
|
|
dg.ins_srtdeel_omschrijving,
|
|
dg.ins_deel_omschrijving,
|
|
dg.alg_gebouw_omschrijving,
|
|
dg.alg_verdieping_code,
|
|
dg.alg_ruimte_nr,
|
|
cm.ins_controlemode_oms,
|
|
(SELECT LISTAGG (
|
|
COALESCE (k.ins_kenmerk_omschrijving,
|
|
sk.ins_srtkenmerk_omschrijving),
|
|
CHR (13))
|
|
WITHIN GROUP (ORDER BY
|
|
COALESCE (k.ins_kenmerk_omschrijving,
|
|
sk.ins_srtkenmerk_omschrijving)) AS bevindingen
|
|
FROM ins_kmdeelsrtcontr kdsc, ins_kenmerk k, ins_srtkenmerk sk
|
|
WHERE kdsc.ins_kenmerk_key = k.ins_kenmerk_key
|
|
AND k.ins_srtkenmerk_key = sk.ins_srtkenmerk_key
|
|
AND kdsc.ins_deelsrtcontrole_key = dsc.ins_deelsrtcontrole_key) bevindingen
|
|
FROM ins_deelsrtcontrole dsc,
|
|
ins_srtcontrole sc,
|
|
ins_v_deel_gegevens dg,
|
|
ins_controlemode cm,
|
|
prs_v_perslid_fullnames pf
|
|
WHERE dsc.ins_srtcontrole_key = sc.ins_srtcontrole_key
|
|
AND dsc.ins_deel_key = dg.ins_deel_key
|
|
AND dsc.ins_controlemode_key = cm.ins_controlemode_key
|
|
AND dsc.prs_perslid_key = pf.prs_perslid_key;
|
|
|
|
-- Importfunctie om Asset en MJOB informatie te importeren.
|
|
CREATE OR REPLACE PROCEDURE kmmo_import_assets (p_import_key IN NUMBER)
|
|
AS
|
|
c_fielddelimitor VARCHAR2 (1) := ';';
|
|
v_newline VARCHAR2 (4000); -- Input line
|
|
v_errormsg VARCHAR2 (1000);
|
|
v_errorhint VARCHAR2 (1000);
|
|
oracle_err_num NUMBER;
|
|
oracle_err_mes VARCHAR2 (200);
|
|
header_is_valid NUMBER;
|
|
v_count NUMBER;
|
|
v_ongeldig NUMBER (1);
|
|
v_mode NUMBER (1);
|
|
v_aanduiding VARCHAR2 (200);
|
|
v_all_null BOOLEAN;
|
|
v_count_error NUMBER (10);
|
|
v_count_tot NUMBER (10);
|
|
v_count_import NUMBER (10);
|
|
|
|
-- De importvelden:
|
|
v_alg_ruimte_nr VARCHAR2(100);
|
|
v_ins_deel_aanmaak_txt VARCHAR2(100);
|
|
v_ins_deel_aantal_txt VARCHAR2(100);
|
|
v_ins_deel_eenheid VARCHAR2(100);
|
|
v_ins_deel_omschrijving VARCHAR2(100);
|
|
v_ins_deel_opmerking VARCHAR2(1000);
|
|
v_ins_srtcontrole_periode_txt VARCHAR2(100);
|
|
v_ins_srtcontrole_prijs_txt VARCHAR2(100);
|
|
v_ins_srtdeel_code VARCHAR2(100);
|
|
v_ins_srtdeel_omschrijving VARCHAR2(100);
|
|
v_ins_deel_percentage NUMBER;
|
|
v_ins_srtcontrole_periode NUMBER;
|
|
v_kenmerk1 VARCHAR2(1000);
|
|
v_kenmerk2 VARCHAR2(1000);
|
|
v_kenmerk3 VARCHAR2(1000);
|
|
v_kenmerk4 VARCHAR2(1000);
|
|
v_kenmerk5 VARCHAR2(1000);
|
|
v_kenmerk7 VARCHAR2(1000);
|
|
v_kenmerk9 VARCHAR2(1000);
|
|
v_dumm NUMBER (10,2);
|
|
v_ins_deel_aanmaak DATE;
|
|
v_ins_deel_startjaar DATE;
|
|
v_ins_deel_aantal NUMBER;
|
|
v_ins_srtcontrole_prijs NUMBER(10,2);
|
|
v_alg_locatie_code VARCHAR2(20);
|
|
v_alg_gebouw_code VARCHAR2(20);
|
|
v_alg_verdieping_volgnr NUMBER;
|
|
v_srtk_code_rvb_key NUMBER;
|
|
v_srtk_opm_key NUMBER;
|
|
v_srtk_merk_key NUMBER;
|
|
v_discipline_key NUMBER;
|
|
v_srtgroep_key NUMBER;
|
|
v_ins_discipline_omschrijving VARCHAR2(100);
|
|
v_ins_srtgroep_omschrijving VARCHAR2(100);
|
|
|
|
CURSOR c
|
|
IS
|
|
SELECT *
|
|
FROM fac_imp_file
|
|
WHERE fac_import_key = p_import_key
|
|
ORDER BY fac_imp_file_index;
|
|
|
|
CURSOR c_dis IS
|
|
SELECT '5 - installaties werktuigbouwkunde' disc FROM DUAL
|
|
UNION
|
|
SELECT '2 - ruwbouw' FROM DUAL
|
|
UNION
|
|
SELECT '7 - vaste voorzieningen' FROM DUAL
|
|
UNION
|
|
SELECT '6 - installaties elektrotechniek' FROM DUAL
|
|
UNION
|
|
SELECT '4 - afwerkingen' FROM DUAL
|
|
UNION
|
|
SELECT '3 - afbouw' FROM DUAL
|
|
UNION
|
|
SELECT '9 - terrein' FROM DUAL
|
|
UNION
|
|
SELECT '8 - losse inventaris' FROM DUAL;
|
|
|
|
CURSOR c_grp IS
|
|
SELECT '21 - buitenwanden' groep FROM DUAL
|
|
UNION
|
|
SELECT '22 - binnenwanden' FROM DUAL
|
|
UNION
|
|
SELECT '24 - trappen en hellingen' FROM DUAL
|
|
UNION
|
|
SELECT '31 - buitenwandopeningen' FROM DUAL
|
|
UNION
|
|
SELECT '32 - binnenwandopeningen' FROM DUAL
|
|
UNION
|
|
SELECT '33 - vloeropeningen' FROM DUAL
|
|
UNION
|
|
SELECT '34 - balustrades en leuningen' FROM DUAL
|
|
UNION
|
|
SELECT '37 - dakopeningen' FROM DUAL
|
|
UNION
|
|
SELECT '41 - buitenwandafwerkingen' FROM DUAL
|
|
UNION
|
|
SELECT '42 - binnenwandafwerkingen' FROM DUAL
|
|
UNION
|
|
SELECT '43 - vloerafwerkingen' FROM DUAL
|
|
UNION
|
|
SELECT '44 - trap- en hellingafwerkingen' FROM DUAL
|
|
UNION
|
|
SELECT '45 - plafondafwerkingen' FROM DUAL
|
|
UNION
|
|
SELECT '47 - dakafwerkingen' FROM DUAL
|
|
UNION
|
|
SELECT '51 - warmte-opwekking' FROM DUAL
|
|
UNION
|
|
SELECT '52 - afvoeren' FROM DUAL
|
|
UNION
|
|
SELECT '53 - water' FROM DUAL
|
|
UNION
|
|
SELECT '54 - gas' FROM DUAL
|
|
UNION
|
|
SELECT '55 - koude-opwekking' FROM DUAL
|
|
UNION
|
|
SELECT '56 - warmtedistributie' FROM DUAL
|
|
UNION
|
|
SELECT '57 - luchtbehandeling' FROM DUAL
|
|
UNION
|
|
SELECT '58 - regeling klimaat en sanitair' FROM DUAL
|
|
UNION
|
|
SELECT '61 - centrale elektrotechnische voorzieningen' FROM DUAL
|
|
UNION
|
|
SELECT '63 - verlichting' FROM DUAL
|
|
UNION
|
|
SELECT '64 - communicatie' FROM DUAL
|
|
UNION
|
|
SELECT '65 - beveiliging' FROM DUAL
|
|
UNION
|
|
SELECT '66 - transport' FROM DUAL
|
|
UNION
|
|
SELECT '73 - vaste keukenvoorzieningen' FROM DUAL
|
|
UNION
|
|
SELECT '74 - vaste sanitaire voorzieningen' FROM DUAL
|
|
UNION
|
|
SELECT '83 - losse keukeninventaris' FROM DUAL
|
|
UNION
|
|
SELECT '90 - terrein' FROM DUAL;
|
|
|
|
BEGIN
|
|
v_count_error := 0;
|
|
header_is_valid := 0;
|
|
v_count_tot := 0;
|
|
v_count_import := 0;
|
|
|
|
DELETE fac_imp_ins;
|
|
|
|
-- Zijn de kenmerksoorten er al?
|
|
BEGIN
|
|
SELECT ins_srtkenmerk_key
|
|
INTO v_srtk_code_rvb_key
|
|
FROM ins_srtkenmerk
|
|
WHERE ins_srtkenmerk_upper = 'CODE RVB';
|
|
|
|
EXCEPTION WHEN NO_DATA_FOUND
|
|
THEN
|
|
INSERT INTO ins_srtkenmerk (ins_srtkenmerk_kenmerktype,
|
|
ins_srtkenmerk_omschrijving,
|
|
ins_srtkenmerk_lengte)
|
|
VALUES ('C', 'Code RVB', 20) RETURNING ins_srtkenmerk_key INTO v_srtk_code_rvb_key;
|
|
END;
|
|
|
|
BEGIN
|
|
SELECT ins_srtkenmerk_key
|
|
INTO v_srtk_opm_key
|
|
FROM ins_srtkenmerk
|
|
WHERE ins_srtkenmerk_upper = 'OPMERKING';
|
|
|
|
EXCEPTION WHEN NO_DATA_FOUND
|
|
THEN
|
|
INSERT INTO ins_srtkenmerk (ins_srtkenmerk_kenmerktype,
|
|
ins_srtkenmerk_omschrijving,
|
|
ins_srtkenmerk_lengte)
|
|
VALUES ('C', 'Opmerking', 2000) RETURNING ins_srtkenmerk_key INTO v_srtk_opm_key;
|
|
END;
|
|
|
|
BEGIN
|
|
SELECT ins_srtkenmerk_key
|
|
INTO v_srtk_merk_key
|
|
FROM ins_srtkenmerk
|
|
WHERE ins_srtkenmerk_upper = 'MERK';
|
|
|
|
EXCEPTION WHEN NO_DATA_FOUND
|
|
THEN
|
|
INSERT INTO ins_srtkenmerk (ins_srtkenmerk_kenmerktype,
|
|
ins_srtkenmerk_omschrijving,
|
|
ins_srtkenmerk_lengte)
|
|
VALUES ('C', 'Merk', 49) RETURNING ins_srtkenmerk_key INTO v_srtk_merk_key;
|
|
END;
|
|
|
|
-- Controleer of de MJOB disciplines al bestaan
|
|
SELECT count(*)
|
|
INTO v_count
|
|
FROM ins_discipline
|
|
WHERE ins_discipline_omschrijving = '5 - installaties werktuigbouwkunde';
|
|
|
|
IF v_count = 0
|
|
THEN
|
|
|
|
FOR rec IN c_dis
|
|
LOOP
|
|
BEGIN
|
|
SELECT ins_discipline_key
|
|
INTO v_discipline_key
|
|
FROM ins_tab_discipline
|
|
WHERE UPPER (ins_discipline_omschrijving) = UPPER (rec.disc);
|
|
EXCEPTION
|
|
WHEN NO_DATA_FOUND
|
|
THEN
|
|
INSERT INTO ins_tab_discipline (ins_discipline_omschrijving,
|
|
ins_discipline_min_level)
|
|
VALUES (rec.disc, 1)
|
|
RETURNING ins_discipline_key
|
|
INTO v_discipline_key;
|
|
|
|
INSERT INTO ins_disc_params (ins_discipline_key,
|
|
ins_disc_params_autonum)
|
|
VALUES (v_discipline_key, 2);
|
|
|
|
INSERT INTO ins_kenmerk (ins_srtkenmerk_key, ins_srtinstallatie_key, ins_kenmerk_niveau, ins_kenmerk_bewerkniveau, ins_kenmerk_volgnummer)
|
|
VALUES (v_srtk_code_rvb_key, v_discipline_key, 'D', 'D', 110);
|
|
|
|
INSERT INTO ins_kenmerk (ins_srtkenmerk_key, ins_srtinstallatie_key, ins_kenmerk_niveau, ins_kenmerk_bewerkniveau, ins_kenmerk_volgnummer)
|
|
VALUES (v_srtk_opm_key, v_discipline_key, 'D', 'D', 120);
|
|
|
|
INSERT INTO ins_kenmerk (ins_srtkenmerk_key, ins_srtinstallatie_key, ins_kenmerk_niveau, ins_kenmerk_bewerkniveau, ins_kenmerk_volgnummer)
|
|
VALUES (v_srtk_merk_key, v_discipline_key, 'D', 'D', 130);
|
|
|
|
END;
|
|
END LOOP;
|
|
|
|
FOR rec_grp IN c_grp
|
|
LOOP
|
|
SELECT ins_discipline_key
|
|
INTO v_discipline_key
|
|
FROM ins_tab_discipline
|
|
WHERE SUBSTR (ins_discipline_omschrijving, 1, 3) =
|
|
SUBSTR (rec_grp.groep, 1, 1) || ' -';
|
|
|
|
BEGIN
|
|
SELECT ins_srtgroep_key
|
|
INTO v_srtgroep_key
|
|
FROM ins_srtgroep
|
|
WHERE UPPER (ins_srtgroep_omschrijving) = UPPER (rec_grp.groep)
|
|
AND ins_discipline_key = v_discipline_key;
|
|
EXCEPTION
|
|
WHEN NO_DATA_FOUND
|
|
THEN
|
|
INSERT INTO ins_srtgroep (ins_discipline_key,
|
|
ins_srtgroep_omschrijving)
|
|
VALUES (v_discipline_key, rec_grp.groep)
|
|
RETURNING ins_discipline_key
|
|
INTO v_discipline_key;
|
|
END;
|
|
END LOOP;
|
|
END IF;
|
|
|
|
FOR rec IN c
|
|
LOOP
|
|
BEGIN
|
|
v_errormsg := 'Fout FETCH te importeren rij';
|
|
|
|
v_newline := rec.fac_imp_file_line;
|
|
v_errormsg := 'Fout opvragen te importeren rij';
|
|
v_aanduiding := '';
|
|
|
|
-- Lees alle veldwaarden
|
|
fac.imp_getfield_nr (v_newline, c_fielddelimitor, 12, v_alg_ruimte_nr);
|
|
fac.imp_getfield_nr (v_newline, c_fielddelimitor, 13, v_ins_deel_aanmaak_txt);
|
|
fac.imp_getfield_nr (v_newline, c_fielddelimitor, 14, v_ins_deel_aantal_txt);
|
|
fac.imp_getfield_nr (v_newline, c_fielddelimitor, 15, v_ins_deel_eenheid);
|
|
fac.imp_getfield_nr (v_newline, c_fielddelimitor, 3, v_ins_deel_omschrijving);
|
|
fac.imp_getfield_nr (v_newline, c_fielddelimitor, 7, v_ins_deel_opmerking);
|
|
fac.imp_getfield_nr (v_newline, c_fielddelimitor, 29, v_ins_srtcontrole_periode_txt);
|
|
fac.imp_getfield_nr (v_newline, c_fielddelimitor, 24, v_ins_srtcontrole_prijs_txt);
|
|
fac.imp_getfield_nr (v_newline, c_fielddelimitor, 1, v_ins_srtdeel_code);
|
|
fac.imp_getfield_nr (v_newline, c_fielddelimitor, 6, v_ins_srtdeel_omschrijving);
|
|
fac.imp_getfield_nr (v_newline, c_fielddelimitor, 4, v_kenmerk1); -- code RVB
|
|
fac.imp_getfield_nr (v_newline, c_fielddelimitor, 8, v_kenmerk2); -- opmerking
|
|
fac.imp_getfield_nr (v_newline, c_fielddelimitor, 9, v_kenmerk3); -- taak
|
|
fac.imp_getfield_nr (v_newline, c_fielddelimitor, 16, v_kenmerk5); -- fabrikant / merk
|
|
fac.imp_getfield_nr (v_newline, c_fielddelimitor, 28, v_kenmerk7); -- percentage
|
|
fac.imp_getfield_nr (v_newline, c_fielddelimitor, 30, v_kenmerk9); -- startjaar
|
|
|
|
v_aanduiding := v_ins_deel_omschrijving || '|' || v_kenmerk4;
|
|
|
|
v_count_tot := v_count_tot + 1;
|
|
|
|
v_errormsg := 'Fout bij toevoegen te impoteren v_ins_discipline_omschrijving: ' || v_ins_srtdeel_code;
|
|
SELECT d.ins_discipline_omschrijving
|
|
INTO v_ins_discipline_omschrijving
|
|
FROM ins_discipline d
|
|
WHERE SUBSTR (d.ins_discipline_omschrijving, 1, 1) = SUBSTR (v_ins_srtdeel_code, 1, 1);
|
|
|
|
v_errormsg := 'Fout bij toevoegen te impoteren v_ins_srtgroep_omschrijving: ' || v_ins_srtdeel_code;
|
|
SELECT sg.ins_srtgroep_omschrijving
|
|
INTO v_ins_srtgroep_omschrijving
|
|
FROM ins_srtgroep sg
|
|
WHERE SUBSTR (sg.ins_srtgroep_omschrijving, 1, 2) = SUBSTR (v_ins_srtdeel_code, 1, 2);
|
|
|
|
v_errormsg := 'Fout bij toevoegen te impoteren v_alg_ruimte_nr: ' || v_alg_ruimte_nr;
|
|
SELECT alg_locatie_code, alg_gebouw_upper, alg_verdieping_volgnr
|
|
INTO v_alg_locatie_code, v_alg_gebouw_code, v_alg_verdieping_volgnr
|
|
FROM alg_v_ruimte_gegevens rg
|
|
WHERE rg.alg_ruimte_nr = v_alg_ruimte_nr;
|
|
|
|
v_errormsg := 'Fout bij toevoegen te impoteren v_ins_deel_aanmaak_txt: ' || v_ins_deel_aanmaak_txt;
|
|
v_ins_deel_aanmaak := NULL;
|
|
IF v_ins_deel_aanmaak_txt IS NOT NULL
|
|
THEN
|
|
v_ins_deel_aanmaak := to_date('0101' || v_ins_deel_aanmaak_txt, 'ddmmyyyy');
|
|
END IF;
|
|
|
|
v_errormsg := 'Fout bij toevoegen te impoteren v_kenmerk9: ' || v_kenmerk9;
|
|
IF v_kenmerk9 IS NOT NULL
|
|
THEN
|
|
v_ins_deel_startjaar := to_date('0101' || v_kenmerk9, 'ddmmyyyy');
|
|
END IF;
|
|
|
|
v_errormsg := 'Fout bij toevoegen te impoteren v_ins_deel_aantal_txt: ' || v_ins_deel_aantal_txt;
|
|
IF v_ins_deel_aantal_txt IS NOT NULL
|
|
THEN
|
|
v_ins_deel_aantal := to_number(v_ins_deel_aantal_txt);
|
|
END IF;
|
|
|
|
v_errormsg := 'Fout bij toevoegen te impoteren v_ins_srtcontrole_periode_txt: ' || v_ins_srtcontrole_periode_txt;
|
|
IF v_ins_srtcontrole_periode_txt IS NOT NULL
|
|
THEN
|
|
v_ins_srtcontrole_periode := to_number(v_ins_srtcontrole_periode_txt);
|
|
END IF;
|
|
|
|
v_errormsg := 'Fout bij toevoegen te impoteren v_ins_srtcontrole_prijs_txt: ' || v_ins_srtcontrole_prijs_txt;
|
|
IF v_ins_srtcontrole_prijs_txt IS NOT NULL
|
|
THEN
|
|
v_ins_srtcontrole_prijs := to_number(REPLACE(REPLACE(v_ins_srtcontrole_prijs_txt, '.'), ',', '.'));
|
|
END IF;
|
|
|
|
v_errormsg := 'Fout bij toevoegen te impoteren v_kenmerk7: ' || v_kenmerk7;
|
|
IF v_kenmerk7 IS NOT NULL
|
|
THEN
|
|
IF INSTR(v_kenmerk7, '%') = 0
|
|
THEN
|
|
v_ins_deel_percentage := to_number(v_kenmerk7)*100;
|
|
ELSE
|
|
v_ins_deel_percentage := to_number(REPLACE(v_kenmerk7, '%'));
|
|
END IF;
|
|
END IF;
|
|
|
|
INSERT INTO fac_imp_ins (ins_discipline_omschrijving,
|
|
ins_srtgroep_omschrijving,
|
|
ins_srtdeel_code,
|
|
ins_srtdeel_omschrijving,
|
|
ins_deel_omschrijving,
|
|
ins_deel_opmerking,
|
|
alg_locatie_code,
|
|
alg_gebouw_code,
|
|
alg_verdieping_volgnr,
|
|
alg_ruimte_nr,
|
|
ins_kenmerkwaarde1,
|
|
ins_kenmerkwaarde2,
|
|
ins_kenmerkwaarde3,
|
|
ins_kenmerkwaarde4,
|
|
ins_kenmerkwaarde5,
|
|
ins_kenmerkwaarde6,
|
|
ins_kenmerkwaarde7,
|
|
ins_kenmerkwaarde8,
|
|
ins_kenmerkwaarde9,
|
|
ins_kenmerkwaarde10,
|
|
ins_deel_aanmaak,
|
|
ins_deel_aantal)
|
|
VALUES (SUBSTR(v_ins_discipline_omschrijving, 1,60),
|
|
SUBSTR(v_ins_srtgroep_omschrijving, 1, 60),
|
|
SUBSTR(v_ins_srtdeel_code,1,10),
|
|
SUBSTR(v_ins_srtdeel_omschrijving || ' - ' || v_ins_srtdeel_code, 1, 100),
|
|
SUBSTR(v_ins_deel_omschrijving, 1, 60),
|
|
SUBSTR(v_ins_deel_opmerking, 1, 320),
|
|
SUBSTR(v_alg_locatie_code, 1, 10),
|
|
SUBSTR(v_alg_gebouw_code, 1, 12),
|
|
v_alg_verdieping_volgnr,
|
|
SUBSTR(v_alg_ruimte_nr,1,20),
|
|
DECODE(v_kenmerk1, NULL, NULL, 'Code RVB|0=' || v_kenmerk1),
|
|
DECODE(v_kenmerk2, NULL, NULL, 'Opmerking|0=' || v_kenmerk2),
|
|
v_kenmerk3,
|
|
'',
|
|
DECODE(v_kenmerk5, NULL, NULL, 'Merk|0=' || v_kenmerk5),
|
|
v_ins_srtcontrole_prijs,
|
|
v_ins_deel_percentage,
|
|
v_ins_srtcontrole_periode,
|
|
to_char(v_ins_deel_startjaar, 'ddmmyyyy'),
|
|
to_char(v_ins_deel_aanmaak, 'ddmmyyyy'),
|
|
v_ins_deel_aanmaak,
|
|
to_number(v_ins_deel_aantal));
|
|
|
|
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;
|
|
END LOOP;
|
|
|
|
COMMIT;
|
|
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 kmmo_import_assets;
|
|
/
|
|
|
|
|
|
CREATE OR REPLACE PROCEDURE kmmo_update_assets (p_import_key IN NUMBER)
|
|
AS
|
|
CURSOR c IS SELECT * FROM fac_imp_ins;
|
|
|
|
oracle_err_num NUMBER;
|
|
oracle_err_mes VARCHAR2 (200);
|
|
v_errormsg VARCHAR2 (200);
|
|
v_errorhint VARCHAR2 (200);
|
|
v_aanduiding VARCHAR2 (100);
|
|
|
|
v_deel_key NUMBER;
|
|
v_srtdeel_key NUMBER;
|
|
v_srtcontrole_key NUMBER;
|
|
v_srtcontroledl_xcp_key NUMBER;
|
|
v_taakcat_key NUMBER;
|
|
v_srtcontrole_periode INS_SRTCONTROLE.INS_SRTCONTROLE_PERIODE%TYPE;
|
|
v_srtcontrole_materiaal INS_SRTCONTROLE.INS_SRTCONTROLE_MATERIAAL%TYPE;
|
|
v_srtcontrole_percentage INS_SRTCONTROLE.INS_SRTCONTROLE_PERCENTAGE%TYPE;
|
|
v_srtcontrole_level INS_SRTCONTROLE.INS_SRTCONTROLE_LEVEL%TYPE;
|
|
v_percentage NUMBER;
|
|
v_materiaal INS_SRTCONTROLEDL_XCP.INS_SRTCONTROLEDL_XCP_MATERIA%TYPE;
|
|
BEGIN
|
|
|
|
fac_update_ins(p_import_key);
|
|
|
|
FOR rec IN c
|
|
LOOP
|
|
BEGIN
|
|
v_aanduiding := rec.ins_deel_omschrijving;
|
|
-- zoek het object
|
|
v_errorhint := 'Zoek het object';
|
|
|
|
SELECT ins_deel_key, ins_srtdeel_key
|
|
INTO v_deel_key, v_srtdeel_key
|
|
FROM ins_deel
|
|
WHERE ins_deel_omschrijving = rec.ins_deel_omschrijving;
|
|
|
|
-- zoek de taakcategorie
|
|
v_errorhint := 'Zoek de taakcategorie';
|
|
|
|
SELECT ins_discipline_key
|
|
INTO v_taakcat_key
|
|
FROM ctr_discipline
|
|
WHERE UPPER (ins_discipline_omschrijving) =
|
|
UPPER (rec.ins_kenmerkwaarde3);
|
|
|
|
BEGIN
|
|
v_errorhint := 'Bepaal percentage';
|
|
v_percentage := NULL;
|
|
|
|
-- IF rec.ins_kenmerkwaarde7 <> 1
|
|
-- AND rec.ins_kenmerkwaarde7 IS NOT NULL
|
|
-- THEN
|
|
-- v_percentage := rec.ins_kenmerkwaarde7 * 100;
|
|
-- END IF;
|
|
v_percentage := rec.ins_kenmerkwaarde7;
|
|
|
|
v_errorhint := 'Bepaal materiaalkosten';
|
|
v_materiaal :=
|
|
FAC.safe_to_number (
|
|
REPLACE (rec.ins_kenmerkwaarde6, ',', '.'));
|
|
|
|
-- zoek de taak
|
|
v_errorhint := 'Zoek de taak';
|
|
|
|
SELECT ins_srtcontrole_key,
|
|
ins_srtcontrole_periode,
|
|
ins_srtcontrole_materiaal,
|
|
ins_srtcontrole_percentage
|
|
INTO v_srtcontrole_key,
|
|
v_srtcontrole_periode,
|
|
v_srtcontrole_materiaal,
|
|
v_srtcontrole_percentage
|
|
FROM ins_srtcontrole
|
|
WHERE ins_srtinstallatie_key = v_srtdeel_key
|
|
AND ins_srtcontrole_niveau = 'S'
|
|
AND ctr_discipline_key = v_taakcat_key;
|
|
|
|
IF v_srtcontrole_periode <>
|
|
COALESCE (rec.ins_kenmerkwaarde8, 0)
|
|
OR v_srtcontrole_materiaal <> v_materiaal
|
|
OR v_srtcontrole_percentage <> v_percentage
|
|
OR ( rec.ins_kenmerkwaarde9 IS NOT NULL
|
|
AND rec.ins_kenmerkwaarde9 <>
|
|
COALESCE (rec.ins_kenmerkwaarde10, '01010000'))
|
|
THEN
|
|
-- dan moeten we een dl_xcp record aanmaken
|
|
v_errorhint := 'Aanmaken xcp';
|
|
|
|
INSERT INTO ins_srtcontroledl_xcp (ins_srtcontrole_key,
|
|
ins_deel_key)
|
|
VALUES (v_srtcontrole_key, v_deel_key)
|
|
RETURNING ins_srtcontroledl_xcp_key
|
|
INTO v_srtcontroledl_xcp_key;
|
|
|
|
v_errorhint := 'Aanpassen periode';
|
|
|
|
IF v_srtcontrole_periode <>
|
|
COALESCE (rec.ins_kenmerkwaarde8, 0)
|
|
THEN
|
|
UPDATE ins_srtcontroledl_xcp
|
|
SET ins_srtcontroledl_xcp_periode =
|
|
COALESCE (
|
|
TO_NUMBER (rec.ins_kenmerkwaarde8),
|
|
0)
|
|
WHERE ins_srtcontroledl_xcp_key =
|
|
v_srtcontroledl_xcp_key;
|
|
END IF;
|
|
|
|
v_errorhint :=
|
|
'Aanpassen materiaal: '
|
|
|| rec.ins_kenmerkwaarde6
|
|
|| ' - '
|
|
|| v_materiaal;
|
|
|
|
IF v_srtcontrole_materiaal <> v_materiaal
|
|
THEN
|
|
UPDATE ins_srtcontroledl_xcp
|
|
SET ins_srtcontroledl_xcp_materia = v_materiaal
|
|
WHERE ins_srtcontroledl_xcp_key =
|
|
v_srtcontroledl_xcp_key;
|
|
END IF;
|
|
|
|
v_errorhint := 'Aanpassen percentage';
|
|
|
|
IF v_srtcontrole_percentage <> v_percentage
|
|
THEN
|
|
UPDATE ins_srtcontroledl_xcp
|
|
SET ins_srtcontroledl_xcp_perc = v_percentage
|
|
WHERE ins_srtcontroledl_xcp_key =
|
|
v_srtcontroledl_xcp_key;
|
|
END IF;
|
|
|
|
v_errorhint := 'Aanpassen startdatum: ' || rec.ins_kenmerkwaarde9;
|
|
|
|
IF rec.ins_kenmerkwaarde9 IS NOT NULL
|
|
AND rec.ins_kenmerkwaarde9 <>
|
|
COALESCE (rec.ins_kenmerkwaarde10, '01010000')
|
|
THEN
|
|
UPDATE ins_srtcontroledl_xcp
|
|
SET ins_srtcontroledl_xcp_startdat =
|
|
TRUNC (
|
|
TO_DATE (rec.ins_kenmerkwaarde9,
|
|
'DDMMYYYY'),
|
|
'YYYY')
|
|
WHERE ins_srtcontroledl_xcp_key =
|
|
v_srtcontroledl_xcp_key;
|
|
END IF;
|
|
END IF;
|
|
EXCEPTION
|
|
WHEN NO_DATA_FOUND
|
|
THEN
|
|
v_errorhint := 'Bepalen level';
|
|
v_srtcontrole_level := 10;
|
|
|
|
IF rec.ins_kenmerkwaarde3 <> 'Vervanging'
|
|
THEN
|
|
v_srtcontrole_level := 100;
|
|
END IF;
|
|
|
|
v_errorhint := 'Aanmaken srtcontrole';
|
|
|
|
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,
|
|
ins_srtcontrole_materiaal,
|
|
ins_srtcontrole_percentage)
|
|
VALUES (
|
|
v_srtdeel_key,
|
|
'S',
|
|
rec.ins_kenmerkwaarde3
|
|
|| ' - '
|
|
|| rec.ins_srtdeel_code,
|
|
v_taakcat_key,
|
|
COALESCE (
|
|
TO_NUMBER (rec.ins_kenmerkwaarde8),
|
|
0),
|
|
4,
|
|
v_srtcontrole_level,
|
|
v_materiaal,
|
|
v_srtcontrole_percentage);
|
|
END;
|
|
EXCEPTION
|
|
WHEN OTHERS
|
|
THEN
|
|
oracle_err_num := SQLCODE;
|
|
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
|
|
v_errormsg := 'OTHERS (error ' || oracle_err_num || '/' || oracle_err_mes || ')';
|
|
fac.writelog ('KMMO.import MJOB',
|
|
'E',
|
|
v_aanduiding || ': ' || v_errormsg,
|
|
v_errorhint);
|
|
|
|
END;
|
|
END LOOP;
|
|
EXCEPTION
|
|
WHEN OTHERS
|
|
THEN
|
|
oracle_err_num := SQLCODE;
|
|
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
|
|
v_errormsg := 'OTHERS (error ' || oracle_err_num || '/' || oracle_err_mes || ')';
|
|
fac.writelog ('KMMO.import MJOB',
|
|
'E',
|
|
v_aanduiding || ': ' || v_errormsg,
|
|
v_errorhint);
|
|
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
|