Files
Customer/onces/COMMON/FCLT#55024.sql
Erik Groener 8c5a0a93d9 FCLT#55024 Afwijkende INDEX-en in database van diverse klanten
svn path=/Customer/; revision=40462
2019-01-09 14:09:52 +00:00

171 lines
6.5 KiB
SQL

--
-- $Id$
--
-- <<Corrigeren van ontbrekende indexen in verschillende omgevingen>>
DEFINE thisfile = 'FCLT#55024.SQL'
DEFINE dbuser = '*'
SET ECHO ON
SET DEFINE ON
COLUMN fcltlogfile NEW_VALUE fcltlogfile NOPRINT;
WHENEVER SQLERROR EXIT;
SELECT adm.scriptspoolfile('&dbuser', '&thisfile') AS fcltlogfile FROM DUAL;
WHENEVER SQLERROR CONTINUE;
SPOOL &fcltlogfile
SET DEFINE OFF
------ payload begin ------
// Eerst wat tijdelijke procedures definieren voor het zonder errors toevoegen/hernoemen van indexen
CREATE OR REPLACE PROCEDURE tmp_trycreate (n IN VARCHAR2)
AS
stmt VARCHAR2 (1000);
BEGIN
stmt := 'CREATE ' || n;
EXECUTE IMMEDIATE stmt;
DBMS_OUTPUT.put_line ('Successfully created: ' || n);
EXCEPTION
WHEN OTHERS
THEN
IF SQLCODE IN (-901, -904, -942, -1418, -1452, -1918, -2158, -2425, -2427, -4043)
THEN
-- cannot create, voor identifier (column) table, view, index, sequence, object and trigger, constraint
DBMS_OUTPUT.put_line ('Not found, not created: ' || n);
NULL;
ELSIF SQLCODE IN (-955, -1408, -1442, -2261)
THEN
-- object or not-null property already exist
DBMS_OUTPUT.put_line ('Already exists, not created: ' || n);
NULL;
ELSE
raise_application_error (-20001, 'Error trying to CREATE ' || n || ': ' || SQLERRM);
END IF;
END;
/
CREATE OR REPLACE PROCEDURE tmp_tryrename(n_from IN VARCHAR2, n_to IN VARCHAR2)
AS
exec_dml VARCHAR2(500);
BEGIN
exec_dml := 'ALTER '|| n_from ||' RENAME TO '|| n_to;
EXECUTE IMMEDIATE exec_dml;
DBMS_OUTPUT.put_line ('Successfully renamed index to: ' || n_to);
EXCEPTION
WHEN OTHERS
THEN
IF SQLCODE IN (-1418)
THEN
DBMS_OUTPUT.put_line ('Index does not exist: ' || n_from);
NULL;
ELSE
raise_application_error (-20001, 'Error trying to RENAME INDEX ' || n_from || ': ' || SQLERRM);
END IF;
END;
/
CREATE OR REPLACE PROCEDURE tmp_tryrename_pk (tab IN VARCHAR2, name IN VARCHAR2)
AS
old_name VARCHAR2(100);
exec_dml VARCHAR2(500);
BEGIN
-- Zoek de constaint-name van de primary-key op. Deze is dan meestal van type sys_c00....
SELECT constraint_name
INTO old_name
FROM user_constraints
WHERE table_name = UPPER(tab)
AND constraint_type = 'P'; -- constraint_type : Unique, Reference, Check, Primary key
--
exec_dml := 'ALTER TABLE '|| tab ||' RENAME CONSTRAINT '|| old_name ||' TO '|| name;
EXECUTE IMMEDIATE exec_dml;
exec_dml := 'ALTER INDEX '|| old_name ||' RENAME TO '|| name;
EXECUTE IMMEDIATE exec_dml;
DBMS_OUTPUT.put_line ('Successfully renamed to: ' || name);
EXCEPTION
WHEN NO_DATA_FOUND
THEN
DBMS_OUTPUT.put_line ('Table does not exist: ' || tab);
NULL;
WHEN OTHERS
THEN
IF SQLCODE IN (-1403)
THEN
DBMS_OUTPUT.put_line ('Index not found: ' || old_name);
NULL;
ELSIF SQLCODE IN (-2264)
THEN
DBMS_OUTPUT.put_line ('Index already exists: ' || name);
NULL;
ELSE
raise_application_error (-20001, 'Error trying to RENAME TO CONSTRAINT ' || name || ': ' || SQLERRM);
END IF;
END;
/
CREATE OR REPLACE PROCEDURE tmp_tryalter (n IN VARCHAR2)
AS
exec_dml VARCHAR2 (1000);
BEGIN
exec_dml := 'ALTER ' || n;
EXECUTE IMMEDIATE exec_dml;
DBMS_OUTPUT.put_line ('Found, successfully altered: ' || n);
EXCEPTION
WHEN OTHERS
THEN
IF SQLCODE IN (-904, -942, -1418, -2289, -4043, -4080, -2443)
THEN
-- did not exist, voor identifier (column) table, view, index, sequence, object and trigger, constraint
DBMS_OUTPUT.put_line ('Not found, not altered: ' || n);
NULL;
ELSIF SQLCODE IN (-955, -1442, -2261)
THEN
-- object or not-null property already exist
DBMS_OUTPUT.put_line ('Already exists, not altered: ' || n);
NULL;
ELSE
raise_application_error (-20001, 'Error trying to ALTER ' || n || ': ' || SQLERRM);
END IF;
END;
/
BEGIN
adm.trydrop('INDEX prs_i_prs_kostenplaats1');
tmp_trycreate('INDEX aut_i_cp_accesstoken ON aut_client_perslid(aut_client_perslid_accesstoken)');
tmp_trycreate('INDEX aut_i_cp_refreshtkn ON aut_client_perslid(aut_client_perslid_refreshtkn)');
tmp_trycreate('UNIQUE INDEX fac_i_fac_menuitems1 ON fac_menuitems (fac_menuitems_label)');
tmp_trycreate('UNIQUE INDEX fac_i_srtnotificatie_code2 on fac_srtnotificatie(fac_srtnotificatie_key, fac_srtnotificatie_xmlnode)');
tmp_trycreate('UNIQUE INDEX mld_i_opdruren_dagkosten1 ON mld_opdruren_dagkosten(prs_perslid_key, mld_opdruren_dagkosten_datum)');
tmp_trycreate('INDEX bgt_i_bgt_budget ON bgt_budget(ins_discipline_key, bgt_project_key, bgt_kostenrubriek_key, prs_kostensoortgrp_key, prs_kostensoort_key)');
tmp_trycreate('INDEX bgt_i_bgt_disc_params ON bgt_disc_params(bgt_ins_discipline_key)');
tmp_trycreate('INDEX ins_i_ins_deel_note1 ON ins_deel_note(ins_deel_key)');
tmp_trycreate('INDEX mld_i_mld_opdr17 ON mld_opdr(mld_opdr_teverzenden)');
tmp_tryalter('TABLE ins_tab_discipline ADD CONSTRAINT ins_u_ins_discipline_code UNIQUE (ins_discipline_code)');
tmp_tryalter('TABLE mld_srtkenmerk ADD CONSTRAINT mld_u_mld_srtkenmerk_code UNIQUE (mld_srtkenmerk_code)');
tmp_tryalter('TABLE mld_kenmerk ADD CONSTRAINT mld_u_mld_kenmerk_code UNIQUE (mld_kenmerk_code)');
tmp_tryrename('INDEX bgt_bgt_budget_key_van', 'bgt_i_bgt_budget_key_van');
tmp_tryrename('INDEX bgt_bgt_budget_key_naar', 'bgt_i_bgt_budget_key_naar');
tmp_tryrename_pk('imp_log', 'imp_k_imp_log_key');
END;
/
// nu mogen de tijdelijke procedures weer verwijderd worden
DROP PROCEDURE tmp_tryrename_pk;
DROP PROCEDURE tmp_tryrename;
DROP PROCEDURE tmp_trycreate;
------ 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