dbMakeConsistent_oracle.sql 2.8 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263
  1. -- Licensed Materials - Property of IBM
  2. --
  3. -- BI and PM: CM
  4. --
  5. -- (C) Copyright IBM Corp. 2008, 2009
  6. --
  7. -- US Government Users Restricted Rights - Use, duplication or disclosure
  8. -- restricted by GSA ADP Schedule Contract with IBM Corp.
  9. -- Copyright (C) 2008 Cognos ULC, an IBM Company. All rights reserved.
  10. -- Cognos (R) is a trademark of Cognos ULC, (formerly Cognos Incorporated).
  11. create or replace procedure makeCSConsistent as
  12. strsql varchar2(500);
  13. cursor tables is
  14. SELECT a.TABLE_NAME FROM USER_TAB_COLS a, USER_TABLES b WHERE a.COLUMN_NAME = 'CMID' AND a.TABLE_NAME like 'CM%' AND a.TABLE_NAME=b.TABLE_NAME ORDER BY a.TABLE_NAME ASC;
  15. util_cursor integer;
  16. num integer;
  17. begin
  18. util_cursor := DBMS_SQL.OPEN_CURSOR;
  19. FOR tables_row in tables LOOP
  20. strsql := 'delete from '||tables_row.TABLE_NAME||' where CMID not in (select CMID from CMOBJECTS)';
  21. DBMS_SQL.PARSE(util_cursor, strsql, DBMS_SQL.NATIVE);
  22. num := DBMS_SQL.EXECUTE(util_cursor);
  23. END LOOP;
  24. strsql := 'insert into CMOBJNAMES (CMID, LOCALEID, MAPDLOCALEID, ISDEFAULT, NAME) select CMID, 24, 24, 1, concat( ''REPAIRED BY CONSISTENCY CHECK '', RAWTOHEX(SYS_GUID())) from CMOBJECTS where CMID not in (select CMID from CMOBJNAMES)';
  25. DBMS_SQL.PARSE(util_cursor, strsql, DBMS_SQL.NATIVE);
  26. num := DBMS_SQL.EXECUTE(util_cursor);
  27. strsql := 'insert into CMPOLICIES (CMID) select CMID from CMOBJECTS where CMID not in (select CMID from CMPOLICIES)';
  28. DBMS_SQL.PARSE(util_cursor, strsql, DBMS_SQL.NATIVE);
  29. num := DBMS_SQL.EXECUTE(util_cursor);
  30. strsql := 'insert into CMSTOREIDS (CMID, STOREID) select CMID, SUBSTR(''i00000000000000000000000000000000'',1,33 - LENGTH(RTRIM(CAST(CMID AS CHAR(10))))) || RTRIM(CAST(CMID AS CHAR(10))) from CMOBJECTS where CMID not in (select CMID from CMSTOREIDS)';
  31. DBMS_SQL.PARSE(util_cursor, strsql, DBMS_SQL.NATIVE);
  32. num := DBMS_SQL.EXECUTE(util_cursor);
  33. strsql := 'update CMSTOREIDS set STOREID = NULL where UPPER(STOREID) in (select STOREID from (select b.CMID, UPPER(b.STOREID) as STOREID from CMSTOREIDS b) group by STOREID having COUNT(CMID) > 1)';
  34. DBMS_SQL.PARSE(util_cursor, strsql, DBMS_SQL.NATIVE);
  35. num := DBMS_SQL.EXECUTE(util_cursor);
  36. strsql := 'update CMSTOREIDS set STOREID = SUBSTR(''i00000000000000000000000000000000'',1,33 - LENGTH(RTRIM(CAST(CMID AS CHAR(10))))) || RTRIM(CAST(CMID AS CHAR(10))) where CMID in (select CMID from CMSTOREIDS where STOREID is null)';
  37. DBMS_SQL.PARSE(util_cursor, strsql, DBMS_SQL.NATIVE);
  38. num := DBMS_SQL.EXECUTE(util_cursor);
  39. DBMS_SQL.CLOSE_CURSOR(util_cursor);
  40. exception
  41. when others then
  42. if DBMS_SQL.IS_OPEN(util_cursor) then
  43. DBMS_SQL.CLOSE_CURSOR(util_cursor);
  44. end if;
  45. raise_application_error(-20000, 'Unknown Exception Raised: '||sqlcode||' '||sqlerrm);
  46. end;
  47. /
  48. exec makeCSConsistent;
  49. drop procedure makeCSConsistent;