169 lines
6.8 KiB
SQL
169 lines
6.8 KiB
SQL
--
|
|
-- $Id$
|
|
--
|
|
-- ARAI#75066 deel 1: Ingelezen records muteren zodat deze onder de bestaande objectenstructuur passen.
|
|
-- Vervolgens eventuele spaties weg trimmen en de import tabel voor objecten leeg maken.
|
|
-- Daarna de fac_imp_ins tabel leeg maken en vullen met de ingelezen data uit de CSV.
|
|
--
|
|
DEFINE thisfile = 'ARAI#75066-1.SQL'
|
|
DEFINE dbuser = 'ARAI'
|
|
|
|
SET ECHO ON
|
|
SET DEFINE ON
|
|
COLUMN fcltlogfile NEW_VALUE fcltlogfile NOPRINT;
|
|
COLUMN fcltcusterr NEW_VALUE fcltcusterr NOPRINT;
|
|
WHENEVER SQLERROR CONTINUE;
|
|
SELECT adm.getscriptspoolfile('&thisfile') AS fcltlogfile FROM DUAL;
|
|
SPOOL &fcltlogfile
|
|
WHENEVER SQLERROR EXIT;
|
|
SELECT adm.checkscriptcust('&dbuser') AS fcltcusterr FROM DUAL;
|
|
WHENEVER SQLERROR CONTINUE;
|
|
PROMPT &fcltcusterr
|
|
SET DEFINE OFF
|
|
|
|
------ payload begin ------
|
|
DECLARE
|
|
|
|
CURSOR c1 IS
|
|
SELECT DISTINCT i.ins_discipline_omschrijving
|
|
FROM ins_discipline i, fac_imp_csv f
|
|
WHERE SUBSTR (f.fac_imp_csv_col06, 1, 2) =
|
|
SUBSTR (i.ins_discipline_omschrijving, 1, 2)
|
|
AND i.ins_discipline_verwijder IS NULL;
|
|
|
|
CURSOR c2 IS
|
|
SELECT DISTINCT i.ins_srtgroep_omschrijving
|
|
FROM ins_srtgroep i, fac_imp_csv f
|
|
WHERE SUBSTR (f.fac_imp_csv_col07, 1, 4) =
|
|
SUBSTR (i.ins_srtgroep_omschrijving, 1, 4)
|
|
AND i.ins_srtgroep_verwijder IS NULL;
|
|
|
|
CURSOR c3 IS
|
|
SELECT DISTINCT i.ins_srtdeel_code, i.ins_srtdeel_omschrijving
|
|
FROM ins_srtdeel i, fac_imp_csv f
|
|
WHERE f.fac_imp_csv_col08 = i.ins_srtdeel_code
|
|
AND i.ins_srtdeel_verwijder IS NULL;
|
|
|
|
BEGIN
|
|
-- Behouden disciplines
|
|
FOR rec IN c1
|
|
LOOP
|
|
BEGIN
|
|
UPDATE fac_imp_csv
|
|
SET fac_imp_csv_col06 = rec.ins_discipline_omschrijving
|
|
WHERE SUBSTR (fac_imp_csv_col06, 1, 2) =
|
|
SUBSTR (rec.ins_discipline_omschrijving, 1, 2);
|
|
END;
|
|
END LOOP;
|
|
|
|
-- Behouden groepen
|
|
FOR rec IN c2
|
|
LOOP
|
|
BEGIN
|
|
UPDATE fac_imp_csv
|
|
SET fac_imp_csv_col07 = rec.ins_srtgroep_omschrijving
|
|
WHERE SUBSTR (fac_imp_csv_col07, 1, 4) =
|
|
SUBSTR (rec.ins_srtgroep_omschrijving, 1, 4);
|
|
END;
|
|
END LOOP;
|
|
|
|
-- Behouden objectsoorten
|
|
FOR rec IN c3
|
|
LOOP
|
|
BEGIN
|
|
UPDATE fac_imp_csv
|
|
SET fac_imp_csv_col08 = rec.ins_srtdeel_code,
|
|
fac_imp_csv_col09 = rec.ins_srtdeel_omschrijving
|
|
WHERE fac_imp_csv_col08 = rec.ins_srtdeel_code;
|
|
END;
|
|
END LOOP;
|
|
|
|
UPDATE fac_imp_csv
|
|
SET FAC_IMP_CSV_COL06 = TRIM (FAC_IMP_CSV_COL06),
|
|
FAC_IMP_CSV_COL07 = TRIM (FAC_IMP_CSV_COL07),
|
|
FAC_IMP_CSV_COL08 = TRIM (FAC_IMP_CSV_COL08),
|
|
FAC_IMP_CSV_COL09 = TRIM (FAC_IMP_CSV_COL09),
|
|
FAC_IMP_CSV_COL10 = TRIM (FAC_IMP_CSV_COL10);
|
|
|
|
-- Voor het verwerken eerst de import tabel leeg maken
|
|
DELETE FROM fac_imp_ins;
|
|
|
|
-- Plaats de data uit de csv file in de fac_imp_ins tabel
|
|
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_deel_aantal,
|
|
ins_kenmerkwaarde1,
|
|
ins_kenmerkwaarde2,
|
|
ins_kenmerkwaarde3,
|
|
ins_kenmerkwaarde4,
|
|
ins_deel_aanmaak)
|
|
SELECT DISTINCT fac_imp_csv_col06, -- ins_discipline_omschrijving
|
|
fac_imp_csv_col07, -- ins_srtgroep_omschrijving
|
|
fac_imp_csv_col08, -- ins_srtdeel_code
|
|
fac_imp_csv_col09, -- ins_srtdeel_omschrijving
|
|
fac_imp_csv_col13 || fac_imp_csv_col01, -- ins_deel_omschrijving
|
|
fac_imp_csv_col10, -- ins_deel_opmerking
|
|
'RAI', -- alg_locatie_code
|
|
g.alg_gebouw_upper, -- alg_gebouw_upper
|
|
(SELECT MAX (alg_verdieping_volgnr) -- Verdieping
|
|
FROM alg_v_ruimte_gegevens rg
|
|
WHERE rg.alg_ruimte_nr = 'ONB1'
|
|
AND rg.alg_gebouw_key = g.alg_gebouw_key),
|
|
(SELECT MAX (alg_ruimte_nr) -- Ruimte
|
|
FROM alg_v_ruimte_gegevens rg
|
|
WHERE rg.alg_ruimte_nr = 'ONB1'
|
|
AND rg.alg_gebouw_key = g.alg_gebouw_key),
|
|
fac.safe_to_number (REPLACE (fac_imp_csv_col11, ',', '.')), -- aantal object
|
|
|
|
-- Kenmerken ook meenemen
|
|
DECODE (fac_imp_csv_col23,
|
|
NULL, NULL,
|
|
'Type|0=' || fac_imp_csv_col23), -- Type
|
|
DECODE (fac_imp_csv_col24,
|
|
NULL, NULL,
|
|
'Fabricaat|0=' || fac_imp_csv_col24), -- Fabricaat
|
|
DECODE (fac_imp_csv_col26,
|
|
NULL, NULL,
|
|
'Capaciteit|0=' || fac_imp_csv_col26), -- Capaciteit
|
|
DECODE (fac_imp_csv_col88,
|
|
NULL, NULL,
|
|
'Extra|0=' || fac_imp_csv_col88), -- Extra omschrijving
|
|
DECODE (
|
|
fac_imp_csv_col25,
|
|
NULL, SYSDATE,
|
|
COALESCE (
|
|
fac.safe_to_date ('0101' || fac_imp_csv_col25, 'ddmmyyyy'),
|
|
SYSDATE))
|
|
FROM fac_imp_csv, alg_gebouw g
|
|
WHERE UPPER (fac_imp_csv_col03) = UPPER(g.alg_gebouw_naam)
|
|
AND fac_imp_csv_col01 NOT LIKE '%"%';
|
|
|
|
-- Nog even zeker weten dat er geen spaties zijn meegekomen
|
|
|
|
UPDATE fac_imp_ins SET ins_discipline_omschrijving = TRIM (ins_discipline_omschrijving),
|
|
ins_srtgroep_omschrijving = TRIM (ins_srtgroep_omschrijving),
|
|
ins_srtdeel_code = TRIM (ins_srtdeel_code),
|
|
ins_srtdeel_omschrijving = TRIM (ins_srtdeel_omschrijving);
|
|
|
|
END;
|
|
/
|
|
|
|
------ payload end ------
|
|
|
|
SET DEFINE OFF
|
|
BEGIN adm.systrackscriptId ('$Id$', 1); END;
|
|
/
|
|
|
|
COMMIT;
|
|
SET ECHO OFF
|
|
SPOOL OFF
|
|
SET DEFINE ON
|
|
PROMPT Logfile of this upgrade is: &fcltlogfile |