PCHS#89787 Facilitor implementatie verbeteren bij contractverlenging
svn path=/Customer/; revision=70659
This commit is contained in:
107
onces/PCHS/PCHS#89787.sql
Normal file
107
onces/PCHS/PCHS#89787.sql
Normal file
@@ -0,0 +1,107 @@
|
||||
--
|
||||
-- $Id$
|
||||
--
|
||||
-- Korte beschrijving wat het script doet
|
||||
-- Script om de gebouwen te koppelen aan andere locaties. Gebouwen vallen nu niet meer onder één locatie. Data
|
||||
--
|
||||
DEFINE thisfile = 'PCHS#89787.SQL'
|
||||
DEFINE dbuser = '^PCHS'
|
||||
|
||||
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 c IS
|
||||
SELECT fac_imp_csv_col01 alg_locatie_code, fac_imp_csv_col02 alg_gebouw_code
|
||||
FROM fac_imp_csv
|
||||
WHERE fac_import_key = (SELECT MAX(fac_import_key) FROM fac_import)
|
||||
AND fac_imp_csv_key <> 1;
|
||||
|
||||
CURSOR cm IS
|
||||
SELECT m.mld_melding_key, aogk.alg_locatie_key
|
||||
FROM mld_melding m, alg_v_allonroerendgoed aogk
|
||||
WHERE mld_alg_onroerendgoed_keys = aogk.alg_onroerendgoed_keys AND m.mld_alg_locatie_key <> aogk.alg_locatie_key;
|
||||
|
||||
CURSOR cd IS
|
||||
SELECT d.ins_deel_key, aogk.alg_locatie_key
|
||||
FROM ins_deel d, alg_v_allonroerendgoed aogk
|
||||
WHERE ins_alg_ruimte_key = aogk.alg_ruimte_key
|
||||
AND ins_alg_ruimte_type = 'R'
|
||||
AND d.ins_alg_locatie_key <> aogk.alg_locatie_key;
|
||||
|
||||
v_locatie_key NUMBER;
|
||||
v_gebouw_key NUMBER;
|
||||
BEGIN
|
||||
FOR rec IN c
|
||||
LOOP
|
||||
BEGIN
|
||||
SELECT alg_locatie_key
|
||||
INTO v_locatie_key
|
||||
FROM alg_locatie l
|
||||
WHERE alg_locatie_verwijder IS NULL AND alg_district_key = 3 AND alg_locatie_code = rec.alg_locatie_code;
|
||||
|
||||
DBMS_OUTPUT.put_line ('Locatie bestaat al: ' || rec.alg_locatie_code);
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND
|
||||
THEN
|
||||
INSERT INTO alg_locatie (alg_district_key, alg_locatie_code, alg_locatie_omschrijving)
|
||||
VALUES (3, rec.alg_locatie_code, rec.alg_locatie_code)
|
||||
RETURNING alg_locatie_key
|
||||
INTO v_locatie_key;
|
||||
END;
|
||||
|
||||
BEGIN
|
||||
SELECT alg_gebouw_key
|
||||
INTO v_gebouw_key
|
||||
FROM alg_gebouw
|
||||
WHERE alg_gebouw_code = rec.alg_gebouw_code AND alg_gebouw_verwijder IS NULL;
|
||||
|
||||
UPDATE alg_gebouw
|
||||
SET alg_locatie_key = v_locatie_key
|
||||
WHERE alg_gebouw_key = v_gebouw_key;
|
||||
EXCEPTION
|
||||
WHEN OTHERS
|
||||
THEN
|
||||
DBMS_OUTPUT.put_line ('Fout bij opzoeken gebouw: ' || rec.alg_gebouw_code);
|
||||
END;
|
||||
END LOOP;
|
||||
|
||||
FOR rec IN cm
|
||||
LOOP
|
||||
UPDATE mld_melding m
|
||||
SET mld_alg_locatie_key = rec.alg_locatie_key
|
||||
WHERE m.mld_melding_key = rec.mld_melding_key;
|
||||
END LOOP;
|
||||
|
||||
FOR rec IN cd
|
||||
LOOP
|
||||
UPDATE ins_deel d
|
||||
SET ins_alg_locatie_key = rec.alg_locatie_key
|
||||
WHERE d.ins_deel_key = rec.ins_deel_key;
|
||||
END LOOP;
|
||||
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
|
||||
Reference in New Issue
Block a user