dbCheckConsistency_oracle.sql 5.6 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137
  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 TABLE CMCHECKCONSISTENCY (
  12. INCONSISTENCY number(10) not null,
  13. DESCRIPTION varchar2(255),
  14. CMID number(10)
  15. );
  16. create or replace procedure getInconsistentCMIDs as
  17. tablename char(20);
  18. cmid number(10);
  19. strsql varchar2(500);
  20. cursor tables is
  21. 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;
  22. cmid_cursor integer;
  23. fdbk integer;
  24. begin
  25. cmid_cursor := DBMS_SQL.OPEN_CURSOR;
  26. FOR tables_row in tables LOOP
  27. if tables_row.TABLE_NAME != 'CMCHECKCONSISTENCY' then
  28. strsql := 'insert into CMCHECKCONSISTENCY(INCONSISTENCY,DESCRIPTION,CMID) select 1, '''||tables_row.TABLE_NAME||''', CMID from '||tables_row.TABLE_NAME||' where CMID not in (select CMID from CMOBJECTS)';
  29. DBMS_SQL.PARSE(cmid_cursor, strsql, DBMS_SQL.NATIVE);
  30. fdbk := DBMS_SQL.EXECUTE(cmid_cursor);
  31. end if;
  32. END LOOP;
  33. strsql := 'insert into CMCHECKCONSISTENCY(INCONSISTENCY,DESCRIPTION,CMID) select 2, ''CMOBJECTS'', CMID from CMOBJECTS where CMID not in (select CMID from CMOBJNAMES) or CMID not in (select CMID from CMPOLICIES)';
  34. DBMS_SQL.PARSE(cmid_cursor, strsql, DBMS_SQL.NATIVE);
  35. fdbk := DBMS_SQL.EXECUTE(cmid_cursor);
  36. strsql := 'insert into CMCHECKCONSISTENCY(INCONSISTENCY,DESCRIPTION,CMID) select 3, ''CMSTOREIDS'', CMID from CMSTOREIDS where STOREID is null';
  37. DBMS_SQL.PARSE(cmid_cursor, strsql, DBMS_SQL.NATIVE);
  38. fdbk := DBMS_SQL.EXECUTE(cmid_cursor);
  39. strsql := 'insert into CMCHECKCONSISTENCY(INCONSISTENCY,DESCRIPTION,CMID) select 4, ''CMSTOREIDS'', s.CMID from CMSTOREIDS s where UPPER(s.STOREID) in (select STOREID from (select b.CMID, UPPER(b.STOREID) as STOREID from CMSTOREIDS b) group by STOREID having COUNT(CMID) > 1)';
  40. DBMS_SQL.PARSE(cmid_cursor, strsql, DBMS_SQL.NATIVE);
  41. fdbk := DBMS_SQL.EXECUTE(cmid_cursor);
  42. DBMS_SQL.CLOSE_CURSOR(cmid_cursor);
  43. exception
  44. when others then
  45. if DBMS_SQL.IS_OPEN(cmid_cursor) then
  46. DBMS_SQL.CLOSE_CURSOR(cmid_cursor);
  47. end if;
  48. raise_application_error(-20000, 'Unknown Exception Raised: '||sqlcode||' '||sqlerrm);
  49. end;
  50. /
  51. Rem CMSCRIPT_SKIP_COMMAND
  52. create or replace procedure printInconsistentCMIDs as
  53. tablename char(20);
  54. cmid number(10);
  55. cursor tables is
  56. SELECT a.DESCRIPTION, a.CMID FROM CMCHECKCONSISTENCY a WHERE a.INCONSISTENCY = 1 ORDER BY CMID ASC;
  57. cursor cmobjects is
  58. SELECT a.DESCRIPTION, a.CMID FROM CMCHECKCONSISTENCY a WHERE a.INCONSISTENCY = 2 ORDER BY CMID ASC;
  59. cursor cmstoreids is
  60. SELECT a.DESCRIPTION, a.CMID FROM CMCHECKCONSISTENCY a WHERE a.INCONSISTENCY = 3 ORDER BY CMID ASC;
  61. cursor cmduplicatestoreids is
  62. SELECT a.DESCRIPTION, a.CMID FROM CMCHECKCONSISTENCY a WHERE a.INCONSISTENCY = 4 ORDER BY CMID ASC;
  63. header_printed integer;
  64. begin
  65. header_printed := 0;
  66. FOR tables_row in tables LOOP
  67. if header_printed = 0 then
  68. DBMS_OUTPUT.PUT_LINE('CMIDs not in CMOBJECTS table');
  69. DBMS_OUTPUT.PUT_LINE('Table Orphaned CMID');
  70. DBMS_OUTPUT.PUT_LINE('----- -------------');
  71. header_printed := 1;
  72. end if;
  73. tablename := tables_row.DESCRIPTION;
  74. cmid := tables_row.CMID;
  75. DBMS_OUTPUT.PUT_LINE(tablename || TO_CHAR(cmid));
  76. END LOOP;
  77. header_printed := 0;
  78. FOR cmobjects_row in cmobjects LOOP
  79. if header_printed = 0 then
  80. DBMS_OUTPUT.PUT_LINE('');
  81. DBMS_OUTPUT.PUT_LINE('CMIDs in CMOBJECTS table but not in CMOBJNAMES or CMPOLICIES tables');
  82. DBMS_OUTPUT.PUT_LINE('Table CMID');
  83. DBMS_OUTPUT.PUT_LINE('----- -------------');
  84. header_printed := 1;
  85. end if;
  86. cmid := cmobjects_row.CMID;
  87. DBMS_OUTPUT.PUT_LINE('CMOBJECTS ' || TO_CHAR(cmid));
  88. END LOOP;
  89. header_printed := 0;
  90. FOR cmobjects_row in cmstoreids LOOP
  91. if header_printed = 0 then
  92. DBMS_OUTPUT.PUT_LINE('');
  93. DBMS_OUTPUT.PUT_LINE('CMIDs in CMSTOREIDS table where STOREID is null');
  94. DBMS_OUTPUT.PUT_LINE('Table CMID');
  95. DBMS_OUTPUT.PUT_LINE('----- -------------');
  96. header_printed := 1;
  97. end if;
  98. cmid := cmobjects_row.CMID;
  99. DBMS_OUTPUT.PUT_LINE('CMSTOREIDS ' || TO_CHAR(cmid));
  100. END LOOP;
  101. header_printed := 0;
  102. FOR cmobjects_row in cmduplicatestoreids LOOP
  103. if header_printed = 0 then
  104. DBMS_OUTPUT.PUT_LINE('');
  105. DBMS_OUTPUT.PUT_LINE('CMIDs in CMSTOREIDS table which have non-unique STOREIDs');
  106. DBMS_OUTPUT.PUT_LINE('Table CMID');
  107. DBMS_OUTPUT.PUT_LINE('----- -------------');
  108. header_printed := 1;
  109. end if;
  110. cmid := cmobjects_row.CMID;
  111. DBMS_OUTPUT.PUT_LINE('CMSTOREIDS ' || TO_CHAR(cmid));
  112. END LOOP;
  113. exception
  114. when others then
  115. raise_application_error(-20000, 'Unknown Exception Raised: '||sqlcode||' '||sqlerrm);
  116. end;
  117. /
  118. Rem CMSCRIPT_SKIP_COMMAND
  119. set serveroutput on format wrapped;
  120. delete from CMCHECKCONSISTENCY;
  121. exec getInconsistentCMIDs;
  122. Rem CMSCRIPT_SKIP_COMMAND
  123. exec printInconsistentCMIDs;
  124. drop procedure getInconsistentCMIDs;
  125. Rem CMSCRIPT_SKIP_COMMAND
  126. drop procedure printInconsistentCMIDs;