|
| 1 | +REM Filename : tab_desc.sql |
| 2 | +REM Author : Craig Richards |
| 3 | +REM Created : 25-February-2009 |
| 4 | +REM Version : 1.0 |
| 5 | +REM Modifications : |
| 6 | +REM |
| 7 | +REM Description : Gives a full description of the table, including all constraints, indexes and comments etc |
| 8 | + |
| 9 | +SET ECHO OFF |
| 10 | +SET TERM ON |
| 11 | + |
| 12 | +ACCEPT table_name PROMPT "Enter the name of the table: " |
| 13 | +ACCEPT tab_owner PROMPT "Enter table owner: " |
| 14 | + |
| 15 | +SET HEADING ON |
| 16 | +SET NEWPAGE 0 |
| 17 | + |
| 18 | +TTITLE 'Table Description - Space Definition' |
| 19 | + |
| 20 | +SPOOL tab_desc.log |
| 21 | + |
| 22 | +BTITLE off |
| 23 | +COLUMN nline newline |
| 24 | + |
| 25 | +SET PAGESIZE 54 |
| 26 | +SET LINESIZE 78 |
| 27 | +SET HEADING OFF |
| 28 | +SET EMBEDDED OFF |
| 29 | +SET VERIFY OFF |
| 30 | + |
| 31 | +ACCEPT report_comment char PROMPT 'Enter a comment to identify the system: ' |
| 32 | +SET TERMOUT OFF |
| 33 | +SELECT 'Date - '||TO_CHAR(sysdate,'Day Ddth Month YYYY HH24:MI:SS'), |
| 34 | + 'At - '||'&&report_comment' nline, |
| 35 | + 'Username - '||User nline |
| 36 | +FROM sys.dual |
| 37 | +/ |
| 38 | +PROMPT |
| 39 | + |
| 40 | +SET EMBEDDED ON |
| 41 | +SET HEADING ON |
| 42 | + |
| 43 | +COLUMN Ts FORMAT a30 |
| 44 | +COLUMN Ta FORMAT a30 |
| 45 | +COLUMN Clu FORMAT a30 |
| 46 | +COLUMN Pcf FORMAT 99999999999990 |
| 47 | +COLUMN Pcu FORMAT 99999999999990 |
| 48 | +COLUMN Int FORMAT 99,999,999,990 |
| 49 | +COLUMN Mat FORMAT 99,999,999,990 |
| 50 | +COLUMN Inx FORMAT 99,999,999,990 |
| 51 | +COLUMN Nxt FORMAT 99,999,999,990 |
| 52 | +COLUMN Mix FORMAT 99,999,999,990 |
| 53 | +COLUMN Max FORMAT 99,999,999,990 |
| 54 | +COLUMN Pci FORMAT 99999999999990 |
| 55 | +COLUMN Num FORMAT 99,999,999,990 |
| 56 | +COLUMN Blo FORMAT 99,999,999,990 |
| 57 | +COLUMN Emp FORMAT 99,999,999,990 |
| 58 | +COLUMN Avg FORMAT 99,999,999,990 |
| 59 | +COLUMN Cha FORMAT 99,999,999,990 |
| 60 | +COLUMN Rln FORMAT 99,999,999,990 |
| 61 | +COLUMN Hdg FORMAT a30 newline |
| 62 | +SET HEADING OFF |
| 63 | +SELECT 'Table Name' Hdg, table_name Ta, |
| 64 | + 'Tablespace_name' Hdg, tablespace_name Ts, |
| 65 | + 'Cluster Name' Hdg, cluster_name Clu, |
| 66 | + '% Free' Hdg, Pct_Free Pcf, |
| 67 | + '% Used' Hdg, Pct_Used Pcu, |
| 68 | + 'Ini Trans' Hdg, Ini_Trans Int, |
| 69 | + 'Max Trans' Hdg, Max_Trans Mat, |
| 70 | + 'Initial Extent (K)' Hdg, Initial_Extent/1024 Inx, |
| 71 | + 'Next Extent (K)' Hdg, Next_extent/1024 Nxt, |
| 72 | + 'Min Extents' Hdg, Min_extents Mix, |
| 73 | + 'Max Extents' Hdg, Max_extents Max, |
| 74 | + '% Increase' Hdg, Pct_Increase Pci, |
| 75 | + 'Number of Rows' Hdg, Num_Rows Num, |
| 76 | + 'Number of Blocks' Hdg, Blocks Blo, |
| 77 | + 'Number of Empty Blocks' Hdg, Empty_Blocks Emp, |
| 78 | + 'Average Space' Hdg, Avg_Space Avg, |
| 79 | + 'Chain Count' Hdg, Chain_Cnt Cha, |
| 80 | + 'Average Row Length' Hdg, Avg_Row_len Rln |
| 81 | +FROM dba_tables |
| 82 | +WHERE table_name = UPPER('&&table_name') |
| 83 | +AND owner=UPPER('&&tab_owner') |
| 84 | +/ |
| 85 | + |
| 86 | +SET HEADING ON |
| 87 | + |
| 88 | +PROMPT |
| 89 | +PROMPT Comments on the Table |
| 90 | +PROMPT |
| 91 | + |
| 92 | +SELECT COMMENTS FROM dba_tab_comments |
| 93 | +WHERE table_name = UPPER('&&table_name') |
| 94 | +AND owner=UPPER('&&tab_owner') |
| 95 | +/ |
| 96 | + |
| 97 | +SET HEADING ON |
| 98 | +SET EMBEDDED OFF |
| 99 | + |
| 100 | +COLUMN Cn FORMAT A30 HEADING 'Column Name' |
| 101 | +COLUMN Fo FORMAT A15 HEADING 'Type' |
| 102 | +COLUMN Nu FORMAT A8 HEADING 'Null' |
| 103 | +COLUMN Nds FORMAT 99,999,999 HEADING 'No Distinct' |
| 104 | +COLUMN Dfl FORMAT 9999 HEADING 'Dflt Len' |
| 105 | +COLUMN Dfv FORMAT A40 HEADING 'Default Value' |
| 106 | + |
| 107 | +TTITLE 'Table Description - Column Definition' |
| 108 | + |
| 109 | +SELECT Column_name Cn, data_type || |
| 110 | +DECODE(Data_type,'NUMBER','('||TO_CHAR(data_precision)||DECODE(data_scale,0,'',','||TO_CHAR(data_scale))||')','VARCHAR2', |
| 111 | +'('||TO_CHAR(Data_Length)||')','CHAR', |
| 112 | +'('||TO_CHAR(Data_Length)||')','DATE','','LONG','','Error') Fo, |
| 113 | +DECODE(NUllable,'Y','','NOT NULL') Nu, |
| 114 | +Num_Distinct Nds, |
| 115 | +Default_length Dfl, |
| 116 | +Data_Default Dfv |
| 117 | +FROM dba_tab_columns |
| 118 | +WHERE table_name = UPPER('&&table_name') |
| 119 | +AND owner=UPPER('&&tab_owner') |
| 120 | +ORDER BY COLUMN_ID |
| 121 | +/ |
| 122 | + |
| 123 | +TTITLE off |
| 124 | + |
| 125 | +PROMPT |
| 126 | +PROMPT TABLE CONSTRAINTS |
| 127 | +PROMPT |
| 128 | + |
| 129 | +SET HEADING ON |
| 130 | + |
| 131 | +COLUMN Cn FORMAT a30 HEADING 'Primary Constraint' |
| 132 | +COLUMN Cln FORMAT a45 HEADING 'Table.Column Name' |
| 133 | +COLUMN Ct FORMAT a7 HEADING 'Type' |
| 134 | +COLUMN St FORMAT a7 HEADING 'Status' |
| 135 | +COLUMN Ro FORMAT a30 HEADING 'Ref Owner| Constraint Name' |
| 136 | +COLUMN Se FORMAT a70 HEADING 'Criteria ' newline |
| 137 | + |
| 138 | +BREAK ON Cn ON St |
| 139 | + |
| 140 | +SET EMBEDDED ON |
| 141 | + |
| 142 | +PROMPT Primary Key |
| 143 | +PROMPT |
| 144 | + |
| 145 | +SELECT CNS.Constraint_name Cn, |
| 146 | +CNS.Table_name||'.'||CLS.Column_Name Cln,INITCAP(CNS.Status) St |
| 147 | +FROM dba_constraints CNS, DBA_CONS_COLUMNS CLS |
| 148 | +WHERE CNS.Table_name=UPPER('&&table_name') |
| 149 | +AND CNS.Owner=UPPER('&&tab_owner') |
| 150 | +AND CNS.Constraint_Type='P' |
| 151 | +AND CNS.Constraint_Name=CLS.Constraint_name |
| 152 | +ORDER BY CLS.Position |
| 153 | +/ |
| 154 | + |
| 155 | +PROMPT Unique Key |
| 156 | +PROMPT |
| 157 | + |
| 158 | +COLUMN Cn FORMAT a30 HEADING 'Unique Key' |
| 159 | + |
| 160 | +SELECT CNS.Constraint_name Cn, |
| 161 | +CNS.Table_name||'.'||CLS.Column_Name Cln, |
| 162 | +INITCAP(CNS.Status) St |
| 163 | +FROM dba_constraints CNS, DBA_CONS_COLUMNS CLS |
| 164 | +WHERE cns.Table_name=UPPER('&&table_name') |
| 165 | +AND CNS.Owner=UPPER('&&tab_owner') |
| 166 | +AND CNS.Constraint_Type='U' |
| 167 | +AND CNS.Constraint_name=CLS.Constraint_name |
| 168 | +ORDER BY CLS.Position |
| 169 | +/ |
| 170 | + |
| 171 | +PROMPT Foreign Keys |
| 172 | +PROMPT |
| 173 | + |
| 174 | +COLUMN Cln FORMAT a38 HEADING 'Foreign Key' newline |
| 175 | +COLUMN Clfn FORMAT a38 HEADING 'Parent Key' |
| 176 | +COLUMN Cn FORMAT a40 HEADING 'Foreign Constraint' |
| 177 | + |
| 178 | +BREAK ON Cn ON St SKIP 1 |
| 179 | + |
| 180 | +SELECT cns.constraint_name Cn, |
| 181 | +INITCAP(CNS.Status) St, |
| 182 | +CLS.Table_name||'.'||cls.COLUMN_name Cln, |
| 183 | +CLF.Owner||'.'||CLf.Table_name||'.'||clf.COLUMN_name Clfn |
| 184 | +FROM dba_constraints cns, dba_cons_COLUMNs clf, dba_cons_COLUMNs cls |
| 185 | +WHERE cns.table_name=UPPER('&&table_name') |
| 186 | +AND CNS.Owner=UPPER('&&tab_owner') |
| 187 | +AND CNS.Constraint_Type='R' |
| 188 | +AND cns.constraint_name=cls.constraint_name |
| 189 | +AND clf.constraint_name = cns.r_constraint_name |
| 190 | +AND clf.owner = cns.owner |
| 191 | +AND clf.position = cls.position |
| 192 | +ORDER BY cns.constraint_name, cls.position |
| 193 | +/ |
| 194 | + |
| 195 | +PROMPT Check Constraints |
| 196 | +PROMPT |
| 197 | + |
| 198 | +COLUMN Cn FORMAT a40 HEADING 'Check Constraint' |
| 199 | +COLUMN Se FORMAT a75 HEADING 'Criteria ' |
| 200 | + |
| 201 | +SET ARRAYSIZE 1 |
| 202 | +SET LONG 32000 |
| 203 | + |
| 204 | +SELECT constraint_name Cn,INITCAP(Status) St, |
| 205 | +Search_Condition Se |
| 206 | +FROM DBA_CONSTRAINTS |
| 207 | +WHERE table_name=UPPER('&&table_name') |
| 208 | +AND owner=UPPER('&&tab_owner') |
| 209 | +AND Constraint_Type='C' |
| 210 | +/ |
| 211 | + |
| 212 | +PROMPT View Constraints |
| 213 | +PROMPT |
| 214 | + |
| 215 | +COLUMN Cn FORMAT a40 HEADING 'View Constraint' |
| 216 | +SELECT Constraint_Name Cn, |
| 217 | +INITCAP(Status) St, |
| 218 | +Search_Condition Se |
| 219 | +FROM DBA_CONSTRAINTS |
| 220 | +WHERE table_name=UPPER('&&table_name') |
| 221 | +AND owner=UPPER('&&tab_owner') |
| 222 | +AND Constraint_Type='V' |
| 223 | +/ |
| 224 | + |
| 225 | +SPOOL OFF |
| 226 | + |
| 227 | +SET ARRAYSIZE 30 |
| 228 | +SET NEWPAGE 1 VERIFY ON FEEDBACK 6 PAGESIZE 24 LINESIZE 80 |
| 229 | +SET HEADING ON EMBEDDED OFF TERMOUT ON ARRAYSIZE 15 LONG 80 |
| 230 | + |
| 231 | +UNDEFINE table_name |
| 232 | +UNDEFINE tab_owner |
| 233 | +UNDEFINE report_comment |
| 234 | + |
| 235 | +TTITLE OFF |
| 236 | +BTITLE OFF |
| 237 | +CLEAR COLUMNS |
| 238 | + |
| 239 | +REM End of Script |
0 commit comments