PLGR#81652 -- Implementatie Plieger
svn path=/Customer/trunk/; revision=64730
This commit is contained in:
431
PLGR/PLGR.sql
Normal file
431
PLGR/PLGR.sql
Normal file
@@ -0,0 +1,431 @@
|
||||
--
|
||||
-- $Id$
|
||||
--
|
||||
|
||||
DEFINE thisfile = 'PLGR.SQL'
|
||||
DEFINE dbuser = 'PLGR'
|
||||
|
||||
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 PACKAGE PLGR
|
||||
--AS
|
||||
|
||||
|
||||
|
||||
|
||||
--END;
|
||||
--/
|
||||
|
||||
--CREATE OR REPLACE PACKAGE BODY PLGR
|
||||
--AS
|
||||
|
||||
|
||||
|
||||
|
||||
--END;
|
||||
--/
|
||||
|
||||
-- Import routines
|
||||
CREATE OR REPLACE PROCEDURE PLGR_IMPORT_TAKEN (p_import_key IN NUMBER)
|
||||
AS
|
||||
CURSOR obj
|
||||
IS
|
||||
SELECT fac_imp_csv_key fac_imp_csv_key,
|
||||
fac_imp_csv_col06 ins_deel_omschrijving,
|
||||
fac_imp_csv_col07 taak_omschrijving,
|
||||
fac_imp_csv_col08 taak_cyclus,
|
||||
fac_imp_csv_col09 taak_cyclus_eenheid,
|
||||
fac_imp_csv_col10 taak_datum,
|
||||
fac_imp_csv_col11 taak_categorie,
|
||||
fac_imp_csv_col12 taak_kosten
|
||||
FROM fac_imp_csv
|
||||
WHERE fac_import_key=p_import_key;
|
||||
|
||||
|
||||
v_ins_deel_key NUMBER;
|
||||
|
||||
|
||||
BEGIN
|
||||
|
||||
fac_import_genericcsv(p_import_key);
|
||||
|
||||
FOR rec in obj
|
||||
LOOP
|
||||
|
||||
IF (LENGTH(rec.taak_datum)>1
|
||||
AND LENGTH(rec.taak_cyclus)>=1
|
||||
AND LENGTH(rec.taak_categorie)>1)
|
||||
THEN
|
||||
BEGIN
|
||||
SELECT ins_deel_key INTO v_ins_deel_key
|
||||
FROM ins_deel i
|
||||
WHERE i.ins_deel_omschrijving=rec.ins_deel_omschrijving
|
||||
AND i.ins_deel_verwijder IS NULL;
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND THEN
|
||||
v_ins_deel_key := -1;
|
||||
END;
|
||||
IF v_ins_deel_key=-1
|
||||
THEN
|
||||
fac.imp_writelog (p_import_key,
|
||||
'W',
|
||||
'Object '||rec.ins_deel_omschrijving||' niet gevonden',
|
||||
'Regel wordt overgeslagen');
|
||||
DELETE
|
||||
FROM fac_imp_csv
|
||||
WHERE fac_imp_csv_key = rec.fac_imp_csv_key
|
||||
AND fac_import_key=p_import_key;
|
||||
END IF;
|
||||
|
||||
ELSE
|
||||
fac.imp_writelog (p_import_key,
|
||||
'W',
|
||||
'De aangeleverde regel voor object '||rec.ins_deel_omschrijving|| ' voldoet niet',
|
||||
'Regel wordt overgeslagen');
|
||||
DELETE
|
||||
FROM fac_imp_csv
|
||||
WHERE fac_imp_csv_key = rec.fac_imp_csv_key
|
||||
AND fac_import_key=p_import_key;
|
||||
END IF;
|
||||
|
||||
|
||||
|
||||
END LOOP;
|
||||
END;
|
||||
/
|
||||
|
||||
|
||||
CREATE OR REPLACE PROCEDURE PLGR_UPDATE_TAKEN(p_import_key IN NUMBER)
|
||||
AS
|
||||
|
||||
CURSOR obj
|
||||
IS
|
||||
SELECT fac_imp_csv_key fac_imp_csv_key,
|
||||
fac_imp_csv_col06 ins_deel_omschrijving,
|
||||
fac_imp_csv_col07 taak_omschrijving,
|
||||
fac_imp_csv_col08 taak_cyclus,
|
||||
fac_imp_csv_col09 taak_cyclus_eenheid,
|
||||
fac_imp_csv_col10 taak_datum,
|
||||
fac_imp_csv_col11 taak_categorie,
|
||||
fac_imp_csv_col12 taak_kosten
|
||||
FROM fac_imp_csv
|
||||
WHERE fac_import_key=p_import_key;
|
||||
|
||||
v_errormsg VARCHAR2 (1000);
|
||||
v_errorhint VARCHAR2 (1000);
|
||||
v_aanduiding VARCHAR2 (1000);
|
||||
oracle_err_num NUMBER;
|
||||
oracle_err_mes VARCHAR2 (200);
|
||||
|
||||
v_eenheid NUMBER;
|
||||
v_deel_key NUMBER;
|
||||
v_ins_discipine_key NUMBER;
|
||||
v_ins_srtgroep_key NUMBER;
|
||||
v_ins_srtdeel_key NUMBER;
|
||||
v_taak_cyclus NUMBER;
|
||||
|
||||
v_revisie_interval NUMBER;
|
||||
v_onderhoud_interval NUMBER;
|
||||
v_taak_kosten NUMBER;
|
||||
v_taak_datum DATE;
|
||||
v_ins_srtcontrole_niveau VARCHAR2(2);
|
||||
v_srtkenmerk_doc NUMBER;
|
||||
v_taakcat_key NUMBER;
|
||||
v_srtcontrole_key NUMBER;
|
||||
v_srtcontroledl_xcp_key NUMBER;
|
||||
v_taakcat_ismjob NUMBER;
|
||||
|
||||
BEGIN
|
||||
|
||||
|
||||
v_onderhoud_interval:=1;
|
||||
v_deel_key:=-1;
|
||||
v_taak_cyclus :=0;
|
||||
|
||||
BEGIN
|
||||
SELECT ins_srtkenmerk_key
|
||||
INTO v_srtkenmerk_doc
|
||||
FROM ins_srtkenmerk i
|
||||
WHERE i.ins_srtkenmerk_code='DOCUMENTEN'
|
||||
AND i.ins_srtkenmerk_verwijder IS NULL;
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND
|
||||
THEN
|
||||
v_srtkenmerk_doc:=-1;
|
||||
END;
|
||||
FOR rec IN obj
|
||||
LOOP
|
||||
|
||||
v_taak_datum := fac.safe_to_date(rec.taak_datum,'DD-MM-YYYY');
|
||||
IF rec.taak_cyclus_eenheid='3'
|
||||
THEN
|
||||
v_eenheid:=3;
|
||||
ELSIF rec.taak_cyclus_eenheid='4'
|
||||
THEN
|
||||
v_eenheid:=4;
|
||||
ELSIF rec.taak_cyclus_eenheid='2'
|
||||
THEN
|
||||
v_eenheid:=2;
|
||||
END IF;
|
||||
|
||||
--Haal het object, discipine , groep en objectsoort
|
||||
BEGIN
|
||||
v_errormsg :='Ophalen object '||rec.ins_deel_omschrijving;
|
||||
SELECT ins_deel_key, ins_discipline_key, ins_srtgroep_key, ins_srtdeel_key
|
||||
INTO v_deel_key, v_ins_discipine_key, v_ins_srtgroep_key, v_ins_srtdeel_key
|
||||
FROM ins_v_deel_gegevens
|
||||
WHERE ins_deel_omschrijving = rec.ins_deel_omschrijving ;
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND THEN
|
||||
v_deel_key:=-1;
|
||||
END;
|
||||
v_ins_srtcontrole_niveau:='S';
|
||||
IF v_deel_key>0
|
||||
THEN
|
||||
-- Haal taak categorie op indien niet aanwezig maak deze aan.
|
||||
v_errormsg :='Ophalen taakcetegorie '||rec.taak_omschrijving;
|
||||
-- Gaan we eerst check of er onderhoud controles zijn
|
||||
SELECT i.ins_discipline_key, p.ctr_disc_params_ismjob
|
||||
INTO v_taakcat_key, v_taakcat_ismjob
|
||||
FROM ins_tab_discipline i , ctr_disc_params p
|
||||
WHERE i.ins_discipline_module='CTR'
|
||||
AND UPPER(i.ins_discipline_omschrijving) = UPPER(rec.taak_categorie)
|
||||
AND i.ins_discipline_verwijder IS NULL
|
||||
AND p.ctr_ins_discipline_key=i.ins_discipline_key;
|
||||
|
||||
|
||||
IF v_taakcat_ismjob=1 -- MJOB categorien UITZOEKEN HOE IK DAT VANUIT DE DATABSE KAN ACHTERHALEN.
|
||||
THEN
|
||||
v_taak_cyclus:=0;
|
||||
ELSE
|
||||
v_taak_cyclus := fac.safe_to_number(rec.taak_cyclus);
|
||||
END IF;
|
||||
|
||||
BEGIN
|
||||
SELECT ins_srtcontrole_key
|
||||
INTO v_srtcontrole_key
|
||||
FROM ins_srtcontrole
|
||||
where ins_srtinstallatie_key=v_ins_srtdeel_key
|
||||
AND ins_srtcontrole_niveau=v_ins_srtcontrole_niveau
|
||||
AND UPPER(ins_srtcontrole_omschrijving) = UPPER(rec.taak_omschrijving)
|
||||
AND ins_srtcontrole_periode=v_taak_cyclus
|
||||
AND ins_srtcontrole_eenheid=v_eenheid
|
||||
AND ins_srtcontrole_mode=1
|
||||
AND ctr_discipline_key=v_taakcat_key;
|
||||
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND THEN
|
||||
-- ins_srtcontrole is er niet dus maken we hem aan,
|
||||
INSERT INTO ins_srtcontrole (ins_srtinstallatie_key,
|
||||
ins_srtcontrole_niveau,
|
||||
ins_srtcontrole_omschrijving,
|
||||
ins_srtcontrole_periode,
|
||||
ins_srtcontrole_eenheid,
|
||||
ins_srtcontrole_mode,
|
||||
ctr_discipline_key
|
||||
)
|
||||
VALUES (v_ins_srtdeel_key,
|
||||
v_ins_srtcontrole_niveau,
|
||||
SUBSTR(rec.taak_omschrijving,0,60),
|
||||
v_taak_cyclus,
|
||||
v_eenheid,
|
||||
1,
|
||||
v_taakcat_key
|
||||
)
|
||||
RETURNING ins_srtcontrole_key
|
||||
INTO v_srtcontrole_key;
|
||||
IF v_srtkenmerk_doc>0 THEN
|
||||
INSERT INTO ins_kenmerk (
|
||||
ins_srtkenmerk_key,
|
||||
ins_srtinstallatie_key,
|
||||
ins_kenmerk_niveau,
|
||||
ins_kenmerk_bewerkniveau,
|
||||
ins_kenmerk_groep,
|
||||
ins_kenmerk_volgnummer,
|
||||
ins_kenmerk_hint,
|
||||
ins_kenmerk_omschrijving
|
||||
)
|
||||
VALUES (
|
||||
v_srtkenmerk_doc,
|
||||
v_srtcontrole_key,
|
||||
'C',
|
||||
'D',
|
||||
0,
|
||||
10,
|
||||
'',
|
||||
'Documenten'
|
||||
);
|
||||
END IF;
|
||||
END;
|
||||
|
||||
|
||||
|
||||
|
||||
IF v_taakcat_ismjob=1 THEN
|
||||
v_taak_kosten:=COALESCE(fac.safe_to_number(rec.taak_kosten),0);
|
||||
ELSE
|
||||
v_taak_kosten:=0;
|
||||
END IF;
|
||||
|
||||
BEGIN
|
||||
|
||||
SELECT ins_srtcontroledl_xcp_key
|
||||
INTO v_srtcontroledl_xcp_key
|
||||
FROM ins_srtcontroledl_xcp
|
||||
WHERE ins_deel_key=v_deel_key
|
||||
AND ins_srtcontrole_key=v_srtcontrole_key
|
||||
AND ins_srtcontroledl_xcp_eenheid=v_eenheid;
|
||||
|
||||
-- we hebben een xcp record dan updaten we nu alleen de startdatum
|
||||
UPDATE ins_srtcontroledl_xcp
|
||||
SET INS_SRTCONTROLEDL_XCP_STARTDAT=v_taak_datum
|
||||
WHERE ins_srtcontroledl_xcp_key = v_srtcontroledl_xcp_key;
|
||||
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND THEN
|
||||
-- Er is nog geen XCP record dus maken we er 1 met de verwachte startdatum
|
||||
|
||||
|
||||
INSERT INTO ins_srtcontroledl_xcp
|
||||
(ins_srtcontrole_key,
|
||||
ins_deel_key,
|
||||
ins_srtcontroledl_xcp_eenheid,
|
||||
INS_SRTCONTROLEDL_xcp_kosten,
|
||||
INS_SRTCONTROLEDL_XCP_PERIODE,
|
||||
INS_SRTCONTROLEDL_XCP_STARTDAT)
|
||||
VALUES (v_srtcontrole_key,
|
||||
v_deel_key,
|
||||
v_eenheid,
|
||||
v_taak_kosten,
|
||||
v_taak_cyclus,
|
||||
v_taak_datum);
|
||||
END;
|
||||
|
||||
|
||||
|
||||
ELSE
|
||||
fac.imp_writelog (p_import_key,
|
||||
'W',
|
||||
'Object '||rec.ins_deel_omschrijving||' niet gevonden',
|
||||
'Object niet gevonden');
|
||||
END IF;
|
||||
|
||||
|
||||
|
||||
END LOOP;
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND
|
||||
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;
|
||||
/
|
||||
|
||||
-- EXPORTS
|
||||
-- Export View
|
||||
|
||||
-- VIEWS
|
||||
CREATE OR REPLACE VIEW PLGR_V_REGIOMANAGERS
|
||||
(
|
||||
prs_perslid_key,
|
||||
prs_naam
|
||||
)
|
||||
AS
|
||||
SELECT p.prs_perslid_key,
|
||||
p.prs_perslid_naam_friendly
|
||||
FROM prs_v_perslid_fullnames p, prs_kenmerklink pkl, prs_kenmerk pk
|
||||
WHERE pk.prs_kenmerk_code='REGIOMAN'
|
||||
AND pkl.prs_kenmerk_key = pk.prs_kenmerk_key
|
||||
AND pkl.prs_link_key=p.prs_perslid_key
|
||||
AND pkl.prs_kenmerklink_niveau='P';
|
||||
|
||||
CREATE OR REPLACE VIEW PLGR_V_EXPRESSMANAGERS
|
||||
(
|
||||
prs_perslid_key,
|
||||
prs_naam
|
||||
)
|
||||
AS
|
||||
SELECT p.prs_perslid_key,
|
||||
p.prs_perslid_naam_friendly
|
||||
FROM prs_v_perslid_fullnames p, prs_kenmerklink pkl, prs_kenmerk pk
|
||||
WHERE pk.prs_kenmerk_code='EXPRESSMAN'
|
||||
AND pkl.prs_kenmerk_key = pk.prs_kenmerk_key
|
||||
AND pkl.prs_link_key=p.prs_perslid_key
|
||||
AND pkl.prs_kenmerklink_niveau='P';
|
||||
|
||||
CREATE OR REPLACE VIEW PLGR_V_SHOWROOMMANAGERS
|
||||
(
|
||||
prs_perslid_key,
|
||||
prs_naam
|
||||
)
|
||||
AS
|
||||
SELECT p.prs_perslid_key,
|
||||
p.prs_perslid_naam_friendly
|
||||
FROM prs_v_perslid_fullnames p, prs_kenmerklink pkl, prs_kenmerk pk
|
||||
WHERE pk.prs_kenmerk_code='SHOWMAN'
|
||||
AND pkl.prs_kenmerk_key = pk.prs_kenmerk_key
|
||||
AND pkl.prs_link_key=p.prs_perslid_key
|
||||
AND pkl.prs_kenmerklink_niveau='P';
|
||||
|
||||
CREATE OR REPLACE VIEW PLGR_V_BINNENDIENSTMMANAGERS
|
||||
(
|
||||
prs_perslid_key,
|
||||
prs_naam
|
||||
)
|
||||
AS
|
||||
SELECT p.prs_perslid_key,
|
||||
p.prs_perslid_naam_friendly
|
||||
FROM prs_v_perslid_fullnames p, prs_kenmerklink pkl, prs_kenmerk pk
|
||||
WHERE pk.prs_kenmerk_code='BINNENDIENSTMAN'
|
||||
AND pkl.prs_kenmerk_key = pk.prs_kenmerk_key
|
||||
AND pkl.prs_link_key=p.prs_perslid_key
|
||||
AND pkl.prs_kenmerklink_niveau='P';
|
||||
|
||||
CREATE OR REPLACE VIEW PLGR_V_DCMMANAGERS
|
||||
(
|
||||
prs_perslid_key,
|
||||
prs_naam
|
||||
)
|
||||
AS
|
||||
SELECT p.prs_perslid_key,
|
||||
p.prs_perslid_naam_friendly
|
||||
FROM prs_v_perslid_fullnames p, prs_kenmerklink pkl, prs_kenmerk pk
|
||||
WHERE pk.prs_kenmerk_code='DCMAN'
|
||||
AND pkl.prs_kenmerk_key = pk.prs_kenmerk_key
|
||||
AND pkl.prs_link_key=p.prs_perslid_key
|
||||
AND pkl.prs_kenmerklink_niveau='P';
|
||||
|
||||
|
||||
|
||||
------ 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
|
||||
Reference in New Issue
Block a user