FZKH#87266 -- Implementatie Import functies AOC
svn path=/Customer/trunk/; revision=68891
This commit is contained in:
459
FZKH/FZKH.sql
Normal file
459
FZKH/FZKH.sql
Normal file
@@ -0,0 +1,459 @@
|
||||
--
|
||||
-- $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_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
|
||||
|
||||
SELECT COUNT(*)
|
||||
INTO v_count
|
||||
FROM prs_perslid p
|
||||
WHERE p.prs_perslid_nr = rec.prs_perslid_matchcode
|
||||
AND p.prs_perslid_verwijder IS NULL
|
||||
AND ( p.prs_perslid_inactief IS NULL
|
||||
OR p.prs_perslid_inactief > SYSDATE);
|
||||
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_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_col37 ins_kenm_leverancier,
|
||||
fac_imp_csv_col38 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
|
||||
FROM fac_imp_csv
|
||||
WHERE fac_import_key=p_import_key
|
||||
ORDER BY fac_imp_csv_key;
|
||||
|
||||
|
||||
v_locatie_code VARCHAR2(10);
|
||||
v_gebouw_code VARCHAR2(10);
|
||||
v_verdieping_nr VARCHAR2(10);
|
||||
v_ruimte_nr VARCHAR2(25);
|
||||
v_huidige_locatie VARCHAR2(50);
|
||||
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:='Locatie|0='||rec.ins_kenm_locatie;
|
||||
ELSE
|
||||
v_huidige_locatie:='';
|
||||
END IF;
|
||||
IF rec.ins_kenm_ruimtenr IS NOT NULL
|
||||
THEN
|
||||
v_huidige_locatie:='Locatie||0='||rec.ins_kenm_ruimtenr||'-'||rec.ins_kenm_ruimtenaam;
|
||||
ELSE
|
||||
v_huidige_locatie:='';
|
||||
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_kenmerkwaarde11,
|
||||
ins_kenmerkwaarde12,
|
||||
ins_kenmerkwaarde13)
|
||||
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_locatie_code,
|
||||
v_gebouw_code,
|
||||
v_verdieping_nr,
|
||||
v_ruimte_nr,
|
||||
'Eigenaar|0='||rec.ins_kenm_eigenaar,
|
||||
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='||rec.ins_kenm_mdd_clas,
|
||||
'Einde Garantie|0='||rec.ins_kenm_garantie,
|
||||
'Status|0='||rec.ins_kenm_status,
|
||||
'Aanschafprijs|0='||rec.ins_kenm_aanschafprijs
|
||||
);
|
||||
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;
|
||||
|
||||
|
||||
v_ins_deel_key NUMBER;
|
||||
v_prs_afdeling_key NUMBER;
|
||||
BEGIN
|
||||
fac_update_ins(p_import_key);
|
||||
|
||||
|
||||
|
||||
-- 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;
|
||||
|
||||
BEGIN
|
||||
SELECT prs_afdeling_key
|
||||
INTO v_prs_afdeling_key
|
||||
FROM prs_afdeling
|
||||
WHERE prs_afdeling_naam = rec.prs_afdeling_code
|
||||
AND prs_afdeling_verwijder IS NULL;
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND THEN
|
||||
v_prs_afdeling_key:=-1;
|
||||
fac.imp_writelog (
|
||||
p_import_key,
|
||||
'W',
|
||||
'Afdeling niet gevonden :'||rec.prs_afdeling_code,'');
|
||||
END;
|
||||
|
||||
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
|
||||
|
||||
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
|
||||
Reference in New Issue
Block a user