|
| 1 | +REM Filename : tableinfo.sql |
| 2 | +REM Author : Craig Richards |
| 3 | +REM Created : |
| 4 | +REM Version : 1.0 |
| 5 | +REM Modifications : |
| 6 | +REM |
| 7 | +REM Description : Displays everything assocaited with a given table |
| 8 | + |
| 9 | +SET PAGES 1000 |
| 10 | +SET LINES 200 |
| 11 | +SET AUTOTRACE OFF |
| 12 | +SET TIMING OFF |
| 13 | +SET FEEDBACK ON |
| 14 | +SET VERIFY OFF |
| 15 | + |
| 16 | +COLUMN COMMENTS FORMAT A50 |
| 17 | +COLUMN column_name FORMAT A35 |
| 18 | +COLUMN Data_Type FORMAT A15 |
| 19 | +COLUMN DATA_DEFAULT FORMAT A20 |
| 20 | +COLUMN "PK Column" FORMAT A35 |
| 21 | +COLUMN "FK Column" FORMAT A20 |
| 22 | + |
| 23 | +UNDEF Owner |
| 24 | +ACCEPT Owner PROMPT 'Enter Owner :' |
| 25 | +UNDEF Table_Name |
| 26 | +ACCEPT Table_Name PROMPT 'Enter Table Name :' |
| 27 | + |
| 28 | +SET HEADING OFF |
| 29 | + |
| 30 | +PROMPT |
| 31 | +PROMPT Comments for Table &Table_Name. |
| 32 | +SELECT COMMENTS |
| 33 | +FROM ALL_TAB_COMMENTS |
| 34 | +WHERE TABLE_NAME = UPPER('&Table_Name.') |
| 35 | +AND Owner = UPPER('&Owner.') ; |
| 36 | + |
| 37 | +SET HEADING ON |
| 38 | +PROMPT |
| 39 | +PROMPT Column Details for Table &Table_Name. |
| 40 | + |
| 41 | +SELECT ROWNUM "Sr No", T.COLUMN_NAME , T.Data_Type , T.DATA_LENGTH, |
| 42 | +DECODE(T.Nullable, 'N' , 'NOT NULL' , 'Y', ' ') NULLABLE , T.Data_Default , C.Comments |
| 43 | +FROM ALL_TAB_COLS T , All_Col_Comments C |
| 44 | +WHERE T.OWNER = C.OWNER |
| 45 | +AND T.TABLE_NAME = C.TABLE_NAME |
| 46 | +AND T.COLUMN_NAME = C.COLUMN_NAME |
| 47 | +AND T.TABLE_NAME = UPPER('&Table_Name.') |
| 48 | +AND T.Owner = UPPER('&Owner.') ; |
| 49 | + |
| 50 | +PROMPT |
| 51 | +PROMPT PRIMARY KEY for Table &Table_Name. |
| 52 | + |
| 53 | +select COLUMN_NAME |
| 54 | +FROM ALL_CONS_COLUMNS |
| 55 | +WHERE TABLE_NAME = UPPER('&Table_Name.') |
| 56 | +AND Owner = UPPER('&Owner.') |
| 57 | +AND CONSTRAINT_NAME = ( SELECT CONSTRAINT_NAME |
| 58 | +FROM ALL_CONSTRAINTS |
| 59 | +WHERE TABLE_NAME = UPPER('&Table_Name.') |
| 60 | +AND CONSTRAINT_TYPE = 'P' |
| 61 | +AND Owner = UPPER('&Owner.') |
| 62 | +)ORDER BY POSITION |
| 63 | +/ |
| 64 | + |
| 65 | +PROMPT |
| 66 | +PROMPT INDEXES for Table &Table_Name. |
| 67 | + |
| 68 | +BREAK ON INDEX_NAME ON UNIQUENESS SKIP 1 |
| 69 | + |
| 70 | +SELECT I.INDEX_NAME , C.COLUMN_NAME , I.UNIQUENESS |
| 71 | +FROM ALL_IND_COLUMNS C , ALL_INDEXES I |
| 72 | +WHERE C.INDEX_NAME = I.INDEX_NAME |
| 73 | +AND C.TABLE_NAME = I.TABLE_NAME |
| 74 | +AND I.TABLE_NAME = UPPER('&Table_Name.') |
| 75 | +AND I.Owner = UPPER('&Owner.') |
| 76 | +AND C.Table_Owner = UPPER('&Owner.') |
| 77 | +AND NOT EXISTS ( SELECT 'X' |
| 78 | +FROM ALL_CONSTRAINTS |
| 79 | +WHERE CONSTRAINT_NAME = I.INDEX_NAME |
| 80 | +AND Owner = UPPER('&Owner.')) |
| 81 | +ORDER BY INDEX_NAME , COLUMN_POSITION |
| 82 | +/ |
| 83 | + |
| 84 | + |
| 85 | +CLEAR BREAKS |
| 86 | + |
| 87 | +PROMPT |
| 88 | +PROMPT FOREIGN KEYS for Table &Table_Name. |
| 89 | + |
| 90 | +BREAK ON CONSTRAINT_NAME ON TABLE_NAME ON R_CONSTRAINT_NAME SKIP 1 |
| 91 | + |
| 92 | +COLUMN POSITION NOPRINT |
| 93 | + |
| 94 | +SELECT UNIQUE A.CONSTRAINT_NAME, C.COLUMN_NAME "FK Column" , B.TABLE_NAME || '.' || B.COLUMN_NAME "PK Column", A.R_CONSTRAINT_NAME , C.POSITION FROM ALL_CONSTRAINTS A, ALL_CONS_COLUMNS B, ALL_CONS_COLUMNS C |
| 95 | +WHERE A.R_CONSTRAINT_NAME=B.CONSTRAINT_NAME AND B.OWNER=UPPER('&OWNER') |
| 96 | +AND A.CONSTRAINT_NAME=C.CONSTRAINT_NAME AND A.OWNER=C.OWNER AND A.OWNER = B.OWNER |
| 97 | +AND A.TABLE_NAME=C.TABLE_NAME AND B.POSITION=C.POSITION AND A.TABLE_NAME LIKE UPPER('&TABLE_NAME') |
| 98 | +ORDER BY A.CONSTRAINT_NAME, C.POSITION |
| 99 | +/ |
| 100 | + |
| 101 | +COLUMN POSITION NOPRINT |
| 102 | +CLEAR BREAKS |
| 103 | + |
| 104 | +PROMPT |
| 105 | +PROMPT CONSTRAINTS for Table &Table_Name. |
| 106 | + |
| 107 | +SELECT CONSTRAINT_NAME , SEARCH_CONDITION |
| 108 | +FROM ALL_CONSTRAINTS |
| 109 | +WHERE TABLE_NAME = UPPER('&Table_Name.') |
| 110 | +AND Owner = UPPER('&Owner.') |
| 111 | +AND CONSTRAINT_TYPE NOT IN ( 'P' , 'R'); |
| 112 | + |
| 113 | +PROMPT |
| 114 | +PROMPT ROWCOUNT for Table &Table_Name. |
| 115 | + |
| 116 | +SET FEEDBACK OFF |
| 117 | +SET SERVEROUTPUT ON |
| 118 | + |
| 119 | +DECLARE N NUMBER ; |
| 120 | +V VARCHAR2(100) ; |
| 121 | +BEGIN |
| 122 | +V := 'SELECT COUNT(*) FROM ' || UPPER('&Table_Name.') ; |
| 123 | +EXECUTE IMMEDIATE V INTO N ; |
| 124 | +DBMS_OUTPUT.PUT_LINE (N); |
| 125 | +END; |
| 126 | +/ |
| 127 | + |
| 128 | +SET FEEDBACK ON |
| 129 | + |
| 130 | +PROMPT |
| 131 | +PROMPT Tables That REFER to Table &Table_Name. |
| 132 | + |
| 133 | +BREAK ON TABLE_NAME ON CONSTRAINT_NAME skip 1 |
| 134 | + |
| 135 | +SELECT C.TABLE_NAME , C.CONSTRAINT_Name , CC.COLUMN_NAME "FK Column" |
| 136 | +FROM ALL_CONSTRAINTS C, All_Cons_colUMNs CC |
| 137 | +WHERE C.Constraint_Name = CC.Constraint_Name |
| 138 | +AND R_CONSTRAINT_NAME = ( SELECT CONSTRAINT_NAME |
| 139 | +FROM ALL_CONSTRAINTS |
| 140 | +WHERE TABLE_NAME = UPPER('&Table_Name.') |
| 141 | +AND CONSTRAINT_TYPE = 'P' |
| 142 | +AND Owner = UPPER('&Owner.')) |
| 143 | +AND C.Owner = UPPER('&Owner.') |
| 144 | +/ |
| 145 | + |
| 146 | + |
| 147 | + |
| 148 | +CLEAR BREAKS |
| 149 | + |
| 150 | +PROMPT |
| 151 | +PROMPT PARTITIONED COLUMNS for Table &Table_Name. |
| 152 | + |
| 153 | +SELECT COLUMN_NAME , COLUMN_POSITION |
| 154 | +FROM All_Part_Key_Columns |
| 155 | +WHERE NAME = UPPER('&Table_Name.') |
| 156 | +AND Owner = UPPER('&Owner.') ; |
| 157 | + |
| 158 | +PROMPT |
| 159 | +PROMPT PARTITIONS for Table &Table_Name. |
| 160 | + |
| 161 | +SELECT PARTITION_NAME , NUM_ROWS |
| 162 | +FROM All_Tab_Partitions |
| 163 | +WHERE TABLE_NAME = UPPER('&Table_Name.') |
| 164 | +AND Table_Owner = UPPER('&Owner.') ; |
| 165 | + |
| 166 | +PROMPT |
| 167 | +PROMPT TRIGGERS for Table &Table_Name. |
| 168 | + |
| 169 | +SELECT Trigger_Name |
| 170 | +FROM All_Triggers |
| 171 | +WHERE TABLE_NAME = UPPER('&Table_Name.') |
| 172 | +AND Owner = UPPER('&Owner.') ; |
| 173 | + |
| 174 | + |
| 175 | +PROMPT |
| 176 | +PROMPT DEPENDANTS for Table &Table_Name. |
| 177 | + |
| 178 | +BREAK ON TYPE SKIP 1 |
| 179 | + |
| 180 | +SELECT TYPE , NAME |
| 181 | +FROM ALL_DEPENDENCIES |
| 182 | +WHERE REFERENCED_NAME = UPPER('&Table_Name.') |
| 183 | +ORDER BY TYPE ; |
| 184 | + |
| 185 | +CLEAR BREAKS |
| 186 | + |
| 187 | +SET TERMOUT OFF |
| 188 | +SET AUTOTRACE ON |
| 189 | +SET TIMING ON |
| 190 | +SET TERMOUT ON |
| 191 | + |
| 192 | +REM End of Script |
0 commit comments