1619 lines
57 KiB
SQL
1619 lines
57 KiB
SQL
-- Script containing customer specific db-configuration for ASFC.
|
||
-- (c) 2014 SG|facilitor bv
|
||
-- $Revision$
|
||
-- $Id$
|
||
--
|
||
-- Support: +31 53 4800700
|
||
|
||
set echo on
|
||
|
||
spool xasfc.lst
|
||
|
||
-- packages tbv rapportages
|
||
CREATE OR REPLACE PACKAGE ASFC
|
||
AS
|
||
-- PACKAGES voor de klant specifieke rapportages, functies of procedures
|
||
|
||
FUNCTION get_bits_str (p_eenheid IN NUMBER,
|
||
p_bits IN NUMBER)
|
||
RETURN VARCHAR2;
|
||
END;
|
||
/
|
||
|
||
CREATE OR REPLACE PACKAGE BODY ASFC
|
||
AS
|
||
--
|
||
--Functies
|
||
--
|
||
FUNCTION get_bits_str (p_eenheid IN NUMBER,
|
||
p_bits IN NUMBER) RETURN VARCHAR2
|
||
AS
|
||
v_result VARCHAR2(10);
|
||
BEGIN
|
||
|
||
IF p_eenheid = 2
|
||
THEN
|
||
IF BITAND (p_bits, 2) <> 0 THEN v_result := 'Ma'; END IF;
|
||
IF BITAND (p_bits, 4) <> 0 THEN v_result := v_result || 'Di'; END IF;
|
||
IF BITAND (p_bits, 8) <> 0 THEN v_result := v_result || 'Wo'; END IF;
|
||
IF BITAND (p_bits, 16) <> 0 THEN v_result := v_result || 'Do'; END IF;
|
||
IF BITAND (p_bits, 32) <> 0 THEN v_result := v_result || 'Vr'; END IF;
|
||
IF BITAND (p_bits, 64) <> 0 THEN v_result := v_result || 'Za'; END IF;
|
||
IF BITAND (p_bits, 1) <> 0 THEN v_result := v_result || 'Zo'; END IF;
|
||
IF BITAND (p_bits, 128) <> 0 THEN v_result := v_result || 'NF'; END IF;
|
||
END IF;
|
||
RETURN v_result;
|
||
END;
|
||
END;
|
||
/
|
||
|
||
CREATE OR REPLACE VIEW asfc_v_imp_bestek_del
|
||
(
|
||
ins_srtcontroledl_xcp_key,
|
||
ins_deel_key,
|
||
ins_srtcontrole_key
|
||
)
|
||
AS
|
||
SELECT ins_srtcontroledl_xcp_key, x.ins_deel_key, ins_srtcontrole_key
|
||
FROM ins_srtcontroledl_xcp x, ins_v_deel_gegevens dg
|
||
WHERE NOT EXISTS
|
||
(SELECT ins_srtcontrole_key
|
||
FROM ins_deel d, asfc_imp_bestek i, ins_srtcontrole sc
|
||
WHERE ins_deel_upper =
|
||
SUBSTR (
|
||
UPPER (i.alg_ruimte_nr)
|
||
|| ' - '
|
||
|| UPPER (i.ins_deel_omschrijving),
|
||
1,
|
||
60)
|
||
AND UPPER (ins_srtcontrole_omschrijving) =
|
||
UPPER (i.ins_srtcontrole_groep)
|
||
AND x.ins_deel_key = d.ins_deel_key
|
||
AND x.ins_srtcontrole_key = sc.ins_srtcontrole_key)
|
||
AND x.ins_deel_key = dg.ins_deel_key
|
||
AND dg.alg_locatie_key IN
|
||
(SELECT alg_locatie_key
|
||
FROM alg_v_ruimte_gegevens rg, asfc_imp_bestek i
|
||
WHERE i.alg_ruimte_key = rg.alg_ruimte_key);
|
||
|
||
CREATE OR REPLACE PROCEDURE asfc_import_bestek (p_import_key IN NUMBER)
|
||
AS
|
||
CURSOR c_cursor
|
||
IS
|
||
SELECT *
|
||
FROM fac_imp_file
|
||
WHERE fac_import_key = p_import_key
|
||
ORDER BY fac_imp_file_index;
|
||
|
||
CURSOR c_dubbel
|
||
IS
|
||
SELECT alg_ruimte_nr
|
||
|| '-'
|
||
|| ins_deel_omschrijving
|
||
|| '-'
|
||
|| ins_srtcontrole_groep
|
||
omschrijving,
|
||
COUNT (alg_ruimte_nr) aantal
|
||
FROM asfc_imp_bestek
|
||
GROUP BY alg_ruimte_nr, ins_deel_omschrijving, ins_srtcontrole_groep
|
||
HAVING COUNT (alg_ruimte_nr) > 1;
|
||
|
||
v_dummy VARCHAR2 (1000);
|
||
header_found BOOLEAN;
|
||
v_newline VARCHAR2 (1000);
|
||
v_aanduiding VARCHAR2 (1000); -- Import line
|
||
v_field VARCHAR2 (100); -- Import field
|
||
v_fielddelimitor VARCHAR2 (1); -- Field seperator
|
||
v_errormsg VARCHAR (200);
|
||
v_errorhint VARCHAR (200);
|
||
oracle_err_num NUMBER;
|
||
oracle_err_mes VARCHAR2 (200);
|
||
v_skipfield VARCHAR2 (100);
|
||
v_count NUMBER;
|
||
-- De importvelden
|
||
v_ruimte_key alg_ruimte.alg_ruimte_key%TYPE;
|
||
v_ruimte_nr alg_ruimte.alg_ruimte_nr%TYPE;
|
||
v_locatie_code alg_locatie.alg_locatie_code%TYPE;
|
||
v_gebouw_code alg_gebouw.alg_gebouw_code%TYPE;
|
||
v_srtdeel_omschrijving ins_srtdeel.ins_srtdeel_omschrijving%TYPE;
|
||
v_deel_omschrijving ins_deel.ins_deel_omschrijving%TYPE;
|
||
v_srtcontrole_groep ins_srtcontrole.ins_srtcontrole_groep%TYPE;
|
||
v_srtcontrole_periode ins_srtcontrole.ins_srtcontrole_periode%TYPE;
|
||
v_srtcontrole_eenheid ins_srtcontrole.ins_srtcontrole_eenheid%TYPE;
|
||
v_srtcontrole_bits ins_srtcontrole.ins_srtcontrole_bits%TYPE;
|
||
v_srtcontroledl_xcp_groep ins_srtcontroledl_xcp.ins_srtcontroledl_xcp_groep%TYPE;
|
||
BEGIN
|
||
-- Init
|
||
header_found := FALSE;
|
||
v_fielddelimitor := ';';
|
||
|
||
-- Clear my previous imported rows
|
||
DELETE FROM asfc_imp_bestek;
|
||
|
||
FOR rec IN c_cursor
|
||
LOOP
|
||
BEGIN
|
||
v_errorhint := 'Ophalen nieuwe importregel.';
|
||
v_newline := rec.fac_imp_file_line;
|
||
v_aanduiding := v_newline;
|
||
|
||
IF SUBSTR (v_newline, 1, 3) = '?'
|
||
THEN
|
||
-- EF BB BF aangetroffen
|
||
fac.imp_writelog (p_import_key,
|
||
'W',
|
||
'Byte Order Mark aangetroffen',
|
||
'Bestand heeft onbehandeld UTF-8 formaat.');
|
||
v_newline := SUBSTR (v_newline, 4);
|
||
END IF;
|
||
|
||
IF UPPER (v_newline) LIKE
|
||
'%LOCATIECODE;%GEBOUWCODE;BOUWLAAGVOLGNUMMER;RUIMTENUMMER;ELEMENTSOORT;ACTIVITEIT;ELEMENT;TAAK;FREQ%AANTAL;FREQ%PERIODE;MA;DI;WO;DO;VR;ZA;ZO%'
|
||
THEN
|
||
-- Sla de kopregel over.
|
||
header_found := TRUE;
|
||
ELSIF (header_found)
|
||
THEN
|
||
v_errorhint := 'Inlezen locatiecode.';
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_dummy);
|
||
|
||
IF LENGTH (v_dummy) > 10
|
||
THEN
|
||
fac.imp_writelog (
|
||
p_import_key,
|
||
'W',
|
||
'Locatiecode afgebroken tot ' || SUBSTR (v_dummy, 1, 10),
|
||
v_aanduiding);
|
||
END IF;
|
||
|
||
v_locatie_code := SUBSTR (v_dummy, 1, 10);
|
||
|
||
v_errorhint := 'Inlezen gebouwcode.';
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_dummy);
|
||
|
||
IF LENGTH (v_dummy) > 12
|
||
THEN
|
||
fac.imp_writelog (
|
||
p_import_key,
|
||
'W',
|
||
'Gebouwcode afgebroken tot ' || SUBSTR (v_dummy, 1, 10),
|
||
v_aanduiding);
|
||
END IF;
|
||
|
||
v_gebouw_code := SUBSTR (v_dummy, 1, 12);
|
||
|
||
v_errorhint := 'Inlezen verdieping.';
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_dummy);
|
||
|
||
v_errorhint := 'Inlezen ruimtenummer.';
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_dummy);
|
||
|
||
-- In de export/import routine wordt een _ voor het ruimtenummer geplaatst om problemen
|
||
-- met Excel te voorkomen.
|
||
IF SUBSTR(v_dummy, 1,1) = '_'
|
||
THEN
|
||
v_dummy := SUBSTR(v_dummy, 2);
|
||
END IF;
|
||
|
||
IF LENGTH (v_dummy) > 10
|
||
THEN
|
||
fac.imp_writelog (
|
||
p_import_key,
|
||
'W',
|
||
'Ruimtenummer afgebroken tot ' || SUBSTR (v_dummy, 1, 10),
|
||
v_aanduiding);
|
||
END IF;
|
||
|
||
v_ruimte_nr := SUBSTR (v_dummy, 1, 10);
|
||
|
||
BEGIN
|
||
SELECT alg_ruimte_key
|
||
INTO v_ruimte_key
|
||
FROM alg_v_ruimte_gegevens
|
||
WHERE UPPER(alg_locatie_code) = UPPER(v_locatie_code)
|
||
AND alg_gebouw_upper = UPPER(v_gebouw_code)
|
||
AND alg_ruimte_nr = v_ruimte_nr;
|
||
EXCEPTION
|
||
WHEN NO_DATA_FOUND
|
||
THEN
|
||
fac.imp_writelog (
|
||
p_import_key,
|
||
'W',
|
||
'Ruimtenummer niet gevonden: ' || v_ruimte_nr,
|
||
v_aanduiding);
|
||
v_ruimte_key := NULL;
|
||
END;
|
||
|
||
|
||
v_errorhint := 'Inlezen elementsoort/objectsoort.';
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_dummy);
|
||
|
||
IF LENGTH (v_dummy) > 100
|
||
THEN
|
||
fac.imp_writelog (
|
||
p_import_key,
|
||
'W',
|
||
'Elementsoort/objectsoort afgebroken tot '
|
||
|| SUBSTR (v_dummy, 1, 100),
|
||
v_aanduiding);
|
||
END IF;
|
||
|
||
v_srtdeel_omschrijving := SUBSTR (v_dummy, 1, 100);
|
||
|
||
v_errorhint := 'Inlezen activiteit.';
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_dummy);
|
||
|
||
IF LENGTH (v_dummy) > 60
|
||
THEN
|
||
fac.imp_writelog (
|
||
p_import_key,
|
||
'W',
|
||
'Activiteit afgebroken tot ' || SUBSTR (v_dummy, 1, 60),
|
||
v_aanduiding);
|
||
END IF;
|
||
|
||
v_srtcontrole_groep := SUBSTR (v_dummy, 1, 60);
|
||
|
||
v_errorhint := 'Inlezen element/object.';
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_dummy);
|
||
|
||
IF LENGTH (v_dummy) > 60
|
||
THEN
|
||
fac.imp_writelog (
|
||
p_import_key,
|
||
'W',
|
||
'Inlezen element/object afgebroken tot '
|
||
|| SUBSTR (v_dummy, 1, 60),
|
||
v_aanduiding);
|
||
END IF;
|
||
|
||
v_deel_omschrijving := SUBSTR (v_dummy, 1, 60);
|
||
|
||
|
||
v_errorhint := 'Inlezen taak';
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_dummy);
|
||
|
||
IF LENGTH (v_dummy) > 60
|
||
THEN
|
||
fac.imp_writelog (
|
||
p_import_key,
|
||
'W',
|
||
'Inlezen taak afgebroken tot ' || SUBSTR (v_dummy, 1, 60),
|
||
v_aanduiding);
|
||
END IF;
|
||
|
||
v_srtcontroledl_xcp_groep := SUBSTR (v_dummy, 1, 60);
|
||
|
||
v_errorhint := 'Inlezen periode';
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_dummy);
|
||
|
||
IF fac.safe_to_number (v_dummy) = NULL
|
||
THEN
|
||
fac.imp_writelog (p_import_key,
|
||
'E',
|
||
'Periode bevat geen nummer. ',
|
||
v_aanduiding);
|
||
END IF;
|
||
|
||
v_srtcontrole_periode := fac.safe_to_number (v_dummy);
|
||
|
||
v_errorhint := 'Inlezen eenheid';
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_dummy);
|
||
|
||
IF UPPER (v_dummy) IN ('D', 'W', 'M', 'J')
|
||
THEN
|
||
CASE UPPER (v_dummy)
|
||
WHEN 'D'
|
||
THEN
|
||
v_srtcontrole_eenheid := 1;
|
||
WHEN 'W'
|
||
THEN
|
||
v_srtcontrole_eenheid := 2;
|
||
WHEN 'M'
|
||
THEN
|
||
v_srtcontrole_eenheid := 3;
|
||
WHEN 'J'
|
||
THEN
|
||
v_srtcontrole_eenheid := 4;
|
||
END CASE;
|
||
ELSE
|
||
fac.imp_writelog (p_import_key,
|
||
'E',
|
||
'Eenheid bevat geen geldige waarde. ',
|
||
v_aanduiding);
|
||
v_srtcontrole_eenheid := NULL;
|
||
END IF;
|
||
|
||
v_errorhint := 'Inlezen dagen';
|
||
v_srtcontrole_bits := 0;
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_dummy);
|
||
|
||
IF v_dummy = 1
|
||
THEN
|
||
v_srtcontrole_bits := v_srtcontrole_bits + 2;
|
||
END IF;
|
||
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_dummy);
|
||
|
||
IF v_dummy = 1
|
||
THEN
|
||
v_srtcontrole_bits := v_srtcontrole_bits + 4;
|
||
END IF;
|
||
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_dummy);
|
||
|
||
IF v_dummy = 1
|
||
THEN
|
||
v_srtcontrole_bits := v_srtcontrole_bits + 8;
|
||
END IF;
|
||
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_dummy);
|
||
|
||
IF v_dummy = 1
|
||
THEN
|
||
v_srtcontrole_bits := v_srtcontrole_bits + 16;
|
||
END IF;
|
||
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_dummy);
|
||
|
||
IF v_dummy = 1
|
||
THEN
|
||
v_srtcontrole_bits := v_srtcontrole_bits + 32;
|
||
END IF;
|
||
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_dummy);
|
||
|
||
IF v_dummy = 1
|
||
THEN
|
||
v_srtcontrole_bits := v_srtcontrole_bits + 64;
|
||
END IF;
|
||
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_dummy);
|
||
|
||
IF v_dummy = 1
|
||
THEN
|
||
v_srtcontrole_bits := v_srtcontrole_bits + 1;
|
||
END IF;
|
||
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_dummy);
|
||
|
||
IF v_dummy = 1
|
||
THEN
|
||
v_srtcontrole_bits := v_srtcontrole_bits + 128;
|
||
END IF;
|
||
|
||
IF v_srtcontrole_eenheid = 3 -- maand
|
||
THEN
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_dummy); -- inlezen rangorde
|
||
v_srtcontrole_bits := v_srtcontrole_bits + (256 * v_dummy);
|
||
END IF;
|
||
|
||
IF v_srtcontrole_bits = 0
|
||
THEN
|
||
fac.imp_writelog (p_import_key,
|
||
'W',
|
||
'Dagen bevatten geen geldige waarde. ',
|
||
v_aanduiding);
|
||
END IF;
|
||
|
||
INSERT INTO asfc_imp_bestek (alg_ruimte_key,
|
||
alg_ruimte_nr,
|
||
ins_srtdeel_omschrijving,
|
||
ins_deel_omschrijving,
|
||
ins_srtcontrole_groep,
|
||
ins_srtcontrole_periode,
|
||
ins_srtcontrole_eenheid,
|
||
ins_srtcontrole_bits,
|
||
ins_srtcontroledl_xcp_groep)
|
||
VALUES (v_ruimte_key,
|
||
v_ruimte_nr,
|
||
'Schoonmaakobject', -- voor het eenvoud maar <20><>n objectsoort gebruikt v_srtdeel_omschrijving,
|
||
v_deel_omschrijving,
|
||
v_srtcontrole_groep,
|
||
v_srtcontrole_periode,
|
||
v_srtcontrole_eenheid,
|
||
v_srtcontrole_bits,
|
||
v_srtcontroledl_xcp_groep);
|
||
END IF;
|
||
|
||
COMMIT;
|
||
END;
|
||
END LOOP;
|
||
|
||
IF NOT header_found
|
||
THEN
|
||
fac.imp_writelog (p_import_key,
|
||
'E',
|
||
'Geen geldige header aangetroffen',
|
||
'Bestand is geen geldig bestek importbestand.');
|
||
ELSE
|
||
SELECT COUNT ( * ) INTO v_count FROM asfc_v_imp_bestek_del;
|
||
|
||
IF v_count > 0
|
||
THEN
|
||
fac.imp_writelog (
|
||
p_import_key,
|
||
'W',
|
||
'Aantal bestek regels in FACILITOR die niet in importbestand voorkomen: '
|
||
|| TO_CHAR (v_count),
|
||
'');
|
||
END IF;
|
||
|
||
FOR rec IN c_dubbel
|
||
LOOP
|
||
BEGIN
|
||
fac.imp_writelog (
|
||
p_import_key,
|
||
'W',
|
||
'Combinatie van ruimte, element en activiteit komt '
|
||
|| rec.aantal
|
||
|| ' keer voor: '
|
||
|| rec.omschrijving,
|
||
'');
|
||
END;
|
||
END LOOP;
|
||
END IF;
|
||
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.imp_writelog (p_import_key,
|
||
'E',
|
||
SUBSTR (v_errormsg, 1, 1000),
|
||
v_aanduiding);
|
||
|
||
-- maak de importtabel leeg om te voorkomen dat er halve bestanden ingelezen worden.
|
||
DELETE FROM asfc_imp_bestek;
|
||
END;
|
||
/
|
||
|
||
|
||
CREATE OR REPLACE PROCEDURE asfc_update_bestek (p_import_key IN NUMBER)
|
||
AS
|
||
CURSOR c
|
||
IS
|
||
SELECT *
|
||
FROM asfc_imp_bestek
|
||
WHERE alg_ruimte_key IS NOT NULL;
|
||
|
||
v_oldcount NUMBER;
|
||
v_newcount NUMBER;
|
||
v_deel_key INS_DEEL.INS_DEEL_KEY%TYPE;
|
||
v_srtdeel_key INS_SRTDEEL.INS_SRTDEEL_KEY%TYPE;
|
||
v_srtcontrole_key INS_SRTCONTROLE.INS_SRTCONTROLE_KEY%TYPE;
|
||
v_srtcontroledl_xcp_key INS_SRTCONTROLEDL_XCP.INS_SRTCONTROLEDL_XCP_KEY%TYPE;
|
||
v_srtcontroledl_xcp_key_new INS_SRTCONTROLEDL_XCP.INS_SRTCONTROLEDL_XCP_KEY%TYPE;
|
||
v_srtcontroledl_xcp_eenheid INS_SRTCONTROLEDL_XCP.INS_SRTCONTROLEDL_XCP_EENHEID%TYPE;
|
||
v_srtcontroledl_xcp_periode INS_SRTCONTROLEDL_XCP.INS_SRTCONTROLEDL_XCP_PERIODE%TYPE;
|
||
v_srtcontroledl_xcp_bits INS_SRTCONTROLEDL_XCP.INS_SRTCONTROLEDL_XCP_BITS%TYPE;
|
||
v_srtcontroledl_xcp_groep INS_SRTCONTROLEDL_XCP.INS_SRTCONTROLEDL_XCP_GROEP%TYPE;
|
||
v_errormsg VARCHAR2 (1000);
|
||
v_error_hint VARCHAR2 (1000);
|
||
oracle_err_mes VARCHAR2 (1000);
|
||
oracle_err_num VARCHAR2 (1000);
|
||
currentversion fac_module.fac_module_version%TYPE;
|
||
BEGIN
|
||
|
||
SELECT MAX (fac_module_version)
|
||
INTO currentversion
|
||
FROM fac_module;
|
||
|
||
fac.imp_writelog (p_import_key,
|
||
'I',
|
||
'ASFC bestek import version ' || currentversion,
|
||
'$Revision$'
|
||
);
|
||
|
||
SELECT COUNT (*)
|
||
INTO v_oldcount
|
||
FROM ins_srtcontroledl_xcp;
|
||
|
||
SELECT COUNT (*)
|
||
INTO v_newcount
|
||
FROM asfc_imp_bestek
|
||
WHERE alg_ruimte_nr IS NOT NULL;
|
||
|
||
IF v_newcount = 0 THEN
|
||
fac.imp_writelog (p_import_key,
|
||
'E',
|
||
'ASFM bestek import bevat geen records',
|
||
'$Revision$'
|
||
);
|
||
return;
|
||
END IF;
|
||
|
||
-- How many active records are now present?
|
||
SELECT COUNT (*)
|
||
INTO v_oldcount
|
||
FROM ins_srtcontroledl_xcp;
|
||
|
||
FOR rec IN c
|
||
LOOP
|
||
BEGIN
|
||
v_error_hint := rec.alg_ruimte_nr || ' - ' || rec.ins_srtdeel_omschrijving || ' - ' || rec.ins_srtcontrole_groep;
|
||
-- de ruimte is al bekend.
|
||
-- nu gaan we op zoek naar het objectsoort
|
||
BEGIN
|
||
SELECT ins_srtdeel_key
|
||
INTO v_srtdeel_key
|
||
FROM ins_srtdeel sd
|
||
WHERE ins_srtdeel_upper = UPPER(rec.ins_srtdeel_omschrijving);
|
||
|
||
EXCEPTION WHEN NO_DATA_FOUND
|
||
THEN
|
||
INSERT INTO ins_srtdeel (ins_srtgroep_key, ins_srtdeel_code, ins_srtdeel_omschrijving, ins_srtdeel_binding)
|
||
VALUES (1, -- bouwkundig regulier
|
||
substr(rec.ins_srtdeel_omschrijving, 1, 5)|| substr(rec.ins_srtdeel_omschrijving, length(rec.ins_srtdeel_omschrijving)-4, length(rec.ins_srtdeel_omschrijving)),
|
||
rec.ins_srtdeel_omschrijving,
|
||
1)
|
||
RETURNING ins_srtdeel_key
|
||
INTO v_srtdeel_key;
|
||
|
||
fac.imp_writelog (p_import_key, 'I', 'Elementsoort/objectsoort toegevoegd: ' ||rec.ins_srtdeel_omschrijving, '');
|
||
END;
|
||
|
||
BEGIN
|
||
SELECT ins_deel_key
|
||
INTO v_deel_key
|
||
FROM ins_deel sd
|
||
WHERE sd.ins_srtdeel_key = v_srtdeel_key
|
||
AND ins_deel_upper = SUBSTR(UPPER(rec.alg_ruimte_nr) || ' - ' || UPPER(rec.ins_deel_omschrijving),1,60)
|
||
AND ins_alg_ruimte_key = rec.alg_ruimte_key;
|
||
|
||
EXCEPTION WHEN NO_DATA_FOUND
|
||
THEN
|
||
v_error_hint := v_error_hint || ' [' || v_srtdeel_key || '-' ||
|
||
rec.alg_ruimte_key || '-' ||
|
||
'R'|| '-' ||
|
||
rec.alg_ruimte_nr || ' - ' || rec.ins_deel_omschrijving || ']';
|
||
INSERT INTO ins_deel (ins_srtdeel_key, ins_alg_ruimte_key, ins_alg_ruimte_type, ins_deel_omschrijving)
|
||
VALUES (v_srtdeel_key,
|
||
rec.alg_ruimte_key,
|
||
'R',
|
||
SUBSTR(rec.alg_ruimte_nr || ' - ' || rec.ins_deel_omschrijving,1,60))
|
||
RETURNING ins_deel_key
|
||
INTO v_deel_key;
|
||
|
||
fac.imp_writelog (p_import_key, 'I', 'Element/object toegevoegd: ' ||rec.alg_ruimte_nr || ' - ' || rec.ins_deel_omschrijving, '');
|
||
END;
|
||
|
||
-- activiteit
|
||
BEGIN
|
||
SELECT ins_srtcontrole_key
|
||
INTO v_srtcontrole_key
|
||
FROM ins_srtcontrole sc
|
||
WHERE UPPER(ins_srtcontrole_omschrijving) = UPPER(rec.ins_srtcontrole_groep);
|
||
|
||
EXCEPTION WHEN NO_DATA_FOUND
|
||
THEN
|
||
INSERT INTO ins_srtcontrole (ins_srtinstallatie_key,
|
||
ins_srtcontrole_niveau,
|
||
ins_srtcontrole_omschrijving,
|
||
ins_srtcontrole_groep,
|
||
ins_srtcontrole_mode,
|
||
ins_srtcontrole_periode,
|
||
ins_srtcontrole_eenheid)
|
||
VALUES (v_srtdeel_key,
|
||
'S',
|
||
rec.ins_srtcontrole_groep,
|
||
rec.ins_srtcontrole_groep,
|
||
0, -- 0=moment-modus
|
||
0, -- wordt gevuld bij de afwijking
|
||
0) -- wordt gevuld bij de afwijking
|
||
RETURNING ins_srtcontrole_key
|
||
INTO v_srtcontrole_key;
|
||
|
||
fac.imp_writelog (p_import_key, 'I', 'Activiteit toegevoegd: ' || rec.ins_srtcontrole_groep, '');
|
||
END;
|
||
|
||
-- afwijkende activiteit
|
||
BEGIN
|
||
SELECT ins_srtcontroledl_xcp_key,
|
||
ins_srtcontroledl_xcp_eenheid,
|
||
ins_srtcontroledl_xcp_periode,
|
||
ins_srtcontroledl_xcp_bits,
|
||
ins_srtcontroledl_xcp_groep
|
||
INTO v_srtcontroledl_xcp_key,
|
||
v_srtcontroledl_xcp_eenheid,
|
||
v_srtcontroledl_xcp_periode,
|
||
v_srtcontroledl_xcp_bits,
|
||
v_srtcontroledl_xcp_groep
|
||
FROM ins_srtcontroledl_xcp scx
|
||
WHERE scx.ins_deel_key = v_deel_key
|
||
AND scx.ins_srtcontrole_key = v_srtcontrole_key;
|
||
|
||
IF v_srtcontroledl_xcp_eenheid <> rec.ins_srtcontrole_eenheid
|
||
OR v_srtcontroledl_xcp_periode <> rec.ins_srtcontrole_periode
|
||
OR v_srtcontroledl_xcp_bits <> rec.ins_srtcontrole_bits
|
||
OR COALESCE(v_srtcontroledl_xcp_groep, 'Leeg') <> COALESCE(rec.ins_srtcontroledl_xcp_groep, 'Leeg')
|
||
THEN
|
||
-- Willen we een resultaat record aanmaken als start voor de nieuwe controle. Anders komt deze als initieel ver in het verleden te liggen.
|
||
-- SELECT MAX(ins_deelsrtcontrole_datum_org)
|
||
-- INTO v_deelsrtcontrole_datum_org
|
||
-- FROM ins_deelsrtcontrole
|
||
-- WHERE ins_deel_key = v_deel_key
|
||
-- AND ins_srtcontrole_key = v_srtcontrole_key;
|
||
|
||
-- set de vervaldatum bij het huidige record
|
||
UPDATE ins_srtcontroledl_xcp
|
||
SET ins_srtcontroledl_xcp_eind = SYSDATE
|
||
WHERE ins_srtcontroledl_xcp_key = v_srtcontroledl_xcp_key;
|
||
|
||
INSERT INTO ins_srtcontroledl_xcp (ins_deel_key,
|
||
ins_srtcontrole_key,
|
||
ins_srtcontroledl_xcp_eenheid,
|
||
ins_srtcontroledl_xcp_periode,
|
||
ins_srtcontroledl_xcp_bits,
|
||
ins_srtcontroledl_xcp_groep)
|
||
VALUES (v_deel_key,
|
||
v_srtcontrole_key,
|
||
rec.ins_srtcontrole_eenheid,
|
||
rec.ins_srtcontrole_periode,
|
||
rec.ins_srtcontrole_bits,
|
||
rec.ins_srtcontroledl_xcp_groep);
|
||
|
||
END IF;
|
||
-- geen else. Er is niets veranderd.
|
||
|
||
EXCEPTION WHEN NO_DATA_FOUND
|
||
THEN
|
||
INSERT INTO ins_srtcontroledl_xcp (ins_deel_key,
|
||
ins_srtcontrole_key,
|
||
ins_srtcontroledl_xcp_eenheid,
|
||
ins_srtcontroledl_xcp_periode,
|
||
ins_srtcontroledl_xcp_bits,
|
||
ins_srtcontroledl_xcp_groep)
|
||
VALUES (v_deel_key,
|
||
v_srtcontrole_key,
|
||
rec.ins_srtcontrole_eenheid,
|
||
rec.ins_srtcontrole_periode,
|
||
rec.ins_srtcontrole_bits,
|
||
rec.ins_srtcontroledl_xcp_groep);
|
||
fac.imp_writelog (p_import_key, 'I', 'Afw activiteit toegevoegd: ' || rec.ins_srtcontrole_groep, '');
|
||
END;
|
||
|
||
COMMIT;
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
--v_error_hint := v_errormsg;
|
||
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_import_key,
|
||
'E',
|
||
v_errormsg,
|
||
v_error_hint
|
||
);
|
||
COMMIT; -- tbv logging
|
||
END;
|
||
END LOOP;
|
||
|
||
-- pas de aanduiding van het object aan. Deze wordt gevuld met het kenmerk locatieeenheid bij de ruimte
|
||
UPDATE ins_deel i
|
||
SET ins_deel_opmerking =
|
||
(SELECT alg_onrgoedkenmerk_waarde
|
||
FROM alg_onrgoedkenmerk
|
||
WHERE alg_kenmerk_key = 1021
|
||
AND ins_alg_ruimte_key = alg_onrgoed_key);
|
||
|
||
SELECT COUNT (*)
|
||
INTO v_newcount
|
||
FROM ins_srtcontroledl_xcp;
|
||
|
||
fac.imp_writelog (p_import_key,
|
||
'S',
|
||
'Aantal bestek regels vooraf: ' || TO_CHAR (v_oldcount) || ' nu: ' || TO_CHAR (v_newcount),
|
||
''
|
||
);
|
||
|
||
|
||
END;
|
||
/
|
||
|
||
-- Import routine van bestekken die de oude bestekken die niet meer voorkomen in
|
||
-- het importbestand verwijderd.
|
||
CREATE OR REPLACE PROCEDURE asfc_import_bestek_del (
|
||
p_import_key IN NUMBER
|
||
)
|
||
AS
|
||
BEGIN
|
||
asfc_import_bestek (p_import_key);
|
||
END;
|
||
/
|
||
|
||
CREATE OR REPLACE PROCEDURE asfc_update_bestek_del (
|
||
p_import_key IN NUMBER
|
||
)
|
||
AS
|
||
v_count NUMBER;
|
||
BEGIN
|
||
|
||
asfc_update_bestek (p_import_key);
|
||
|
||
SELECT COUNT (*)
|
||
INTO v_count
|
||
FROM asfc_v_imp_bestek_del;
|
||
|
||
UPDATE ins_srtcontroledl_xcp x SET ins_srtcontroledl_xcp_eind = SYSDATE
|
||
WHERE x.ins_srtcontroledl_xcp_key IN (
|
||
SELECT ins_srtcontroledl_xcp_key FROM asfc_v_imp_bestek_del);
|
||
|
||
fac.imp_writelog (p_import_key,
|
||
'S',
|
||
'Aantal bestek regels dat verwijderd is: ' || TO_CHAR (v_count),
|
||
''
|
||
);
|
||
END;
|
||
/
|
||
|
||
|
||
CREATE OR REPLACE PROCEDURE asfc_import_opleiding (p_import_key IN NUMBER)
|
||
AS
|
||
CURSOR c_cursor
|
||
IS
|
||
SELECT *
|
||
FROM fac_imp_file
|
||
WHERE fac_import_key = p_import_key
|
||
ORDER BY fac_imp_file_index;
|
||
|
||
v_dummy VARCHAR2 (1000);
|
||
header_found BOOLEAN;
|
||
v_newline VARCHAR2 (1000);
|
||
v_aanduiding VARCHAR2 (1000); -- Import line
|
||
v_field VARCHAR2 (100); -- Import field
|
||
v_fielddelimitor VARCHAR2 (1); -- Field seperator
|
||
v_errormsg VARCHAR (200);
|
||
v_errorhint VARCHAR (200);
|
||
oracle_err_num NUMBER;
|
||
oracle_err_mes VARCHAR2 (200);
|
||
v_skipfield VARCHAR2 (100);
|
||
v_count NUMBER;
|
||
-- De importvelden
|
||
v_perslid_nr prs_perslid.prs_perslid_nr%TYPE;
|
||
v_perslid_key prs_perslid.prs_perslid_key%TYPE;
|
||
v_omschrijving VARCHAR2(100);
|
||
v_begindatum DATE;
|
||
v_einddatum DATE;
|
||
BEGIN
|
||
-- Init
|
||
header_found := FALSE;
|
||
v_fielddelimitor := ';';
|
||
|
||
-- Clear my previous imported rows
|
||
DELETE FROM asfc_imp_opleiding;
|
||
|
||
FOR rec IN c_cursor
|
||
LOOP
|
||
BEGIN
|
||
v_errorhint := 'Ophalen nieuwe importregel.';
|
||
v_newline := rec.fac_imp_file_line;
|
||
v_aanduiding := v_newline;
|
||
|
||
IF SUBSTR (v_newline, 1, 3) = '?'
|
||
THEN
|
||
-- EF BB BF aangetroffen
|
||
fac.imp_writelog (p_import_key,
|
||
'W',
|
||
'Byte Order Mark aangetroffen',
|
||
'Bestand heeft onbehandeld UTF-8 formaat.');
|
||
v_newline := SUBSTR (v_newline, 4);
|
||
END IF;
|
||
|
||
IF UPPER (v_newline) LIKE
|
||
'PERNR;OMSCHRIJVING;BEGINDATUM;EINDDATUM%'
|
||
THEN
|
||
-- Sla de kopregel over.
|
||
header_found := TRUE;
|
||
ELSIF (header_found)
|
||
THEN
|
||
v_errorhint := 'Inlezen personeelsnummer.';
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_dummy);
|
||
|
||
IF LENGTH (v_dummy) > 16
|
||
THEN
|
||
fac.imp_writelog (
|
||
p_import_key,
|
||
'W',
|
||
'Personeelsnummer afgebroken tot ' || SUBSTR (v_dummy, 1, 16),
|
||
v_aanduiding);
|
||
END IF;
|
||
|
||
v_perslid_nr := SUBSTR (v_dummy, 1, 16);
|
||
|
||
BEGIN
|
||
SELECT prs_perslid_key
|
||
INTO v_perslid_key
|
||
FROM prs_perslid
|
||
WHERE prs_perslid_verwijder IS NULL
|
||
AND prs_perslid_nr = v_perslid_nr;
|
||
EXCEPTION
|
||
WHEN NO_DATA_FOUND
|
||
THEN
|
||
fac.imp_writelog (
|
||
p_import_key,
|
||
'W',
|
||
'Personeelsnummer niet gevonden: ' || v_perslid_nr,
|
||
v_aanduiding);
|
||
v_perslid_key := NULL;
|
||
END;
|
||
|
||
|
||
v_errorhint := 'Omschrijving';
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_dummy);
|
||
|
||
IF LENGTH (v_dummy) > 100
|
||
THEN
|
||
fac.imp_writelog (
|
||
p_import_key,
|
||
'W',
|
||
'Omschrijving afgebroken tot '
|
||
|| SUBSTR (v_dummy, 1, 100),
|
||
v_aanduiding);
|
||
END IF;
|
||
|
||
v_omschrijving := SUBSTR (v_dummy, 1, 100);
|
||
|
||
v_errorhint := 'Inlezen begindatum.';
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_dummy);
|
||
|
||
v_begindatum := fac.safe_to_date(v_dummy, 'dd-mm-yyyy');
|
||
IF v_begindatum IS NULL
|
||
THEN
|
||
fac.imp_writelog (
|
||
p_import_key,
|
||
'W',
|
||
'ongeldige begindatum ' || v_dummy,
|
||
v_aanduiding);
|
||
END IF;
|
||
|
||
v_errorhint := 'Inlezen einddatum.';
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_dummy);
|
||
|
||
v_einddatum := fac.safe_to_date(v_dummy, 'dd-mm-yyyy');
|
||
IF v_begindatum IS NULL
|
||
THEN
|
||
fac.imp_writelog (
|
||
p_import_key,
|
||
'W',
|
||
'ongeldige begindatum ' || v_dummy,
|
||
v_aanduiding);
|
||
END IF;
|
||
|
||
INSERT INTO asfc_imp_opleiding (prs_perslid_nr,
|
||
prs_perslid_key,
|
||
omschrijving,
|
||
begindatum,
|
||
einddatum)
|
||
VALUES (v_perslid_nr,
|
||
v_perslid_key,
|
||
v_omschrijving,
|
||
v_begindatum,
|
||
v_einddatum);
|
||
END IF;
|
||
|
||
COMMIT;
|
||
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.imp_writelog (p_import_key,
|
||
'E',
|
||
SUBSTR (v_errormsg, 1, 1000),
|
||
v_aanduiding);
|
||
|
||
END;
|
||
END LOOP;
|
||
|
||
IF NOT header_found
|
||
THEN
|
||
fac.imp_writelog (p_import_key,
|
||
'E',
|
||
'Geen geldige header aangetroffen',
|
||
'Bestand is geen geldig opleidingen importbestand.');
|
||
END IF;
|
||
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.imp_writelog (p_import_key,
|
||
'E',
|
||
SUBSTR (v_errormsg, 1, 1000),
|
||
v_aanduiding);
|
||
|
||
-- maak de importtabel leeg om te voorkomen dat er halve bestanden ingelezen worden.
|
||
DELETE FROM asfc_imp_opleiding;
|
||
END;
|
||
/
|
||
|
||
CREATE OR REPLACE PROCEDURE asfc_update_opleiding (p_import_key IN NUMBER)
|
||
AS
|
||
CURSOR c
|
||
IS
|
||
SELECT *
|
||
FROM asfc_imp_opleiding
|
||
WHERE prs_perslid_key IS NOT NULL
|
||
ORDER by prs_perslid_key, einddatum desc;
|
||
|
||
v_kenmerk_key NUMBER;
|
||
v_errormsg VARCHAR2 (1000);
|
||
v_error_hint VARCHAR2 (1000);
|
||
oracle_err_mes VARCHAR2 (1000);
|
||
oracle_err_num VARCHAR2 (1000);
|
||
currentversion fac_module.fac_module_version%TYPE;
|
||
BEGIN
|
||
|
||
SELECT MAX (fac_module_version)
|
||
INTO currentversion
|
||
FROM fac_module;
|
||
|
||
fac.imp_writelog (p_import_key,
|
||
'I',
|
||
'ASFC opleiding import version ' || currentversion,
|
||
'$Revision$'
|
||
);
|
||
|
||
FOR rec IN c
|
||
LOOP
|
||
BEGIN
|
||
v_error_hint := rec.prs_perslid_nr || ' - ' || rec.omschrijving || ' - ' || rec.einddatum;
|
||
-- de persoon is al bekend.
|
||
-- nu gaan we op zoek naar de opleiding
|
||
|
||
v_kenmerk_key := NULL;
|
||
CASE UPPER(rec.omschrijving)
|
||
WHEN 'BASIS-VCA' THEN v_kenmerk_key := 1023;
|
||
WHEN 'VOL-VCA' THEN v_kenmerk_key := 1024;
|
||
WHEN 'SVS SCHOONMAAK' THEN v_kenmerk_key := 1025;
|
||
WHEN 'HEFTRUCK' THEN v_kenmerk_key := 1026;
|
||
WHEN 'HOOGWERKER' THEN v_kenmerk_key := 1027;
|
||
END CASE;
|
||
|
||
IF v_kenmerk_key IS NOT NULL
|
||
THEN
|
||
prs.upsertkenmerk (v_kenmerk_key, rec.prs_perslid_key, to_char(rec.einddatum, 'dd-mm-yyyy'));
|
||
END IF;
|
||
|
||
COMMIT;
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
--v_error_hint := v_errormsg;
|
||
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_import_key,
|
||
'E',
|
||
v_errormsg,
|
||
v_error_hint
|
||
);
|
||
COMMIT; -- tbv logging
|
||
END;
|
||
END LOOP;
|
||
|
||
END;
|
||
/
|
||
|
||
|
||
CREATE OR REPLACE VIEW asfc_v_rap_schoonmaak
|
||
(
|
||
fclt_f_gebouw,
|
||
fclt_f_verdieping,
|
||
fclt_f_ruimte,
|
||
fclt_f_element,
|
||
fclt_f_locatieonderdeel,
|
||
fclt_f_werkzaamheden,
|
||
fclt_d_datum,
|
||
fclt_f_resultaat,
|
||
opmerking
|
||
)
|
||
AS
|
||
SELECT alg_gebouw_omschrijving,
|
||
alg_verdieping_omschrijving,
|
||
alg_ruimte_nr,
|
||
ins_deel_omschrijving,
|
||
ins_deel_opmerking,
|
||
ins_srtcontrole_omschrijving,
|
||
TO_CHAR (dsc.ins_deelsrtcontrole_datum_org, 'dd-mm-yyyy'),
|
||
ins_controlemode_oms,
|
||
dsc.ins_deelsrtcontrole_opmerking
|
||
FROM ins_srtcontrole sc,
|
||
ins_deelsrtcontrole dsc,
|
||
ins_v_deel_gegevens dg,
|
||
ins_controlemode cm
|
||
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;
|
||
|
||
|
||
CREATE OR REPLACE VIEW asfc_v_rap_ruimte_bestek
|
||
(
|
||
fclt_f_locatie,
|
||
fclt_f_gebouw,
|
||
verdieping,
|
||
ruimte,
|
||
omschrijving,
|
||
fclt_f_functie,
|
||
opp,
|
||
ruimtegroep,
|
||
fclt_f_locatieonderdeel,
|
||
fclt_f_vloersoort,
|
||
ruimtebestek,
|
||
element,
|
||
fclt_f_werkzaamheden,
|
||
taak,
|
||
periode,
|
||
eenheid,
|
||
ma,
|
||
di,
|
||
wo,
|
||
do,
|
||
vr,
|
||
za,
|
||
zo,
|
||
nf,
|
||
rangorde
|
||
)
|
||
AS
|
||
SELECT alg_locatie_code,
|
||
alg_gebouw_upper,
|
||
alg_verdieping_code,
|
||
'_' || alg_ruimte_nr,
|
||
alg_ruimte_omschrijving,
|
||
alg_srtruimte_omschrijving,
|
||
alg_ruimte_bruto_vloeropp,
|
||
(SELECT alg_onrgoedkenmerk_waarde
|
||
FROM alg_onrgoedkenmerk
|
||
WHERE alg_kenmerk_key = 1020 AND alg_onrgoed_key = alg_ruimte_key)
|
||
ruimtegroep, -- kk 1020
|
||
(SELECT alg_onrgoedkenmerk_waarde
|
||
FROM alg_onrgoedkenmerk
|
||
WHERE alg_kenmerk_key = 1021 AND alg_onrgoed_key = alg_ruimte_key)
|
||
locatieonderdeel, -- kk 1021
|
||
(SELECT fac_usrdata_omschr
|
||
FROM fac_usrdata u, alg_onrgoedkenmerk
|
||
WHERE fac.safe_to_number (alg_onrgoedkenmerk_waarde) =
|
||
fac_usrdata_key
|
||
AND alg_kenmerk_key = 2
|
||
AND alg_onrgoed_key = alg_ruimte_key)
|
||
vloersoort, -- kk2
|
||
(SELECT alg_onrgoedkenmerk_waarde
|
||
FROM alg_onrgoedkenmerk
|
||
WHERE alg_kenmerk_key = 1023 AND alg_onrgoed_key = alg_ruimte_key)
|
||
ruimtenummerbestek, -- kk 1023
|
||
ins_deel_omschrijving,
|
||
a.ins_srtcontrole_omschrijving,
|
||
c.ins_srtcontroledl_xcp_groep,
|
||
c.ins_srtcontroledl_xcp_periode periode,
|
||
DECODE (c.ins_srtcontroledl_xcp_eenheid, 1, 'd', 2, 'w', 3, 'm', 4, 'j') eenheid,
|
||
DECODE (BITAND (c.ins_srtcontroledl_xcp_bits, 2), 0, '', '1') ma,
|
||
DECODE (BITAND (c.ins_srtcontroledl_xcp_bits, 4), 0, '', '1') di,
|
||
DECODE (BITAND (c.ins_srtcontroledl_xcp_bits, 8), 0, '', '1') wo,
|
||
DECODE (BITAND (c.ins_srtcontroledl_xcp_bits, 16), 0, '', '1') do,
|
||
DECODE (BITAND (c.ins_srtcontroledl_xcp_bits, 32), 0, '', '1') vr,
|
||
DECODE (BITAND (c.ins_srtcontroledl_xcp_bits, 64), 0, '', '1') za,
|
||
DECODE (BITAND (c.ins_srtcontroledl_xcp_bits, 1), 0, '', '1') zo,
|
||
DECODE (BITAND (c.ins_srtcontroledl_xcp_bits, 128), 0, '', '1') nf,
|
||
BITAND (c.ins_srtcontroledl_xcp_bits, 1792)/256 rangorde
|
||
FROM alg_v_ruimte_gegevens r,
|
||
ins_deel d,
|
||
ins_srtcontroledl_xcp c,
|
||
ins_srtcontrole a
|
||
WHERE r.alg_ruimte_key = d.ins_alg_ruimte_key
|
||
AND d.ins_deel_key = c.ins_deel_key
|
||
AND c.ins_srtcontrole_key = a.ins_srtcontrole_key;
|
||
|
||
CREATE OR REPLACE VIEW asfc_v_rap_imp_bestek
|
||
(
|
||
fclt_f_locatiecode,
|
||
fclt_f_gebouwcode,
|
||
bouwlaagvolgnummer,
|
||
ruimtenummer,
|
||
elementsoort,
|
||
activiteit,
|
||
element,
|
||
taak,
|
||
freq_aantal,
|
||
freq_periode,
|
||
ma,
|
||
di,
|
||
wo,
|
||
do,
|
||
vr,
|
||
za,
|
||
zo,
|
||
nf,
|
||
rangorde
|
||
)
|
||
AS
|
||
SELECT fclt_f_locatie,
|
||
fclt_f_gebouw,
|
||
verdieping,
|
||
ruimte,
|
||
'Schoonmaakobject',
|
||
fclt_f_werkzaamheden,
|
||
SUBSTR (element, INSTR (element, ' - ') + 3) element,
|
||
taak,
|
||
periode,
|
||
eenheid,
|
||
ma,
|
||
di,
|
||
wo,
|
||
do,
|
||
vr,
|
||
za,
|
||
zo,
|
||
nf,
|
||
rangorde
|
||
FROM asfc_v_rap_ruimte_bestek;
|
||
|
||
CREATE OR REPLACE VIEW asfc_v_rap_imp_bestek_dif
|
||
(
|
||
ruimte,
|
||
fclt_f_werkzaamheden,
|
||
periode,
|
||
eenheid,
|
||
bits,
|
||
taak,
|
||
opmerking
|
||
)
|
||
AS
|
||
SELECT alg_ruimte_nr,
|
||
ins_srtcontrole_omschrijving,
|
||
ins_srtcontroledl_xcp_periode,
|
||
ins_srtcontroledl_xcp_eenheid,
|
||
ins_srtcontroledl_xcp_bits,
|
||
ins_srtcontroledl_xcp_groep,
|
||
opmerking
|
||
FROM (-- controles die niet in het import bestand voorkomen
|
||
SELECT dg.alg_locatie_key,
|
||
dg.alg_ruimte_nr,
|
||
alg_ruimte_key,
|
||
x.ins_deel_key,
|
||
x.ins_srtcontrole_key,
|
||
x.ins_srtcontroledl_xcp_key,
|
||
ins_srtcontrole_omschrijving,
|
||
ins_srtcontroledl_xcp_periode,
|
||
ins_srtcontroledl_xcp_eenheid,
|
||
ins_srtcontroledl_xcp_bits,
|
||
ins_srtcontroledl_xcp_groep,
|
||
'Te verwijderen bestekregels' opmerking
|
||
FROM ins_srtcontroledl_xcp x,
|
||
ins_v_deel_gegevens dg,
|
||
ins_srtcontrole sc2
|
||
WHERE x.ins_srtcontrole_key = sc2.ins_srtcontrole_key
|
||
AND NOT EXISTS
|
||
(SELECT ins_srtcontrole_key
|
||
FROM ins_deel d,
|
||
asfc_imp_bestek i,
|
||
ins_srtcontrole sc
|
||
WHERE ins_deel_upper =
|
||
SUBSTR (
|
||
UPPER (i.alg_ruimte_nr)
|
||
|| ' - '
|
||
|| UPPER (i.ins_deel_omschrijving),
|
||
1,
|
||
60)
|
||
AND UPPER (ins_srtcontrole_omschrijving) =
|
||
UPPER (i.ins_srtcontrole_groep)
|
||
AND x.ins_deel_key = d.ins_deel_key
|
||
AND x.ins_srtcontrole_key = sc.ins_srtcontrole_key)
|
||
AND x.ins_deel_key = dg.ins_deel_key
|
||
AND dg.alg_locatie_key IN
|
||
(SELECT alg_locatie_key
|
||
FROM alg_v_ruimte_gegevens rg, asfc_imp_bestek i
|
||
WHERE i.alg_ruimte_key = rg.alg_ruimte_key)
|
||
UNION ALL
|
||
-- controles met afwijkende gegevens
|
||
SELECT dg.alg_locatie_key,
|
||
dg.alg_ruimte_nr,
|
||
dg.alg_ruimte_key,
|
||
x.ins_deel_key,
|
||
x.ins_srtcontrole_key,
|
||
x.ins_srtcontroledl_xcp_key,
|
||
ins_srtcontrole_omschrijving,
|
||
x.ins_srtcontroledl_xcp_periode,
|
||
x.ins_srtcontroledl_xcp_eenheid,
|
||
x.ins_srtcontroledl_xcp_bits,
|
||
x.ins_srtcontroledl_xcp_groep,
|
||
DECODE (
|
||
x.ins_srtcontroledl_xcp_periode,
|
||
i.ins_srtcontrole_periode,
|
||
'',
|
||
'Afwijkende periode:'
|
||
|| x.ins_srtcontroledl_xcp_periode
|
||
|| '-'
|
||
|| i.ins_srtcontrole_periode
|
||
|| CHR (13))
|
||
|| DECODE (
|
||
x.ins_srtcontroledl_xcp_eenheid,
|
||
i.ins_srtcontrole_eenheid,
|
||
'',
|
||
'Afwijkende eenheid:'
|
||
|| x.ins_srtcontroledl_xcp_eenheid
|
||
|| '-'
|
||
|| i.ins_srtcontrole_eenheid
|
||
|| CHR (13))
|
||
|| DECODE (
|
||
x.ins_srtcontroledl_xcp_bits,
|
||
i.ins_srtcontrole_bits,
|
||
'',
|
||
'Afwijkend schema:'
|
||
|| asfc.get_bits_str(x.ins_srtcontroledl_xcp_eenheid,x.ins_srtcontroledl_xcp_bits)
|
||
|| '-'
|
||
|| asfc.get_bits_str(i.ins_srtcontrole_eenheid, i.ins_srtcontrole_bits)
|
||
|| CHR (13))
|
||
|| DECODE (
|
||
x.ins_srtcontroledl_xcp_groep,
|
||
i.ins_srtcontroledl_xcp_groep,
|
||
'',
|
||
'Afwijkende taak:'
|
||
|| x.ins_srtcontroledl_xcp_groep
|
||
|| '-'
|
||
|| i.ins_srtcontroledl_xcp_groep
|
||
|| CHR (13))
|
||
FROM ins_srtcontroledl_xcp x,
|
||
ins_v_deel_gegevens dg,
|
||
asfc_imp_bestek i,
|
||
ins_srtcontrole sc
|
||
WHERE ins_deel_upper =
|
||
SUBSTR (
|
||
UPPER (i.alg_ruimte_nr)
|
||
|| ' - '
|
||
|| UPPER (i.ins_deel_omschrijving),
|
||
1,
|
||
60)
|
||
AND UPPER (ins_srtcontrole_omschrijving) =
|
||
UPPER (i.ins_srtcontrole_groep)
|
||
AND x.ins_deel_key = dg.ins_deel_key
|
||
AND x.ins_srtcontrole_key = sc.ins_srtcontrole_key
|
||
AND x.ins_deel_key = dg.ins_deel_key
|
||
AND (COALESCE (x.ins_srtcontroledl_xcp_periode, -1) <>
|
||
COALESCE (i.ins_srtcontrole_periode, -1)
|
||
OR COALESCE (x.ins_srtcontroledl_xcp_eenheid, -1) <>
|
||
COALESCE (i.ins_srtcontrole_eenheid, -1)
|
||
OR COALESCE (x.ins_srtcontroledl_xcp_bits, -1) <>
|
||
COALESCE (i.ins_srtcontrole_bits, -1)
|
||
OR COALESCE (x.ins_srtcontroledl_xcp_groep, 'x') <>
|
||
COALESCE (i.ins_srtcontroledl_xcp_groep, 'x'))
|
||
AND dg.alg_locatie_key IN
|
||
(SELECT alg_locatie_key
|
||
FROM alg_v_ruimte_gegevens rg, asfc_imp_bestek i
|
||
WHERE i.alg_ruimte_key = rg.alg_ruimte_key)
|
||
UNION ALL
|
||
-- regels uit het importbestand die nog niet in FACILITOR staan
|
||
SELECT rg.alg_locatie_key,
|
||
rg.alg_ruimte_nr,
|
||
i.alg_ruimte_key,
|
||
NULL,
|
||
NULL,
|
||
NULL,
|
||
i.ins_srtcontrole_groep,
|
||
i.ins_srtcontrole_periode,
|
||
i.ins_srtcontrole_eenheid,
|
||
i.ins_srtcontrole_bits,
|
||
i.ins_srtcontroledl_xcp_groep,
|
||
'Nieuwe bestekregels'
|
||
FROM asfc_imp_bestek i, alg_v_ruimte_gegevens rg
|
||
WHERE i.alg_ruimte_key = rg.alg_ruimte_key
|
||
AND NOT EXISTS
|
||
(SELECT sc.ins_srtcontrole_key
|
||
FROM ins_deel d,
|
||
ins_srtcontrole sc,
|
||
ins_srtcontroledl_xcp x
|
||
WHERE ins_deel_upper =
|
||
SUBSTR (
|
||
UPPER (i.alg_ruimte_nr)
|
||
|| ' - '
|
||
|| UPPER (i.ins_deel_omschrijving),
|
||
1,
|
||
60)
|
||
AND UPPER (ins_srtcontrole_omschrijving) =
|
||
UPPER (i.ins_srtcontrole_groep)
|
||
AND x.ins_deel_key = d.ins_deel_key
|
||
AND x.ins_srtcontrole_key = sc.ins_srtcontrole_key));
|
||
|
||
CREATE OR REPLACE VIEW asfc_v_graph_afw_schoonmaak (
|
||
fclt_xas_,
|
||
fclt_yas_,
|
||
volgorde
|
||
)
|
||
AS
|
||
SELECT DECODE (SUBSTR (TO_CHAR (ins_deelsrtcontrole_datum_org, 'yyyymm'), 5),
|
||
'01', 'Januari',
|
||
'02', 'Februari',
|
||
'03', 'Maart',
|
||
'04', 'April',
|
||
'05', 'Mei',
|
||
'06', 'Juni',
|
||
'07', 'Juli',
|
||
'08', 'Augustus',
|
||
'09', 'September',
|
||
'10', 'Oktober',
|
||
'11', 'November',
|
||
'December'),
|
||
COUNT (ins_deelsrtcontrole_key),
|
||
TO_CHAR (ins_deelsrtcontrole_datum_org, 'yyyymm')
|
||
FROM ins_deelsrtcontrole sc, ins_controlemode cm
|
||
WHERE sc.ins_controlemode_key = cm.ins_controlemode_key
|
||
AND ins_controlemode_success = 0
|
||
AND ins_deelsrtcontrole_datum_org BETWEEN ADD_MONTHS (
|
||
TO_DATE (
|
||
TO_CHAR (SYSDATE, 'yyyymm') || '01',
|
||
'yyyymmdd'),
|
||
-11)
|
||
AND SYSDATE
|
||
AND ins_deelsrtcontrole_datum_org > TO_DATE ('20140101', 'yyyymmdd')
|
||
GROUP BY TO_CHAR (ins_deelsrtcontrole_datum_org, 'yyyymm');
|
||
|
||
|
||
CREATE OR REPLACE VIEW asfc_v_graph_regie_schoonmaak (
|
||
fclt_xas_,
|
||
fclt_yas_,
|
||
volgorde
|
||
)
|
||
AS
|
||
SELECT DECODE (SUBSTR (TO_CHAR (mld_melding_datum, 'yyyymm'), 5),
|
||
'01', 'Januari',
|
||
'02', 'Februari',
|
||
'03', 'Maart',
|
||
'04', 'April',
|
||
'05', 'Mei',
|
||
'06', 'Juni',
|
||
'07', 'Juli',
|
||
'08', 'Augustus',
|
||
'09', 'September',
|
||
'10', 'Oktober',
|
||
'11', 'November',
|
||
'December'),
|
||
COUNT (mld_melding_key),
|
||
TO_CHAR (mld_melding_datum, 'yyyymm')
|
||
FROM mld_melding m, mld_stdmelding std, ins_tab_discipline d
|
||
WHERE mld_melding_datum BETWEEN ADD_MONTHS (
|
||
TO_DATE (
|
||
TO_CHAR (SYSDATE, 'yyyymm') || '01',
|
||
'yyyymmdd'),
|
||
-11)
|
||
AND SYSDATE
|
||
AND mld_melding_datum > TO_DATE ('20131001', 'yyyymmdd')
|
||
AND m.mld_stdmelding_key = std.mld_stdmelding_key
|
||
AND std.mld_ins_discipline_key = d.ins_discipline_key
|
||
AND d.ins_srtdiscipline_key = 1 -- Regie
|
||
GROUP BY TO_CHAR (mld_melding_datum, 'yyyymm');
|
||
|
||
|
||
CREATE OR REPLACE VIEW asfc_v_noti_opleidingen
|
||
(
|
||
sender,
|
||
receiver,
|
||
text,
|
||
code,
|
||
fac_srtnotificatie_key,
|
||
key,
|
||
xkey,
|
||
xemail,
|
||
xmobile
|
||
)
|
||
AS
|
||
SELECT NULL sender,
|
||
fac.safe_to_number (kla.prs_kenmerklink_waarde) receiver,
|
||
'Het certificaat van: '
|
||
|| pf.prs_perslid_naam_full
|
||
|| ' voor de opleiding '
|
||
|| k.prs_kenmerk_omschrijving
|
||
|| ' is nog maar <20><>n maand geldig. ',
|
||
'PRSINF' code,
|
||
NULL fac_srtnotificatie_key,
|
||
p.prs_perslid_key key,
|
||
NULL xkey,
|
||
NULL xemail,
|
||
NULL xmobile
|
||
FROM prs_kenmerklink kl,
|
||
prs_kenmerk k,
|
||
prs_perslid p,
|
||
prs_kenmerklink kla,
|
||
prs_v_perslid_fullnames pf
|
||
WHERE kl.prs_kenmerk_key = k.prs_kenmerk_key
|
||
AND k.prs_kenmerk_kenmerktype = 'D'
|
||
AND k.prs_kenmerk_niveau = 'P'
|
||
AND kl.prs_link_key = p.prs_perslid_key
|
||
AND p.prs_perslid_key = pf.prs_perslid_key
|
||
AND p.prs_afdeling_key = kla.prs_link_key
|
||
AND kla.prs_kenmerk_key = 1040 -- leidinggevende
|
||
AND fac.safe_to_date (kl.prs_kenmerklink_waarde, 'dd-mm-yyyy') =
|
||
ADD_MONTHS (TRUNC (SYSDATE), 1);
|
||
|
||
-- overzicht van schoonmaakactiviteiten die vandaag uitgevoerd moeten worden.
|
||
CREATE OR REPLACE VIEW asfc_v_taaklijst_basis
|
||
(
|
||
identificatie,
|
||
locatieeenheid,
|
||
werkzaamheden,
|
||
taak,
|
||
ruimtenr_bestek,
|
||
eenheid,
|
||
i_next,
|
||
i_nextnext,
|
||
i_nextnextnext
|
||
)
|
||
AS
|
||
SELECT d.ins_deel_omschrijving,
|
||
d.ins_deel_opmerking,
|
||
ins_srtcontrole_omschrijving,
|
||
xcp.ins_srtcontroledl_xcp_groep,
|
||
( SELECT alg_onrgoedkenmerk_waarde
|
||
FROM alg_onrgoedkenmerk
|
||
WHERE alg_kenmerk_key = 1023
|
||
AND alg_onrgoed_key = d.ins_alg_ruimte_key),
|
||
xcp.ins_srtcontroledl_xcp_eenheid,
|
||
fac.nextcyclusdate (
|
||
COALESCE (last_i.ins_deelsrtcontrole_datum_org,
|
||
d.ins_deel_aanmaak),
|
||
sc.ins_srtcontrole_mode,
|
||
xcp.ins_srtcontroledl_xcp_eenheid,
|
||
xcp.ins_srtcontroledl_xcp_periode,
|
||
xcp.ins_srtcontroledl_xcp_bits,
|
||
1)
|
||
inspectie_next,
|
||
fac.nextcyclusdate (
|
||
fac.nextcyclusdate (
|
||
COALESCE (last_i.ins_deelsrtcontrole_datum_org,
|
||
d.ins_deel_aanmaak),
|
||
sc.ins_srtcontrole_mode,
|
||
xcp.ins_srtcontroledl_xcp_eenheid,
|
||
xcp.ins_srtcontroledl_xcp_periode,
|
||
xcp.ins_srtcontroledl_xcp_bits,
|
||
1),
|
||
sc.ins_srtcontrole_mode,
|
||
xcp.ins_srtcontroledl_xcp_eenheid,
|
||
xcp.ins_srtcontroledl_xcp_periode,
|
||
xcp.ins_srtcontroledl_xcp_bits,
|
||
1)
|
||
inspectie_nextnext,
|
||
fac.nextcyclusdate (
|
||
fac.nextcyclusdate (
|
||
fac.nextcyclusdate (
|
||
COALESCE (last_i.ins_deelsrtcontrole_datum_org,
|
||
d.ins_deel_aanmaak),
|
||
sc.ins_srtcontrole_mode,
|
||
xcp.ins_srtcontroledl_xcp_eenheid,
|
||
xcp.ins_srtcontroledl_xcp_periode,
|
||
xcp.ins_srtcontroledl_xcp_bits,
|
||
1),
|
||
sc.ins_srtcontrole_mode,
|
||
xcp.ins_srtcontroledl_xcp_eenheid,
|
||
xcp.ins_srtcontroledl_xcp_periode,
|
||
xcp.ins_srtcontroledl_xcp_bits,
|
||
1),
|
||
sc.ins_srtcontrole_mode,
|
||
xcp.ins_srtcontroledl_xcp_eenheid,
|
||
xcp.ins_srtcontroledl_xcp_periode,
|
||
xcp.ins_srtcontroledl_xcp_bits,
|
||
1)
|
||
inspectie_nextnextnext
|
||
FROM ins_deel d,
|
||
ins_srtcontroledl_xcp xcp,
|
||
ins_srtcontrole sc,
|
||
( SELECT xcp1.ins_srtcontroledl_xcp_key,
|
||
MAX (ins_deelsrtcontrole_datum_org)
|
||
ins_deelsrtcontrole_datum_org
|
||
FROM ins_deelsrtcontrole dc, ins_srtcontroledl_xcp xcp1
|
||
WHERE xcp1.ins_deel_key = dc.ins_deel_key
|
||
AND xcp1.ins_srtcontrole_key = dc.ins_srtcontrole_key
|
||
GROUP BY xcp1.ins_srtcontroledl_xcp_key) last_i
|
||
WHERE d.ins_deel_key = xcp.ins_deel_key
|
||
AND xcp.ins_srtcontrole_key = sc.ins_srtcontrole_key
|
||
AND xcp.ins_srtcontroledl_xcp_key = last_i.ins_srtcontroledl_xcp_key(+)
|
||
AND d.ins_deel_verwijder IS NULL;
|
||
|
||
|
||
CREATE OR REPLACE VIEW asfc_v_rap_taaklijst
|
||
(
|
||
identificatie,
|
||
locatieeenheid,
|
||
ruimtenr_bestek,
|
||
inspectiedatum,
|
||
werkzaamheden,
|
||
fclt_f_taak
|
||
)
|
||
AS
|
||
SELECT identificatie,
|
||
locatieeenheid,
|
||
ruimtenr_bestek,
|
||
TO_CHAR(i_next, 'dd-mm-yyyy'),
|
||
werkzaamheden,
|
||
taak
|
||
FROM asfc_v_taaklijst_basis b
|
||
WHERE TRUNC(i_next) <= TRUNC(sysdate);
|
||
|
||
CREATE OR REPLACE VIEW asfc_v_rap_taaklijst_plus1
|
||
(
|
||
identificatie,
|
||
locatieeenheid,
|
||
ruimtenr_bestek,
|
||
inspectiedatum,
|
||
werkzaamheden,
|
||
fclt_f_taak
|
||
)
|
||
AS
|
||
SELECT identificatie,
|
||
locatieeenheid,
|
||
ruimtenr_bestek,
|
||
TO_CHAR(SYSDATE+1, 'dd-mm-yyyy'),
|
||
werkzaamheden,
|
||
taak
|
||
FROM asfc_v_taaklijst_basis b
|
||
WHERE TRUNC(i_next) = TRUNC(sysdate+1)
|
||
OR TRUNC(i_nextnext) = TRUNC(sysdate+1);
|
||
|
||
CREATE OR REPLACE VIEW asfc_v_rap_taaklijst_plus2
|
||
(
|
||
identificatie,
|
||
locatieeenheid,
|
||
ruimtenr_bestek,
|
||
inspectiedatum,
|
||
werkzaamheden,
|
||
fclt_f_taak
|
||
)
|
||
AS
|
||
SELECT identificatie,
|
||
locatieeenheid,
|
||
ruimtenr_bestek,
|
||
TO_CHAR(SYSDATE+2, 'dd-mm-yyyy'),
|
||
werkzaamheden,
|
||
taak
|
||
FROM asfc_v_taaklijst_basis b
|
||
WHERE TRUNC(i_next) = TRUNC(sysdate+2)
|
||
OR TRUNC(i_nextnext) = TRUNC(sysdate+2)
|
||
OR TRUNC(i_nextnextnext) = TRUNC(sysdate+2);
|
||
|
||
CREATE OR REPLACE VIEW asfc_v_rap_taaklijst_lf
|
||
(
|
||
identificatie,
|
||
locatieeenheid,
|
||
ruimtenr_bestek,
|
||
inspectiedatum,
|
||
werkzaamheden,
|
||
fclt_f_taak,
|
||
volgorde
|
||
)
|
||
AS
|
||
SELECT identificatie,
|
||
locatieeenheid,
|
||
ruimtenr_bestek,
|
||
TO_CHAR (i_next, 'dd-mm-yyyy'),
|
||
werkzaamheden,
|
||
taak,
|
||
TO_CHAR (i_next, 'yyyymmdd')
|
||
FROM asfc_v_taaklijst_basis b
|
||
WHERE eenheid > 2;
|
||
|
||
|
||
BEGIN fac.registercustversion('ASFC', 3); END;
|
||
/
|
||
BEGIN adm.systrackscriptId('$Id$', 0); END;
|
||
/
|
||
commit;
|
||
|
||
spool off |