|
| 1 | +REM Script Name : db_report.sql |
| 2 | +REM Author : Craig Richards |
| 3 | +REM Created : 07-December-2006 |
| 4 | +REM Last Modified : |
| 5 | +REM Version : 1.0 |
| 6 | +REM |
| 7 | +REM Modifications : |
| 8 | +REM |
| 9 | +REM Description : |
| 10 | + |
| 11 | +SET PAUSE OFF |
| 12 | +SET HEADING OFF |
| 13 | + |
| 14 | +ACCEPT dbsid PROMPT "Enter SID for report : "; |
| 15 | +SPOOL /admin/output/db_report_&dbsid |
| 16 | + |
| 17 | +PROMPT Database Information |
| 18 | +PROMPT ==================== |
| 19 | + |
| 20 | +SELECT banner from v$version; |
| 21 | + |
| 22 | +SET HEADING ON |
| 23 | + |
| 24 | +select DBID,name,LOG_MODE,created from v$database; |
| 25 | + |
| 26 | +SET HEADING OFF |
| 27 | + |
| 28 | +PROMPT |
| 29 | +PROMPT Who Has the Dba privilege |
| 30 | +PROMPT ========================= |
| 31 | + |
| 32 | +SELECT grantee FROM dba_role_privs WHERE granted_role = 'DBA'; |
| 33 | + |
| 34 | +PROMPT |
| 35 | +PROMPT Who owns the recovery catalog |
| 36 | +PROMPT ============================= |
| 37 | + |
| 38 | +SELECT grantee FROM dba_role_privs WHERE granted_role = 'RECOVERY_CATALOG_OWNER'; |
| 39 | + |
| 40 | +SET FEEDBACK OFF |
| 41 | + |
| 42 | +PROMPT |
| 43 | +PROMPT Map of datafiles, controlfiles, redo logs |
| 44 | +PROMPT ========================================= |
| 45 | + |
| 46 | +PROMPT |
| 47 | +PROMPT Datafiles |
| 48 | +PROMPT ========= |
| 49 | + |
| 50 | +SELECT file_name FROM dba_data_files; |
| 51 | + |
| 52 | +PROMPT |
| 53 | +PROMPT Control Files |
| 54 | +PROMPT ============= |
| 55 | + |
| 56 | +COLUMN name FORMAT A40 |
| 57 | + |
| 58 | +SELECT name FROM v$controlfile; |
| 59 | + |
| 60 | +CLEAR COLUMNS |
| 61 | + |
| 62 | +PROMPT |
| 63 | +PROMPT Redo Logs |
| 64 | +PROMPT ========= |
| 65 | + |
| 66 | +SELECT member FROM v$logfile; |
| 67 | + |
| 68 | +SET PAUSE OFF |
| 69 | +SET FEEDBACK OFF |
| 70 | +SET PAGESIZE 66 |
| 71 | +SET TERMOUT OFF |
| 72 | +SET TRIMSPOOL ON |
| 73 | + |
| 74 | +TTITLE SKIP 2 CENTER 'FREE - Free space by Tablespace' skip 2 |
| 75 | + |
| 76 | +COLUMN dummy NOPRINT |
| 77 | +COLUMN pct_used FORMAT 999.9 HEADING "%|Used" |
| 78 | +COLUMN name FORMAT A16 HEADING "Tablespace Name" |
| 79 | +COLUMN bytes FORMAT 9,999,999,999,999 HEADING "Total Bytes" |
| 80 | +COLUMN used FORMAT 9,999,999,999,999 HEADING "Used" |
| 81 | +COLUMN free FORMAT 999,999,999,999 HEADING "Free" |
| 82 | + |
| 83 | +BREAK ON REPORT |
| 84 | + |
| 85 | +COMPUTE SUM of bytes ON REPORT |
| 86 | +COMPUTE SUM of free ON REPORT |
| 87 | +COMPUTE SUM of used ON REPORT |
| 88 | + |
| 89 | +SELECT a.tablespace_name name, b.tablespace_name dummy, |
| 90 | + SUM(b.bytes)/COUNT( DISTINCT a.file_id||'.'||a.block_id ) bytes, |
| 91 | + SUM(b.bytes)/COUNT( DISTINCT a.file_id||'.'||a.block_id ) - |
| 92 | + SUM(a.bytes)/COUNT( DISTINCT b.file_id ) used, |
| 93 | + SUM(a.bytes)/COUNT( DISTINCT b.file_id ) free, |
| 94 | + 100 * ( (SUM(b.bytes)/COUNT( DISTINCT a.file_id||'.'||a.block_id )) - |
| 95 | + (SUM(a.bytes)/COUNT( DISTINCT b.file_id ) )) / |
| 96 | + (SUM(b.bytes)/COUNT( DISTINCT a.file_id||'.'||a.block_id )) pct_used |
| 97 | +FROM sys.dba_free_space a, sys.dba_data_files b |
| 98 | +WHERE a.tablespace_name = b.tablespace_name |
| 99 | +GROUP BY a.tablespace_name, b.tablespace_name; |
| 100 | +SET TERMOUT ON |
| 101 | + |
| 102 | +TTITLE OFF |
| 103 | + |
| 104 | +PROMPT |
| 105 | +PROMPT User Information |
| 106 | +PROMPT ================ |
| 107 | +PROMPT |
| 108 | + |
| 109 | +COLUMN username FORMAT A20 |
| 110 | +COLUMN profile FORMAT A10 |
| 111 | +COLUMN default_tablespace FORMAT A15 |
| 112 | +COLUMN temporary_tablespace FORMAT A15 |
| 113 | + |
| 114 | +select username, default_tablespace, temporary_tablespace,profile, created from dba_users; |
| 115 | + |
| 116 | +CLEAR COLUMNS |
| 117 | + |
| 118 | +PROMPT |
| 119 | +PROMPT Database Parameters |
| 120 | +PROMPT =================== |
| 121 | + |
| 122 | +COLUMN name FORMAT A40 |
| 123 | +COLUMN value FORMAT A60 |
| 124 | + |
| 125 | +SET LINES 200 |
| 126 | + |
| 127 | +select name, value from v$parameter; |
| 128 | + |
| 129 | +CLEAR COLUMNS |
| 130 | + |
| 131 | +SET LINES 80 |
| 132 | + |
| 133 | +SET PAUSE OFF |
| 134 | + |
| 135 | +COLUMN segment_name FORMAT A15 |
| 136 | +COLUMN tablespace_name FORMAT A15 |
| 137 | + |
| 138 | +PROMPT |
| 139 | +PROMPT Rollback Segments |
| 140 | +PROMPT ================= |
| 141 | + |
| 142 | +SELECT segment_name, tablespace_name, segment_id, status |
| 143 | +FROM dba_rollback_segs; |
| 144 | + |
| 145 | +SET PAUSE OFF |
| 146 | +SET FEEDBACK OFF |
| 147 | + |
| 148 | +COLUMN name FORMAT A20 |
| 149 | + |
| 150 | +SELECT name, optsize, shrinks, aveshrink, extends,wraps |
| 151 | +FROM v$rollstat, v$rollname |
| 152 | +WHERE v$rollstat.usn=v$rollname.usn; |
| 153 | + |
| 154 | +PROMPT |
| 155 | +PROMPT Invalid Objects in the database |
| 156 | +PROMPT =============================== |
| 157 | + |
| 158 | +SET LINES 200 |
| 159 | + |
| 160 | +COLUMN owner FORMAT A20 |
| 161 | +COLUMN object_name FORMAT A30 |
| 162 | +COLUMN object_type FORMAT A30 |
| 163 | + |
| 164 | +select owner, object_name, object_type from dba_objects where status = 'INVALID'; |
| 165 | + |
| 166 | +CLEAR COLUMNS |
| 167 | + |
| 168 | +SET LINESIZE 80 |
| 169 | + |
| 170 | +PROMPT |
| 171 | +PROMPT SGA Settings |
| 172 | +PROMPT ============ |
| 173 | + |
| 174 | +SHOW SGA; |
| 175 | + |
| 176 | +PROMPT |
| 177 | +PROMPT Tablespace Information |
| 178 | +PROMPT ====================== |
| 179 | + |
| 180 | +COLUMN tablespace_name FORMAT A25 |
| 181 | + |
| 182 | +SET LINES 200 |
| 183 | +SET HEADING ON |
| 184 | + |
| 185 | +select tablespace_name, initial_extent, next_extent,min_extents,max_extents,extent_management from dba_tablespaces; |
| 186 | + |
| 187 | +COLUMN file_name FORMAT A80 |
| 188 | + |
| 189 | +select file_name from dba_data_files where AUTOEXTENSIBLE = 'YES'; |
| 190 | + |
| 191 | +CLEAR COLUMNS |
| 192 | + |
| 193 | +SET LINES 80 |
| 194 | + |
| 195 | +PROMPT |
| 196 | +PROMPT DBMS SCHEDULER |
| 197 | +PROMPT ============== |
| 198 | + |
| 199 | +SELECT owner, job_name, job_type FROM dba_scheduler_jobs; |
| 200 | + |
| 201 | +PROMPT |
| 202 | +PROMPT Undo Stats |
| 203 | +PROMPT ========== |
| 204 | +PROMPT |
| 205 | + |
| 206 | +SET LINES 200 |
| 207 | + |
| 208 | +SELECT TO_CHAR(MIN(Begin_Time), 'DD-MON-YYYY HH24:MI:SS') "Begin Time", |
| 209 | + TO_CHAR(MAX(End_Time), 'DD-MON-YYYY HH24:MI:SS') "End Time", |
| 210 | + SUM(Undoblks) "Total Undo Blocks Used", |
| 211 | + SUM(Txncount) "Total Num Trans Exec", |
| 212 | + MAX(Maxquerylen) "Longest Query(in secs)", |
| 213 | + MAX(Maxconcurrency) "Highest Concurrent Trans Count", |
| 214 | + SUM(Ssolderrcnt), SUM(Nospaceerrcnt) |
| 215 | +FROM v$undostat; |
| 216 | + |
| 217 | +SPOOL OFF |
| 218 | + |
| 219 | +REM exit |
| 220 | + |
| 221 | +REM End of Script |
0 commit comments