├── .gitignore ├── CONFSQL └── confsql.sql ├── ENVIRONMENT ├── showamb.sql └── showmetrics.sql ├── README.md ├── RMAN └── showrman.sql ├── SGA └── showsga.sql └── SQLPLAN └── showplan.sql /.gitignore: -------------------------------------------------------------------------------- 1 | .DS_Store 2 | -------------------------------------------------------------------------------- /CONFSQL/confsql.sql: -------------------------------------------------------------------------------- 1 | --#/*************************************************************************************/ 2 | --#/* Script : confsql.sql */ 3 | --#/* Author : Mario Barduchi */ 4 | --#/* E-mail : mario.barduchi@gmail.com */ 5 | --#/* Date : 07/07/2020 */ 6 | --#/* Original : None */ 7 | --#/* Description : Configurations - SQL*Plus */ 8 | --#/* Location : /home/oracle/SCRIPTS2DBA */ 9 | --#/* Responsibility : DBA */ 10 | --#/* External Parameters : */ 11 | --#/* Changes Made : */ 12 | --#/* Observations : */ 13 | --#/*************************************************************************************/ 14 | SET LINESIZE 1000 15 | SET PAGESIZE 999 16 | SET LONG 32767 17 | SET LONGCHUNKSIZE 4095 18 | SET TIME ON 19 | SET TAB OFF 20 | SET VERIFY OFF 21 | SET TRIMOUT OFF 22 | SET TRIMSPOOL OFF 23 | SET TERMOUT ON 24 | SET TRIM ON 25 | SET FEEDBACK ON 26 | SET WRAP OFF 27 | alter session set nls_date_format = 'DD/MM/YYYY HH24:Mi:SS'; 28 | -------------------------------------------------------------------------------- /ENVIRONMENT/showamb.sql: -------------------------------------------------------------------------------- 1 | --#/*********************************************************************************************/ 2 | --#/* Script : showamb.sql */ 3 | --#/* Autor : Jose Mario Barduchi */ 4 | --#/* E-mail : mario.barduchi@gmail.com */ 5 | --#/* Data : 17/01/2017 */ 6 | --#/* Original : Sr. Fabio Telles */ 7 | --#/* Descricao : Coleta informacoes do ambiente */ 8 | --#/* Localizacao : /home/oracle/DBA/sql */ 9 | --#/* Responsabilidade : DBA-Executado com usuario SYS */ 10 | --#/* Parametros Externos : Nao Ha */ 11 | --#/* Alteracoes Efetuadas : */ 12 | --#/* Acrescimo de algumas verificacoes e informacoes */ 13 | --#/* Alteracao de algumas tabelas fontes */ 14 | --#/* Acertos gerais */ 15 | --#/* Adicionada a area de upgrade */ 16 | --#/* Observacoes : */ 17 | --#/* Baseado no script do Sr. Fabio Telles encontrado abaixo */ 18 | --#/* http://www.midstorm.org/~telles/2010/05/13/coletando-informacoes-de-uma-base-oracle/ */ 19 | --#/*********************************************************************************************/ 20 | SET serveroutput ON SIZE 1000000 FORMAT WRAPPED 21 | SET autotrace OFF 22 | SET feedback OFF 23 | SET wrap OFF 24 | SET trimspool ON 25 | SET pagesize 100 26 | SET linesize 200 27 | SET VERIFY OFF 28 | 29 | ALTER SESSION SET NLS_DATE_FORMAT = 'DD-MON-YYYY HH24:MI:SS'; 30 | 31 | -- Spool: Nome da base + data 32 | column filename new_val filename 33 | select 'SNAPSHOT_'||name||'_'|| to_char(sysdate, 'yyyymmdd')||'.rpt' as filename from v$database; 34 | --spool /tmp/&filename 35 | 36 | 37 | DECLARE 38 | v_media_archive NUMBER; 39 | v_spfile VARCHAR(10); 40 | v_name v$database.db_unique_name%TYPE; 41 | v_log_mode v$database.log_mode%TYPE; 42 | v_data DATE; 43 | v_version NUMBER; 44 | 45 | BEGIN 46 | SELECT SUBSTR(&_O_RELEASE,1) INTO v_version from dual; 47 | 48 | SELECT DECODE(COUNT(*),0,'PFILE','SPFILE') INTO v_spfile FROM v$spparameter 49 | WHERE isspecified != 'FALSE'; 50 | 51 | SELECT db_unique_name,log_mode,sysdate INTO v_name,v_log_mode,v_data FROM v$database; 52 | 53 | -- Pula uma linha 54 | dbms_output.put_line(chr(10)); 55 | 56 | dbms_output.put_line('==============================================================================='); 57 | dbms_output.put_line('Informacoes da(s) INSTANCE(s) do database: ' || v_name || ' (' || v_data || ')'); 58 | dbms_output.put_line('==============================================================================='); 59 | dbms_output.put_line(''); 60 | 61 | for lst in ( SELECT distinct dbid, db_unique_name, created, resetlogs_time, log_mode FROM gv$database) loop 62 | dbms_output.put_line('DBID.............: ' || lst.dbid); 63 | dbms_output.put_line('Unique Name......: ' || lst.db_unique_name); 64 | dbms_output.put_line('DB Created.......: ' || to_char(lst.created,'DD/MM/YYYY HH:MM:SS')); 65 | dbms_output.put_line('Last ResetLogs...: ' || to_char(lst.resetlogs_time,'DD/MM/YYYY HH:MM:SS')); 66 | dbms_output.put_line('Archive Mode.....: ' || lst.log_mode); 67 | end loop; 68 | 69 | dbms_output.put_line('Inicializado com.: ' || v_spfile); 70 | dbms_output.put_line('.........................................'); 71 | 72 | for lst in (select THREAD#, INSTANCE_NUMBER, INSTANCE_NAME, VERSION, STATUS, STARTUP_TIME, HOST_NAME from gv$instance order by INSTANCE_NUMBER) loop 73 | dbms_output.put_line('Instance ID......: ' || lst.instance_number); 74 | dbms_output.put_line('Instance name....: ' || lst.instance_name); 75 | dbms_output.put_line('DB Version.......: ' || lst.version); 76 | dbms_output.put_line('Status...........: ' || lst.status); 77 | dbms_output.put_line('Hostname.........: ' || lst.host_name); 78 | dbms_output.put_line('Last Startup.....: ' || lst.startup_time); 79 | dbms_output.put_line('.........................................'); 80 | end loop; 81 | 82 | for lst in (select * from database_properties) loop 83 | if lst.property_name = 'DEFAULT_TEMP_TABLESPACE' then 84 | dbms_output.put_line('Temp default.....: ' || lst.property_value); 85 | end if; 86 | end loop; 87 | 88 | for lst in (select global_name from global_name) loop 89 | dbms_output.put_line('Global name......: ' || lst.global_name); 90 | end loop; 91 | 92 | for lst in (SELECT distinct ((length(addr)*4)||'-Bits') as version FROM v$process) loop 93 | dbms_output.put_line('OS Version.......: ' || lst.version); 94 | end loop; 95 | 96 | for lst in (select distinct PLATFORM_NAME from gv$database) loop 97 | dbms_output.put_line('Plataforma.......: ' || lst.platform_name); 98 | end loop; 99 | 100 | dbms_output.put_line('.........................................'); 101 | dbms_output.put_line('Database Version.:'); 102 | 103 | for lst in (select min(inst_id) as inst_id, substr(banner,1,60) version from gv$version group by substr(banner,1,60) order by substr(banner,1,60)) loop 104 | dbms_output.put_line('.................: ' || lst.version); 105 | end loop; 106 | 107 | 108 | IF v_version >= 12 THEN 109 | 110 | dbms_output.put_line(''); 111 | dbms_output.put_line('======================================'); 112 | dbms_output.put_line('PDBs: '); 113 | dbms_output.put_line('======================================'); 114 | dbms_output.put_line(' CON ID | DBID | Name | Open Mode | Restricted | Open Time '); 115 | dbms_output.put_line('---------------|---------------|---------------|---------------|---------------|--------------------'); 116 | 117 | 118 | FOR showpdb IN (SELECT 119 | RPAD(c.CON_ID,15) as CON_ID, 120 | RPAD(c.DBID,15) as DBID, 121 | RPAD(c.NAME,15) as NAME, 122 | --RPAD(c.CON_UID,30) as CON_UID, 123 | --RPAD(c.GUID,30) as GUID, 124 | RPAD(NVL(p.OPEN_MODE, ' '), 15,' ') as OPEN_MODE, 125 | RPAD(NVL(p.RESTRICTED, ' '), 15,' ') as RESTRICTED, 126 | RPAD(NVL(to_char(p.OPEN_TIME,'DD/MM/YYYY HH:MM:SS'), ' '), 20, ' ') as OPEN_TIME 127 | FROM 128 | V$CONTAINERS c 129 | LEFT JOIN V$PDBS p ON 130 | p.CON_ID = c.CON_ID 131 | ORDER BY 132 | c.CON_ID 133 | ) LOOP 134 | --dbms_output.put_line(showpdb.CON_ID || '|' || showpdb.DBID || '|' || showpdb.NAME || '|' || showpdb.CON_UID || '|' || showpdb.GUID || '|' || showpdb.OPEN_MODE || '|' || showpdb.RESTRICTED || '|' || showpdb.OPEN_TIME); 135 | dbms_output.put_line(showpdb.CON_ID || '|' || showpdb.DBID || '|' || showpdb.NAME || '|' || showpdb.OPEN_MODE || '|' || showpdb.RESTRICTED || '|' || showpdb.OPEN_TIME); 136 | END LOOP; 137 | END IF; 138 | 139 | 140 | 141 | dbms_output.put_line(''); 142 | dbms_output.put_line('======================================'); 143 | dbms_output.put_line('Atualizacoes/Upgrade: '); 144 | dbms_output.put_line('======================================'); 145 | dbms_output.put_line(' Action Name | Action | Versao | Comments | ID '); 146 | dbms_output.put_line('-----------------------------------|---------------|----------|-------------------------|--------'); 147 | 148 | FOR atuupg IN (SELECT 149 | RPAD(NVL(to_char(ACTION_TIME,'DD/MM/YYYY HH:MM:SS'),' '),35,' ') as ACTION_TIME, 150 | RPAD(NVL(ACTION,' '),15,' ') as ACTION, 151 | RPAD(NVL(VERSION,' '),10,' ') as VERSION, 152 | RPAD(NVL(COMMENTS,' '),25,' ') as COMMENTS, 153 | RPAD(ID,8) as ID 154 | FROM 155 | dba_registry_history 156 | ORDER BY 157 | action_time ASC 158 | ) LOOP 159 | dbms_output.put_line(atuupg.ACTION_TIME || '|' || atuupg.ACTION || '|' || atuupg.VERSION || '|' || atuupg.COMMENTS || atuupg.ID); 160 | END LOOP; 161 | 162 | dbms_output.put_line(''); 163 | dbms_output.put_line('======================================================================================='); 164 | dbms_output.put_line(' Options/Feature ativas no database'); 165 | dbms_output.put_line('Importante: Normalmente, mas nem sempre, as OPTIONS devem ser adquiridas separadamente,'); 166 | dbms_output.put_line(' enquanto as features ja sao fornecidas com a versao adquirida do banco.'); 167 | dbms_output.put_line('======================================================================================='); 168 | 169 | 170 | dbms_output.put_line(''); 171 | dbms_output.put_line('======================================'); 172 | dbms_output.put_line('Options/Features: '); 173 | dbms_output.put_line('======================================'); 174 | 175 | FOR options IN (SELECT INST_ID , UPPER(parameter) AS PARAMETER FROM gv$option WHERE VALUE = 'TRUE' ORDER BY INST_ID, PARAMETER) LOOP 176 | dbms_output.put_line('A option/feature "' || options.parameter || '" esta ativa - thread '|| options.inst_id ||'.'); 177 | END LOOP; 178 | 179 | dbms_output.put_line(''); 180 | dbms_output.put_line('======================================'); 181 | dbms_output.put_line('Componentes instalados: '); 182 | dbms_output.put_line('======================================'); 183 | dbms_output.put_line(' ID | Nome | Versao | Status | Data | Schema'); 184 | dbms_output.put_line('----------|--------------------------------------------------|---------------|---------------|----------------------|---------'); 185 | 186 | FOR registry IN (SELECT 187 | RPAD(comp_id,10) AS comp_id, 188 | RPAD(comp_name,50) AS comp_name, 189 | RPAD(version,15) AS version, 190 | RPAD(status,15) as status, 191 | RPAD(modified,22) AS modified, 192 | RPAD(schema,15) AS schema 193 | FROM dba_registry) 194 | LOOP 195 | dbms_output.put_line(registry.comp_id || '|' || registry.comp_name || '|' || registry.version || '|' || registry.status || '|' || registry.modified || '|' || registry.schema); 196 | END LOOP; 197 | 198 | dbms_output.put_line(''); 199 | dbms_output.put_line('======================================'); 200 | dbms_output.put_line('Registro de utilizacao de features: '); 201 | dbms_output.put_line('======================================'); 202 | dbms_output.put_line(' Feature | Version |Usages|Cur. Used | Last Usage | Fisrt Usage'); 203 | dbms_output.put_line('-----------------------------------------------------------------|------------|------|----------|------------|-------------'); 204 | 205 | FOR optusage IN ( 206 | select 207 | RPAD(substr(u1.name,1,60),65) as name, 208 | RPAD(substr(u1.version,1,10),12) as version, 209 | RPAD(u1.detected_usages,6) as detected_usages, 210 | RPAD(substr(u1.currently_used,1,5),10) as currently_used, 211 | RPAD(TO_CHAR(u1.last_usage_date,'DD/MM/YYYY'),12) as last_usage_date, 212 | RPAD(TO_CHAR(u1.first_usage_date,'DD/MM/YYYY'),12) as first_usage_date 213 | FROM DBA_FEATURE_USAGE_STATISTICS u1 214 | WHERE 215 | version = (SELECT MAX(u2.version) 216 | FROM dba_feature_usage_statistics u2 217 | WHERE u2.name = u1.name) 218 | AND u1.detected_usages > 0 219 | ORDER BY u1.name, u1.version, u1.last_usage_date desc, u1.first_usage_date desc 220 | ) LOOP 221 | dbms_output.put_line(optusage.name || '|' || optusage.version || '|' || optusage.detected_usages || '|' || optusage.currently_used || '|' || optusage.first_usage_date || '|' || optusage.last_usage_date); 222 | END LOOP; 223 | 224 | dbms_output.put_line(''); 225 | dbms_output.put_line('========================================================================================'); 226 | dbms_output.put_line('Para mais detalhes, executar o script options_packs_usage_statistics.sql (MOS 1317265.1)'); 227 | dbms_output.put_line('========================================================================================'); 228 | 229 | dbms_output.put_line(''); 230 | dbms_output.put_line(''); 231 | dbms_output.put_line('============================='); 232 | dbms_output.put_line('Limites utilizados na Istance'); 233 | dbms_output.put_line('============================='); 234 | dbms_output.put_line('Instance | Sessoes | Usuarios | CPUs | Cores '); 235 | dbms_output.put_line('---------|------------|-------------|---------|---------'); 236 | 237 | FOR license IN ( 238 | SELECT 239 | RPAD(inst_id,8) inst_id, 240 | RPAD(sessions_max,10) AS sessions, 241 | RPAD(users_max,11) AS users, 242 | RPAD(NVL(cpu_core_count_highwater,0),7) AS cpu, 243 | RPAD(NVL(cpu_socket_count_highwater,0),7) AS socket 244 | FROM gv$license 245 | ORDER BY inst_id 246 | ) LOOP 247 | dbms_output.put_line(license.inst_id || ' | ' || license.sessions || ' | ' || license.users || ' | ' || license.cpu || ' | ' || license.socket); 248 | END LOOP; 249 | 250 | dbms_output.put_line(''); 251 | dbms_output.put_line(''); 252 | dbms_output.put_line('==============================='); 253 | dbms_output.put_line('Parametros de Localizacao (NLS)'); 254 | dbms_output.put_line('==============================='); 255 | dbms_output.put_line('ID | Parametro | Valor'); 256 | dbms_output.put_line('---|----------------------------------------------------|---------------------------------'); 257 | FOR nls IN ( 258 | SELECT 259 | ' ' AS INST_ID, 260 | RPAD('DATABASE:',50) AS NAME, 261 | ' ' AS VALUE 262 | FROM DUAL 263 | UNION ALL 264 | SELECT 265 | ' ' AS INST_ID, 266 | RPAD(PROPERTY_NAME || '(DATABASE)',50) AS NAME, 267 | PROPERTY_VALUE AS VALUE 268 | FROM database_properties 269 | WHERE property_name IN ( 270 | 'NLS_CHARACTERSET', 271 | 'NLS_DATE_FORMAT', 272 | 'NLS_LANGUAGE', 273 | 'NLS_DATE_LANGUAGE', 274 | 'NLS_NUMERIC_CHARACTERS', 275 | 'NLS_TERRITORY', 276 | 'DBTIMEZONE') 277 | UNION ALL 278 | SELECT 279 | ' ' AS INST_ID, 280 | RPAD('SESSION:',50) AS NAME, 281 | ' ' AS VALUE 282 | FROM DUAL 283 | UNION ALL 284 | SELECT 285 | TO_CHAR(INST_ID,9) AS INST_ID, 286 | RPAD(PARAMETER || '(SESSION)',50) AS NAME, 287 | VALUE AS VALUE 288 | FROM GV$NLS_PARAMETERS 289 | WHERE PARAMETER IN ( 290 | 'NLS_DATE_LANGUAGE', 291 | 'NLS_DATE_FORMAT', 292 | 'NLS_LANGUAGE', 293 | 'NLS_TERRITORY') 294 | ORDER BY NAME,INST_ID 295 | ) LOOP 296 | dbms_output.put_line(nls.inst_id || ' | ' || nls.name || ' | ' || nls.value); 297 | END LOOP; 298 | 299 | dbms_output.put_line(''); 300 | dbms_output.put_line(''); 301 | dbms_output.put_line('======================================='); 302 | dbms_output.put_line('Parametros de Memoria da Instance(s)'); 303 | dbms_output.put_line('======================================='); 304 | dbms_output.put_line('ID Parametro | Valor (MB)'); 305 | dbms_output.put_line('--|----------------------------------------------------|---------------------------------'); 306 | 307 | FOR mem IN ( 308 | SELECT 309 | INST_ID, 310 | RPAD(name,50) AS parameter, 311 | ROUND(VALUE/1024/1024) AS valor_mb 312 | FROM gv$parameter 313 | WHERE name IN ( 314 | 'db_cache_size', 315 | 'large_pool_size', 316 | 'java_pool_size', 317 | 'sga_max_size', 318 | 'sga_target', 319 | 'shared_pool_size', 320 | 'pga_aggregate_target', 321 | 'memory_target', 322 | 'memory_max_target') 323 | ORDER BY name,inst_id 324 | ) LOOP 325 | dbms_output.put_line(mem.inst_id || ' | ' || mem.parameter || ' | ' || mem.valor_mb); 326 | END LOOP; 327 | 328 | dbms_output.put_line(''); 329 | dbms_output.put_line(''); 330 | dbms_output.put_line('======================================='); 331 | dbms_output.put_line('Parametros principais da Instance(s)'); 332 | dbms_output.put_line('======================================='); 333 | dbms_output.put_line('ID Parametro | Valor'); 334 | dbms_output.put_line('--|----------------------------------------------------|---------------------------------'); 335 | 336 | FOR mem IN ( 337 | SELECT 338 | INST_ID, 339 | RPAD(name,50) AS parameter, 340 | VALUE AS valor_mb 341 | FROM gv$parameter 342 | WHERE name IN ( 343 | 'sessions', 344 | 'processes', 345 | 'open_cursors', 346 | 'cursor_sharing', 347 | 'audit_file_dest', 348 | 'audit_syslog_level', 349 | 'audit_sys_operations', 350 | 'audit_trail', 351 | 'background_dump_dest', 352 | 'cluster_database', 353 | 'cluster_database_instances', 354 | 'cluster_interconnects', 355 | 'compatible', 356 | 'control_files', 357 | 'control_management_pack_access', 358 | 'core_dump_dest', 359 | 'cursor_sharing', 360 | 'db_block_size', 361 | 'db_cache_size', 362 | 'db_create_file_dest', 363 | 'db_create_online_log_dest_1', 364 | 'db_create_online_log_dest_2', 365 | 'db_file_multiblock_read_count', 366 | 'db_file_name_convert', 367 | 'db_flashback_retention_target', 368 | 'db_flash_cache_file', 369 | 'db_flash_cache_size', 370 | 'db_name', 371 | 'db_recovery_file_dest', 372 | 'db_recovery_file_dest_size', 373 | 'db_unique_name', 374 | 'dg_broker_config_file1', 375 | 'dg_broker_config_file2', 376 | 'dg_broker_start', 377 | 'diagnostic_dest', 378 | 'enable_ddl_logging', 379 | 'enable_goldengate_replication', 380 | 'global_names', 381 | 'instance_name', 382 | 'instance_number', 383 | 'job_queue_processes', 384 | 'listener_networks', 385 | 'local_listener', 386 | 'log_archive_dest_1', 387 | 'log_archive_format', 388 | 'recyclebin', 389 | 'remote_listener', 390 | 'service_names', 391 | 'spfile', 392 | 'undo_management', 393 | 'undo_retention') 394 | ORDER BY name,inst_id 395 | ) LOOP 396 | dbms_output.put_line(mem.inst_id || ' | ' || mem.parameter || ' | ' || mem.valor_mb); 397 | END LOOP; 398 | 399 | dbms_output.put_line(''); 400 | dbms_output.put_line(''); 401 | dbms_output.put_line('====================================='); 402 | dbms_output.put_line('Informacoes Gerais do tamanho da base'); 403 | dbms_output.put_line('====================================='); 404 | dbms_output.put_line(' Dados | Undo | Redos | Temp | Livre | Total ' ); 405 | dbms_output.put_line('-----------|------------|------------|------------|------------|------------'); 406 | 407 | FOR tam IN ( 408 | select LPAD(to_char(sum(dados) / 1048576, 'fm99g999g990'),10,' ') dados, 409 | LPAD(to_char(sum(undo) / 1048576, 'fm99g999g990'),10,' ') undo, 410 | LPAD(to_char(sum(redo) / 1048576, 'fm99g999g990'),10,' ') redo, 411 | LPAD(to_char(sum(temp) / 1048576, 'fm99g999g990'),10,' ') temp, 412 | LPAD(to_char(sum(free) / 1048576, 'fm99g999g990'),10,' ') livre, 413 | LPAD(to_char(sum(dados + undo + redo + temp) / 1048576, 'fm99g999g990'),10,' ') total 414 | from ( 415 | select sum(decode(substr(t.contents, 1, 1), 'P', bytes, 0)) dados, 416 | sum(decode(substr(t.contents, 1, 1), 'U', bytes, 0)) undo, 417 | 0 redo, 418 | 0 temp, 419 | 0 free 420 | from dba_data_files f, dba_tablespaces t 421 | where f.tablespace_name = t.tablespace_name 422 | union all 423 | select 0 dados, 424 | 0 undo, 425 | 0 redo, 426 | sum(bytes) temp, 427 | 0 free 428 | from dba_temp_files f, dba_tablespaces t 429 | where f.tablespace_name = t.tablespace_name(+) 430 | union all 431 | select 0 dados, 432 | 0 undo, 433 | sum(bytes * members) redo, 434 | 0 temp, 435 | 0 free 436 | from v$log 437 | union all 438 | select 0 dados, 439 | 0 undo, 440 | 0 redo, 441 | 0 temp, 442 | sum(bytes) free 443 | from dba_free_space f, dba_tablespaces t 444 | where f.tablespace_name = t.tablespace_name and 445 | substr(t.contents, 1, 1) = 'P' 446 | ) 447 | ) LOOP 448 | dbms_output.put_line(tam.dados || ' | ' || 449 | tam.undo || ' | ' || 450 | tam.redo || ' | ' || 451 | tam.temp || ' | ' || 452 | tam.livre || ' | ' || 453 | tam.total); 454 | END LOOP; 455 | 456 | dbms_output.put_line(''); 457 | dbms_output.put_line(''); 458 | dbms_output.put_line('==========================='); 459 | dbms_output.put_line('Informacoes das tablespaces'); 460 | dbms_output.put_line('==========================='); 461 | dbms_output.put_line(' Tablespace | T | Em Uso (MB) | Atual (MB) | Maximo (MB | Atual Livre (MB)| Max. Livre (MB)| % Ocupada' ); 462 | dbms_output.put_line('---------------------|---|-----------------|-----------------|-----------------|-----------------|----------------|-----------------'); 463 | 464 | FOR tbs IN ( 465 | select 466 | rpad(t.tablespace_name,20) ktablespace, 467 | rpad(substr(t.contents, 1, 1),1) tipo, 468 | lpad(trunc((d.tbs_size-nvl(s.free_space, 0))/1024/1024),15) ktbs_em_uso, 469 | lpad(trunc(d.tbs_size/1024/1024),15) ktbs_size, 470 | lpad(trunc(d.tbs_maxsize/1024/1024),15) ktbs_maxsize, 471 | lpad(trunc(nvl(s.free_space, 0)/1024/1024),15) kfree_space, 472 | lpad(trunc((d.tbs_maxsize - d.tbs_size + nvl(s.free_space, 0))/1024/1024),14) kspace, 473 | lpad(decode(d.tbs_maxsize, 0, 0, trunc((d.tbs_size-nvl(s.free_space, 0))*100/d.tbs_maxsize)),7) kperc 474 | from 475 | (select SUM(bytes) tbs_size, 476 | SUM(decode(sign(maxbytes - bytes), -1, bytes, maxbytes)) tbs_maxsize, 477 | tablespace_name tablespace 478 | from 479 | (select nvl(bytes, 0) bytes, nvl(maxbytes, 0) maxbytes, tablespace_name 480 | from dba_data_files 481 | union all 482 | select nvl(bytes, 0) bytes, nvl(maxbytes, 0) maxbytes, tablespace_name 483 | from dba_temp_files 484 | ) 485 | group by tablespace_name 486 | ) d, 487 | (select SUM(bytes) free_space, 488 | tablespace_name tablespace 489 | from dba_free_space 490 | group by tablespace_name 491 | ) s, 492 | dba_tablespaces t 493 | where t.tablespace_name = d.tablespace(+) and 494 | t.tablespace_name = s.tablespace(+) 495 | order by 1 496 | ) LOOP 497 | dbms_output.put_line(tbs.KTABLESPACE || ' | ' || 498 | tbs.TIPO || ' | ' || 499 | tbs.KTBS_EM_USO || ' | ' || 500 | tbs.KTBS_SIZE || ' | ' || 501 | tbs.KTBS_MAXSIZE || ' | ' || 502 | tbs.KFREE_SPACE || ' | ' || 503 | tbs.KSPACE || ' | ' || 504 | tbs.KPERC); 505 | END LOOP; 506 | 507 | dbms_output.put_line(''); 508 | dbms_output.put_line(''); 509 | dbms_output.put_line('========================='); 510 | dbms_output.put_line('Informacoes dos datafiles'); 511 | dbms_output.put_line('========================='); 512 | dbms_output.put_line(' ID | Tablespace | Datafile | Extend | Status | Em Uso(MB) | Maximo(MB)' ); 513 | dbms_output.put_line('----|-----------------|----------------------------------------------------|----------|----------|------------|-----------' ); 514 | FOR dataf IN ( 515 | select 516 | rpad(a.file_id,3) kfile_id, 517 | rpad(a.tablespace_name,15) ktablespace_name, 518 | rpad(a.file_name,50) kfile_name, 519 | rpad(a.autoextensible,8) kautoextensible, 520 | rpad(b.status,8) kstatus, 521 | rpad(trunc(a.bytes/1024/1024),10) kbytes, 522 | rpad(trunc(a.maxbytes/1024/1024),10) kmaxsize 523 | from dba_data_files a, v$datafile b 524 | where a.file_id = b.file# 525 | order by a.tablespace_name, a.file_id 526 | ) LOOP 527 | 528 | dbms_output.put_line( 529 | dataf.kfile_id || ' | ' || 530 | dataf.ktablespace_name || ' | ' || 531 | dataf.kfile_name || ' | ' || 532 | dataf.kautoextensible || ' | ' || 533 | dataf.kstatus || ' | ' || 534 | dataf.kbytes || ' | ' || 535 | dataf.kmaxsize 536 | ); 537 | END LOOP; 538 | 539 | dbms_output.put_line(''); 540 | dbms_output.put_line(''); 541 | dbms_output.put_line('============================================='); 542 | dbms_output.put_line('Informacoes dos Grupos e Arquivos de REDOLOGs'); 543 | dbms_output.put_line('============================================='); 544 | dbms_output.put_line('Grupo | Thread | Tamanho (MB) | Arquivo'); 545 | dbms_output.put_line('------|--------|--------------|---------------------------------------------------'); 546 | 547 | FOR log IN ( 548 | SELECT 549 | f.GROUP# AS grupo, 550 | l.THREAD#, 551 | ROUND(l.bytes/1024/1024) AS tamanho, 552 | f.member AS arquivo 553 | FROM v$logfile f, v$log l 554 | WHERE f.GROUP# = l.GROUP# 555 | ORDER BY grupo, arquivo) LOOP 556 | dbms_output.put_line(lpad( log.grupo,5) || ' | ' || lpad( log.thread#,6) || ' | ' || lpad(log.tamanho,12) || ' | ' || log.arquivo); 557 | END LOOP; 558 | 559 | dbms_output.put_line(''); 560 | dbms_output.put_line(''); 561 | dbms_output.put_line('==========================================='); 562 | dbms_output.put_line('Informacoes de Localizacao dos ControlFiles'); 563 | dbms_output.put_line('==========================================='); 564 | 565 | FOR control IN ( SELECT name FROM v$controlfile) LOOP 566 | dbms_output.put_line('Arquivo: ' || control.name); 567 | END LOOP; 568 | 569 | IF v_log_mode = 'ARCHIVELOG' THEN 570 | 571 | SELECT 572 | ROUND(SUM(blocks * block_size) / to_number( MAX(first_time) - MIN(first_time)) /1024/1024) AS media 573 | INTO v_media_archive 574 | FROM V$ARCHIVED_LOG; 575 | 576 | dbms_output.put_line(''); 577 | dbms_output.put_line(''); 578 | dbms_output.put_line('==============================================='); 579 | dbms_output.put_line('Informacoes Basicas Sobre a Geracao de ARCHIVES'); 580 | dbms_output.put_line('==============================================='); 581 | dbms_output.put_line(' '); 582 | dbms_output.put_line('Quantidade media de archive gerados por dia: ' || v_media_archive || 'MB'); 583 | dbms_output.put_line(' '); 584 | dbms_output.put_line('ID | Status | Tipo | Destino | Arquivo'); 585 | dbms_output.put_line('---|------------|------------|------------|--------'); 586 | 587 | FOR arch IN ( 588 | SELECT 589 | RPAD(dest_id, 2) as id, 590 | RPAD(STATUS,10) as STATUS, 591 | RPAD(binding,10) AS tipo, 592 | RPAD(target,10) AS destino, 593 | destination AS arquivo 594 | FROM v$archive_dest 595 | WHERE destination IS NOT NULL) LOOP 596 | 597 | dbms_output.put_line(arch.id || ' | ' || arch.STATUS || ' | ' || arch.tipo || ' | ' || arch.destino || ' | ' || arch.arquivo 598 | 599 | ); 600 | END LOOP; 601 | 602 | 603 | dbms_output.put_line(''); 604 | dbms_output.put_line(''); 605 | dbms_output.put_line('====================================='); 606 | dbms_output.put_line('Geracao de ARCHIVES - Ultimos 10 dias'); 607 | dbms_output.put_line('====================================='); 608 | dbms_output.put_line(''); 609 | dbms_output.put_line(' Dia | Thread | Em MB | Em GB | Total gerado'); 610 | dbms_output.put_line('--------------------------|---------|------------|------------|-------------'); 611 | 612 | FOR arch2 IN ( 613 | select 614 | RPAD(trunc(COMPLETION_TIME,'DD'),25,' ') day, 615 | LPAD(thread#,7,' ') thread, 616 | LPAD(round(sum(BLOCKS*BLOCK_SIZE)/1024/1024),10,' ') mb, 617 | LPAD(round(sum(BLOCKS*BLOCK_SIZE)/1024/1024/1024),10,' ') gb, 618 | LPAD(count(*),10,' ') total 619 | from v$archived_log 620 | where COMPLETION_TIME > sysdate-10 AND 621 | CREATOR != 'RMAN' 622 | group by trunc(COMPLETION_TIME,'DD'), 623 | thread# order by 1,2 624 | ) LOOP 625 | 626 | dbms_output.put_line(arch2.day || ' | ' || arch2.thread || ' | ' || arch2.mb || ' | ' || arch2.gb || ' | ' || arch2.total 627 | 628 | ); 629 | END LOOP; 630 | 631 | dbms_output.put_line(''); 632 | dbms_output.put_line(''); 633 | dbms_output.put_line('======================================'); 634 | dbms_output.put_line('Geracao de ARCHIVES - Ultimas 24 horas'); 635 | dbms_output.put_line('======================================'); 636 | dbms_output.put_line(''); 637 | dbms_output.put_line(' Data | Thread | Em MB | Em GB | Total gerado'); 638 | dbms_output.put_line('--------------------------|---------|------------|------------|-------------'); 639 | 640 | FOR arch3 IN ( 641 | SELECT 642 | RPAD(trunc(COMPLETION_TIME,'HH'),25,' ') Hour, 643 | LPAD(thread#,7,' ') thread, 644 | LPAD(round(sum(BLOCKS*BLOCK_SIZE)/1024/1024),10,' ') MB, 645 | LPAD(round(sum(BLOCKS*BLOCK_SIZE)/1024/1024/1024),10,' ') GB, 646 | LPAD(count(*),10,' ') Total 647 | from v$archived_log 648 | WHERE COMPLETION_TIME >= SYSDATE-1 649 | group by trunc(COMPLETION_TIME,'HH'),thread# 650 | order by 1 desc 651 | ) LOOP 652 | 653 | dbms_output.put_line(arch3.hour || ' | ' || arch3.thread || ' | ' || arch3.mb || ' | ' || arch3.gb || ' | ' || arch3.total 654 | 655 | ); 656 | END LOOP; 657 | 658 | END IF; 659 | 660 | dbms_output.put_line(''); 661 | dbms_output.put_line(''); 662 | dbms_output.put_line('=========================================='); 663 | dbms_output.put_line('Informacoes sobre a quantidade de Sessoes'); 664 | dbms_output.put_line('=========================================='); 665 | dbms_output.put_line(' Instance | Hostname | Status | Sessions '); 666 | dbms_output.put_line('---------------------|----------------------|------------|------------'); 667 | FOR sess IN ( 668 | select 669 | LPAD(c.instance_name,20,' ') instance_name, 670 | LPAD(c.host_name,20,' ') hostname, 671 | LPAD(c.status,10,' ') status, 672 | LPAD(to_char(l.sessions_current,'fm99g999g990'),10,' ') sessions 673 | from gv$instance c, 674 | gv$license l, 675 | v$instance i 676 | where c.instance_number = i.instance_number (+) 677 | and c.thread# = i.thread# (+) 678 | and l.inst_id = c.inst_id ) LOOP 679 | dbms_output.put_line( 680 | sess.instance_name || ' | ' || 681 | sess.hostname || ' | ' || 682 | sess.status || ' | ' || 683 | sess.sessions); 684 | END LOOP; 685 | 686 | 687 | dbms_output.put_line(''); 688 | dbms_output.put_line(''); 689 | dbms_output.put_line('======================================================'); 690 | dbms_output.put_line('Informacoes Gerais - Quantidade de Processos'); 691 | dbms_output.put_line('======================================================'); 692 | dbms_output.put_line(' Instance | Hostname | Total '); 693 | dbms_output.put_line('---------------------|----------------------|----------'); 694 | FOR proc IN ( 695 | select 696 | LPAD(i.instance_name,20,' ') instance_name, 697 | LPAD(i.host_name,20,' ') hostname, 698 | count(1) as tot 699 | from gv$process p 700 | join gv$instance i on i.INSTANCE_NUMBER = p.inst_id 701 | group by i.INSTANCE_NAME, i.HOST_NAME 702 | order by i.INSTANCE_NAME, i.HOST_NAME 703 | ) LOOP 704 | dbms_output.put_line( 705 | proc.instance_name || ' | ' || 706 | proc.hostname || ' | ' || 707 | proc.tot 708 | ); 709 | END LOOP; 710 | 711 | 712 | dbms_output.put_line(''); 713 | dbms_output.put_line(''); 714 | dbms_output.put_line('Logs do grupo ADMIN'); 715 | dbms_output.put_line('==================='); 716 | dbms_output.put_line('Nome | Diretorio'); 717 | dbms_output.put_line('----------------|----------'); 718 | FOR admin IN ( 719 | SELECT RPAD(name,15) log, VALUE 720 | FROM v$parameter 721 | WHERE name IN ('background_dump_dest', 'background_core_dump', 'core_dump_dest','user_dump_dest') 722 | ORDER BY NAME) LOOP 723 | dbms_output.put_line(admin.log || ' | ' || admin.VALUE); 724 | END LOOP; 725 | dbms_output.put_line(''); 726 | 727 | dbms_output.put_line('Configuracoes de auditoria e seguranca'); 728 | dbms_output.put_line('======================================'); 729 | dbms_output.put_line('Parametro | Valor'); 730 | dbms_output.put_line('----------------|------'); 731 | FOR security IN ( 732 | SELECT RPAD(name,15) log, VALUE 733 | FROM v$parameter 734 | WHERE name IN ('audit_sys_operations', 'audit_file_dest','audit_trail', 'os_authent_prefix', 'remote_os_authent', 735 | 'remote_login_passwordfile', 'utl_file_dir') 736 | ORDER BY NAME) LOOP 737 | dbms_output.put_line(security.log || ' | ' || security.VALUE); 738 | END LOOP; 739 | dbms_output.put_line(''); 740 | 741 | END; 742 | / 743 | 744 | SET serveroutput OFF 745 | SET serveroutput ON SIZE 1000000 FORMAT WRAPPED 746 | 747 | BEGIN 748 | dbms_output.put_line(''); 749 | dbms_output.put_line(''); 750 | dbms_output.put_line('======================================'); 751 | dbms_output.put_line('Jobs agendados (Jobs and Scheduller)'); 752 | dbms_output.put_line('======================================'); 753 | dbms_output.put_line(''); 754 | dbms_output.put_line('=================='); 755 | dbms_output.put_line('Jobs - Scheduller'); 756 | dbms_output.put_line('=================='); 757 | --dbms_output.put_line('ID| Owner | Job Name | Job Action |Enable| State | Interval | Next Run'); 758 | --dbms_output.put_line('--|------------|--------------------------|-----------------------------|------|-----------|------------------------------|--------------------'); 759 | dbms_output.put_line('ID| Owner | Job Name |Enable| State | Interval | Next Run'); 760 | dbms_output.put_line('--|------------|--------------------------------|------|-----------|------------------------------|--------------------'); 761 | 762 | FOR job2 IN ( 763 | select 764 | RPAD(NVL(substr(INSTANCE_ID,1,2),' '),2) AS ID, 765 | RPAD(SUBSTR(OWNER,1,10),12) AS OWNER, 766 | RPAD(SUBSTR(JOB_NAME,1,30),32) AS JOB_NAME, 767 | --RPAD(NVL(SUBSTR(JOB_ACTION,1,27),' '),27) AS JOB_ACTION, 768 | RPAD(NVL(SUBSTR(ENABLED,1,5),' '),5,' ') AS ENABLE, 769 | RPAD(NVL(SUBSTR(STATE,1,10),' '),11,' ') AS STATE, 770 | RPAD(NVL(SUBSTR(REPEAT_INTERVAL,1,30),' '),30,' ') AS REPEAT_INTERVAL, 771 | RPAD(NVL(TO_CHAR(NEXT_RUN_DATE,'DD/MM/YYYY HH24:Mi:SS'),' '),19, ' ') AS NEXT_RUN_DATE 772 | FROM 773 | dba_scheduler_jobs 774 | WHERE ENABLED != 'FALSE' 775 | ORDER BY 776 | STATE DESC, OWNER, ID, JOB_NAME 777 | ) LOOP 778 | dbms_output.put_line( 779 | job2.id || '|' || 780 | job2.owner || '|' || 781 | job2.job_name || '|' || 782 | --job2.job_action || '|' || 783 | job2.enable || '|' || 784 | job2.state || '|' || 785 | job2.repeat_interval || '|' || 786 | job2.next_run_date); 787 | END LOOP; 788 | 789 | 790 | dbms_output.put_line(''); 791 | dbms_output.put_line('=================='); 792 | dbms_output.put_line('Jobs - DBA_JOBS'); 793 | dbms_output.put_line('=================='); 794 | 795 | dbms_output.put_line(' Nr | Esquema | Dur.(min) | BK| Intervalo | SQL'); 796 | dbms_output.put_line('-------|-----------------|-----------|---|-------------------------------------|----------'); 797 | FOR job IN ( 798 | SELECT LPAD(job,6) id, RPAD(schema_user,15) esquema, RPAD(TRUNC(total_time/60),9) dur_mi, 799 | broken, RPAD(INTERVAL,35) INTERVAL, what 800 | FROM dba_jobs 801 | WHERE INTERVAL !='null' 802 | ) LOOP 803 | dbms_output.put_line(job.id || ' | ' || job.esquema || ' | ' || job.dur_mi || ' | ' || job.broken || ' | ' || job.INTERVAL || ' | ' || job.what); 804 | END LOOP; 805 | END; 806 | / 807 | 808 | SET serveroutput OFF 809 | SET serveroutput ON SIZE 1000000 FORMAT WRAPPED 810 | 811 | BEGIN 812 | dbms_output.put_line(''); 813 | dbms_output.put_line(''); 814 | dbms_output.put_line('========================================'); 815 | dbms_output.put_line('Segmentos por esquema, tablespace e tipo'); 816 | dbms_output.put_line('========================================'); 817 | dbms_output.put_line('Esquema | Tablespace | Tipo de Objeto | QT | Tam(MB)'); 818 | dbms_output.put_line('----------------|-----------------|-----------------|------|--------'); 819 | FOR schema IN ( 820 | SELECT 821 | RPAD(owner,15) schema, 822 | RPAD(tablespace_name, 15) tablespace, 823 | RPAD(segment_type,15) TYPE, 824 | LPAD(COUNT(*),4) qt, LPAD(ROUND(SUM(bytes)/1024/1024),6) mb 825 | FROM dba_segments 826 | --WHERE OWNER NOT IN ('SYS','OUTLN','SYSTEM','WMSYS','XDB') 827 | GROUP BY owner, tablespace_name, segment_type 828 | ORDER BY owner, tablespace_name, segment_type) LOOP 829 | dbms_output.put_line(schema.schema || ' | ' || schema.tablespace || ' | ' 830 | || schema.TYPE || ' | ' || schema.qt || ' | ' || schema.mb); 831 | END LOOP; 832 | dbms_output.put_line(''); 833 | END; 834 | / 835 | 836 | SET serveroutput OFF 837 | SET serveroutput ON SIZE 1000000 FORMAT WRAPPED 838 | 839 | BEGIN 840 | dbms_output.put_line(''); 841 | dbms_output.put_line('===================================='); 842 | dbms_output.put_line('Objetos invalidos por tipo'); 843 | dbms_output.put_line('===================================='); 844 | dbms_output.put_line(' Owner | Object Name | Type '); 845 | dbms_output.put_line('----------------|------------------------------------------|------------------------------'); 846 | FOR invalid IN ( 847 | SELECT RPAD(owner,15,' ') as owner, RPAD(object_name,40,' ') as name, LPAD(object_type,25,' ') AS type 848 | FROM dba_objects 849 | WHERE STATUS != 'VALID' 850 | order by owner, object_type, object_name 851 | ) LOOP 852 | dbms_output.put_line(invalid.owner || ' | ' || invalid.name || ' | ' || invalid.type); 853 | END LOOP; 854 | dbms_output.put_line(''); 855 | END; 856 | / 857 | 858 | SET serveroutput OFF 859 | SET serveroutput ON SIZE 1000000 FORMAT WRAPPED FORMAT WRAPPED 860 | 861 | BEGIN 862 | dbms_output.put_line(''); 863 | dbms_output.put_line('=========='); 864 | dbms_output.put_line('Diretorios'); 865 | dbms_output.put_line('=========='); 866 | dbms_output.put_line('Esquema | Nome | Diretorio'); 867 | dbms_output.put_line('----------------|--------------------------------|----------'); 868 | FOR directory IN ( 869 | SELECT 870 | RPAD(owner,15) AS esquema, 871 | RPAD(directory_name,30) nome, 872 | directory_path AS path 873 | FROM dba_directories ORDER BY owner, path) LOOP 874 | dbms_output.put_line(directory.esquema || ' | ' || directory.nome || ' | ' || 875 | directory.path); 876 | END LOOP; 877 | dbms_output.put_line(''); 878 | dbms_output.put_line(''); 879 | dbms_output.put_line('=============='); 880 | dbms_output.put_line('Database Links'); 881 | dbms_output.put_line('=============='); 882 | dbms_output.put_line('Esquema | Nome | Criacao |' || 883 | ' Esquema remoto | Host remoto'); 884 | dbms_output.put_line('----------------|-----------------|------------|' || 885 | '-----------------|------------'); 886 | FOR dblink IN ( 887 | SELECT 888 | RPAD(owner,15) AS esquema, 889 | RPAD(db_link,15) nome, 890 | RPAD(username,15) esquema_destino, 891 | host host_destino, 892 | to_char(created,'DD-MM-YYYY') criacao 893 | FROM dba_db_links ORDER BY host, owner) LOOP 894 | dbms_output.put_line(dblink.esquema || ' | ' || dblink.nome || ' | ' || 895 | dblink.criacao || ' | ' || dblink.esquema_destino || ' | ' || dblink.host_destino); 896 | END LOOP; 897 | 898 | dbms_output.put_line(''); 899 | dbms_output.put_line(''); 900 | dbms_output.put_line('===================='); 901 | dbms_output.put_line('Views Materializadas'); 902 | dbms_output.put_line('===================='); 903 | dbms_output.put_line('Esquema | Nome | Q Len | Atualiz. | DBLink'); 904 | dbms_output.put_line('----------------|-----------------|-------|----------|-------'); 905 | FOR mview IN ( 906 | SELECT RPAD(owner,15) esquema, RPAD(mview_name,15) nome, RPAD(master_link,15) link, 907 | LPAD(query_len,5) len, last_refresh_date FROM dba_mviews 908 | ) LOOP 909 | dbms_output.put_line(mview.esquema || ' | ' || mview.nome || ' | ' || mview.len || 910 | ' | ' || mview.last_refresh_date || ' | ' || mview.link); 911 | END LOOP; 912 | dbms_output.put_line(''); 913 | 914 | dbms_output.put_line(''); 915 | dbms_output.put_line(''); 916 | dbms_output.put_line('===================================='); 917 | dbms_output.put_line('Informacoes do Storage - ASM'); 918 | dbms_output.put_line('===================================='); 919 | END; 920 | / 921 | 922 | -- Melhorar isso 923 | COLUMN path format a45 924 | COLUMN type FORMAT a6 HEAD 'Type' 925 | COLUMN TOTAL_GB FORMAT 999,999,999 HEAD 'Total (GB)' 926 | COLUMN FREE_GB FORMAT 999,999.999 HEAD 'Free (GB)' 927 | 928 | select 929 | GROUP_NUMBER, 930 | NAME, 931 | PATH, 932 | (TOTAL_MB/1024) AS TOTAL_GB, 933 | (FREE_MB/1024) AS FREE_GB, 934 | STATE 935 | from 936 | v$asm_disk 937 | ORDER BY 938 | GROUP_NUMBER, 939 | NAME; 940 | 941 | select 942 | GROUP_NUMBER, 943 | NAME, 944 | TYPE, 945 | (TOTAL_MB/1024) AS TOTAL_GB, 946 | (FREE_MB/1024) AS FREE_GB, 947 | to_char((100*FREE_MB/TOTAL_MB),999.99) || '%' Livre, 948 | to_char((((TOTAL_MB - FREE_MB) / TOTAL_MB) * 100),999.99)|| ' %' Ocupado, 949 | STATE 950 | from 951 | v$asm_diskgroup 952 | where 953 | TOTAL_MB > 0 954 | order by 955 | GROUP_NUMBER, 956 | NAME; 957 | 958 | 959 | spool off 960 | SET feedback ON 961 | SET LINESIZE 120 962 | -------------------------------------------------------------------------------- /ENVIRONMENT/showmetrics.sql: -------------------------------------------------------------------------------- 1 | --#/*************************************************************************************************/ 2 | --#/* Script : showmetrics.sql */ 3 | --#/* Author : Mario Barduchi */ 4 | --#/* E-mail : mario.barduchi@gmail.com */ 5 | --#/* Date : 03/03/2025 */ 6 | --#/* Original : None */ 7 | --#/* Description : Summary of some system metric values for the long-duration system */ 8 | --#/* accumulated in the period. */ 9 | --#/* Location : /home/oracle/SCRIPTS2DBA */ 10 | --#/* Responsibility : DBA */ 11 | --#/* External Parameters : */ 12 | --#/* Changes Made : */ 13 | --#/* Observations : */ 14 | --#/*************************************************************************************************/ 15 | @../CONFSQL/confsql.sql 16 | 17 | SET FEEDBACK OFF 18 | SET COLSEP '|' 19 | 20 | COLUMN start_time FORMAT A25 HEADING 'Start Time' 21 | COLUMN end_time FORMAT A25 HEADING 'End Time' 22 | COLUMN metric_name FORMAT A45 HEADING 'Metric Name' 23 | COLUMN metric_unit FORMAT A35 HEADING 'Metric Unit' 24 | COLUMN minval FORMAT 999,999,999,999.99 HEADING 'Min Value' 25 | COLUMN maxval FORMAT 999,999,999,999.99 HEADING 'Max Value' 26 | COLUMN metric_value FORMAT 999,999,999,999.99 HEADING 'Metric Value' 27 | COLUMN target_value FORMAT 999,999,999,999.99 HEADING 'Target Value' 28 | COLUMN stddev FORMAT 999,999,999,999.99 HEADING 'Std. Dev.' 29 | COLUMN stddev_pct FORMAT 999.99 HEADING 'Std. Dev. %' 30 | COLUMN check_metric FORMAT A15 HEADING 'Check Metric|Std. Dev > 50%' 31 | COLUMN metric_category FORMAT A30 HEADING 'Metric Category' 32 | COLUMN hist_value FORMAT 999,999,999,999.99 HEADING 'Metric Value' 33 | 34 | 35 | 36 | PROMPT ======================================================================================================================================================================== 37 | prompt Metrics values: 38 | PROMPT 39 | PROMPT Metric Value - The average value of the metric between begin and end Time. 40 | PROMPT Target Value - 50% of the average metric value between begin and end Time. 41 | PROMPT Max Value - The highest recorded metric value between begin and end Time. 42 | PROMPT Std. Dev. - Measures the Standard Deviation (or relative variation) recorded between the begin and end time. This value indicates the variation of 43 | PROMPT the metric in relation to the metric average. If the deviation is high, it means that the values have fluctuated a lot. Therefore, if the deviation 44 | PROMPT is above 50%, we will check the metric to identify possible problems. 45 | PROMPT ======================================================================================================================================================================== 46 | 47 | SELECT 48 | rpad(ss.begin_time,25) as begin_time, 49 | rpad(ss.end_time,25) as end_time, 50 | ss.metric_name, 51 | (SELECT MAX(sh.metric_unit) FROM v$sysmetric_history sh WHERE sh.metric_name = ss.metric_name) AS metric_unit, 52 | --ss.minval, 53 | CASE 54 | WHEN ss.METRIC_NAME = 'Database Time Per Sec' THEN ROUND(ss.average/100/(SELECT value FROM v$osstat WHERE stat_name = 'NUM_CPUS'), 2) -- Performing the calculation considering the number of CPUs, rather than the cumulative number. 55 | ELSE ss.average 56 | END AS metric_value, 57 | (0.5 * ss.average) AS target_value, 58 | ss.maxval, 59 | ss.standard_deviation AS stddev, 60 | CASE 61 | WHEN ss.average > 0 THEN (ss.standard_deviation / ss.average) * 100 62 | ELSE NULL 63 | END AS stddev_pct, 64 | CASE 65 | WHEN ss.standard_deviation > (0.5 * ss.average) THEN 'YES' 66 | ELSE '' 67 | END AS check_metric, 68 | CASE 69 | WHEN ss.metric_name IN ( 70 | 'Host CPU Utilization (%)', 'Database CPU Time Ratio') THEN 'CPU' 71 | WHEN ss.metric_name IN ( 72 | 'Average Active Sessions', 'Current Logons Count', 'Current Open Cursors Count', 73 | 'DB Block Changes Per Sec', 'DB Block Gets Per Sec', 'Executions Per Sec', 74 | 'Logical Reads Per Sec', 'Physical Reads Per Sec', 'User Transaction Per Sec', 75 | 'Redo Generated Per Sec', 'Redo Writes Per Sec', 'Network Traffic Volume Per Sec') THEN 'Counts' 76 | WHEN ss.metric_name IN ( 77 | 'Database Wait Time Ratio', 'Row Cache Hit Ratio', 'Row Cache Miss Ratio', 78 | 'Library Cache Miss Ratio', 'Buffer Cache Hit Ratio', 'Library Cache Hit Ratio', 79 | 'Cursor Cache Hit Ratio', 'Execute Without Parse Ratio', 'Soft Parse Ratio', 80 | 'Redo Allocation Hit Ratio', 'Memory Sorts Ratio') THEN 'Operational System (%)' 81 | WHEN ss.metric_name IN ( 82 | 'Physical Read Total IO Requests Per Sec', 'Physical Write Total IO Requests Per Sec', 83 | 'Physical Read Total Bytes Per Sec', 'Physical Write Total Bytes Per Sec') THEN 'Physical IO (Bytes/Sec)' 84 | ELSE 'Others' 85 | END AS metric_category 86 | FROM v$sysmetric_summary ss 87 | WHERE ss.METRIC_NAME IN ( 88 | 'Average Active Sessions', 'Current Logons Count', 'Current Open Cursors Count', 89 | 'Current OS Load', 'Host CPU Utilization (%)', 'DB Block Changes Per Sec', 90 | 'DB Block Gets Per Sec', 'Database Time Per Sec', 'Executions Per Sec', 91 | 'Logical Reads Per Sec', 'Physical Reads Per Sec', 'Redo Generated Per Sec', 92 | 'Redo Writes Per Sec', 'User Transaction Per Sec', 'Network Traffic Volume Per Sec', 93 | 'Database CPU Time Ratio', 'Database Wait Time Ratio', 'Row Cache Hit Ratio', 94 | 'Row Cache Miss Ratio', 'Library Cache Miss Ratio', 'Buffer Cache Hit Ratio', 95 | 'Library Cache Hit Ratio', 'Cursor Cache Hit Ratio', 'Execute Without Parse Ratio', 96 | 'Soft Parse Ratio', 'Redo Allocation Hit Ratio', 'Memory Sorts Ratio', 97 | 'Physical Read Total IO Requests Per Sec', 'Physical Write Total IO Requests Per Sec', 98 | 'Physical Read Total Bytes Per Sec', 'Physical Write Total Bytes Per Sec' 99 | ) 100 | ORDER BY metric_category, check_metric DESC, ss.metric_name; 101 | 102 | SET SERVEROUTPUT ON 103 | --SET FEEDBACK OFF 104 | 105 | prompt 106 | prompt ======================================================================================================================================================================== 107 | ACCEPT a_metric_name CHAR PROMPT 'Do you want to see details of any Metric? Please, insert the metric name. (Press Enter to finish): ' 108 | prompt ======================================================================================================================================================================== 109 | 110 | declare 111 | v_metric_name varchar2(60) := trim('&&a_metric_name'); 112 | begin 113 | 114 | if v_metric_name is null or length(v_metric_name) = 0 then 115 | RETURN; 116 | else 117 | DBMS_OUTPUT.PUT_LINE(CHR(10)); 118 | DBMS_OUTPUT.PUT_LINE('============================================'); 119 | DBMS_OUTPUT.PUT_LINE('Metric Details: ' || v_metric_name); 120 | DBMS_OUTPUT.PUT_LINE('============================================'); 121 | DBMS_OUTPUT.PUT_LINE(rpad('Begin Time',23) || rpad('End Time',23) || rpad('Metric Name',50) || rpad('Metric Unit',40) || rpad('Metric Value',20)); 122 | DBMS_OUTPUT.PUT_LINE('--------------------- --------------------- ----------------------------------------------- ------------------------------------- -------------------------'); 123 | for rec in ( 124 | SELECT 125 | begin_time, 126 | end_time, 127 | metric_name, 128 | metric_unit, 129 | ROUND(value, 2) AS hist_value 130 | FROM v$sysmetric_history 131 | WHERE UPPER(metric_name) = UPPER(v_metric_name) 132 | ORDER BY begin_time 133 | FETCH FIRST 45 ROWS ONLY 134 | ) loop 135 | DBMS_OUTPUT.PUT_LINE(rpad(rec.begin_time,23) || rpad(rec.end_time,23) || rpad(rec.metric_name,50) || rpad(rec.metric_unit,40) || rpad(rec.hist_value,20)); 136 | end loop; 137 | end if; 138 | end; 139 | / -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Scripts2DBA 2 | 3 | Hello all 4 | 5 | I've created repository and I'm going to start sharing some scripts that I like to make and that help me in my day-to-day life as a DBA. 6 | 7 | But some considerations are important: 8 | 9 | 1) Some scripts are a compilation of several other scripts I've created. 10 | 11 | 2) Some scripts are based on and adapted from existing scripts. Those that I found reference to the author I obviously identify in the script. 12 | 13 | 3) So, if there's a script that you're the author of and I've adapted to my reality and it's not mentioned, please let me know and I'll be happy to reference it. 14 | 15 | 4) Because they're my scripts, they have my logic and help me in my day-to-day work, it doesn't mean that they're the best or that they're always the most refined and concerned with good practices. They can help you, but that's all. 16 | 17 | 5) Feel free to make changes, but please keep the reference to the authors. 18 | 19 | 6) If you find any mistakes, please let me know. 20 | 21 | I hope this helps you. 22 | 23 | Regards 24 | Mario Barduchi 25 | -------------------------------------------------------------------------------- /RMAN/showrman.sql: -------------------------------------------------------------------------------- 1 | --#/*************************************************************************************************/ 2 | --#/* Script : showrman.sql */ 3 | --#/* Author : Mario Barduchi */ 4 | --#/* E-mail : mario.barduchi@gmail.com */ 5 | --#/* Date : 07/07/2011 */ 6 | --#/* Original : None */ 7 | --#/* Description : RMAN info - Task status, Backup level, archives */ 8 | --#/* Location : /home/oracle/SCRIPTS2DBA */ 9 | --#/* Responsibility : DBA */ 10 | --#/* External Parameters : */ 11 | --#/* Changes Made : */ 12 | --#/* 07/07/11 (Mario Barduchi) - Script creation. */ 13 | --#/* 02/04/13 (Mario Barduchi) - Backup full list. */ 14 | --#/* 15/02/24 (Mario Barduchi) - Querys rewrite. */ 15 | --#/* Observations : */ 16 | --#/* Some queries were basesd on: */ 17 | --#/* http://www.pythian.com/blog/viewing-rma-jobs-status-and-output/ */ 18 | --#/*************************************************************************************************/ 19 | @../CONFSQL/confsql.sql 20 | SET FEEDBACK OFF 21 | set COLSEP "|" 22 | 23 | -- Altera o modo de otimizacao devido a BUG 5247609 (NOTES 5247609.8 e 375386.1) 24 | ALTER SESSION SET OPTIMIZER_MODE=RULE; 25 | 26 | COL dbid FOR 999999999999 HEADING "DBID"; 27 | COL oper FOR a25 HEADING "OPERATION"; 28 | COL name FOR a50 HEADING "PARAMETER"; 29 | COL value FOR a90 HEADING "RMAN CONFIGURATION"; 30 | COL session_key FOR 999999 HEADING "SESSION"; 31 | COL operation FOR a19 HEADING "OPERATION"; 32 | COL input_type FOR a12 HEADING "OPER. TYPE"; 33 | COL status FOR a25 HEADING "STATUS"; 34 | COL optimized FOR a05 HEADING "OPT"; 35 | COL start_time FOR a22 HEADING "START TIME"; 36 | COL end_time FOR a22 HEADING "END TIME"; 37 | COL time_taken FOR a11 HEADING "TIME TAKEN"; 38 | COL input_size FOR a11 HEADING "INPUT SIZE"; 39 | COL output_size FOR a11 HEADING "OUTPUT SIZE"; 40 | COL input_size_sec FOR a11 HEADING "INPUT RATE|(PER SEC)"; 41 | COL output_size_sec FOR a11 HEADING "OUTPUT RATE|(PER SEC)"; 42 | COL dev FOR a08 TRUNC HEADING "DEVICE"; 43 | COL compression_ratio FOR 9,999,999 HEADING "COMP. RATIO|(MB PER SEC)"; 44 | COL spfile_included FOR a10 HEADING "SPFILE"; 45 | COL completion_time HEADING "DURATION"; 46 | COL handle FOR a80 HEADING "LOCAL"; 47 | COL type FOR a20 HEADING "TYPE"; 48 | COL records_total HEADING "TOTAL RECORD'S"; 49 | COL records_used HEADING "TOTAL USED"; 50 | COL name_database FOR a15 HEADING "INSTANCE NAME"; 51 | COL session_recid FOR 999999 HEADING "RECID"; 52 | COL session_stamp FOR 99999999999 HEADING "SESSION|STAMP"; 53 | COL cfile FOR 9,999 HEADING "CF"; 54 | COL datafile_full FOR 9,999 HEADING "DF"; 55 | COL level0 FOR 9,999 HEADING "L0"; 56 | COL level1 FOR 9,999 HEADING "L1"; 57 | COL archives_included FOR 9,999 HEADING "ARC"; 58 | COL time_taken_display FOR a10 HEADING "TIME|TAKEN"; 59 | COL output_instance FOR 9999 HEADING "OUT|INST"; 60 | COL backup_type FOR a25 HEADING "BKP TYPE"; 61 | COL controlfile_included HEADING "CF INC"; 62 | COL incremental_level HEADING "LEVEL"; 63 | COL pieces FOR 9999 HEADING "PCS"; 64 | COL compressed FOR a4 HEADING "COMPRESS"; 65 | COL input_file_scan_only FOR a4 HEADING "SCAN|ONLY"; 66 | COL input_bytes_per_sec_display FOR 9,999,999 HEADING "INPUT|(MB PER SEC)"; 67 | COL output_bytes_per_sec_display FOR 9,999,999 HEADING "OUTPUT|(MB PER SEC)"; 68 | 69 | ACCEPT NUMBER_OF_DAYS NUM FORMAT 999 DEFAULT '7' PROMPT 'Enter the number of days back to look >> ' 70 | 71 | prompt 72 | prompt ============================================================================ 73 | prompt DBID 74 | prompt ============================================================================ 75 | SELECT 76 | INST_ID, 77 | DBID, 78 | NAME AS NAME_DATABASE 79 | FROM 80 | gv$database 81 | ORDER BY 82 | INST_ID; 83 | 84 | 85 | prompt 86 | prompt ============================================================================ 87 | prompt LIST RMAN PARAMETERs 88 | prompt ============================================================================ 89 | SELECT 90 | NAME, 91 | VALUE 92 | FROM 93 | V$RMAN_CONFIGURATION 94 | ORDER BY 95 | NAME; 96 | 97 | prompt 98 | prompt ============================================================================ 99 | prompt LIST RMAN - SUMMARY 100 | prompt ============================================================================ 101 | SELECT 102 | CTIME as "Date", 103 | DECODE(BACKUP_TYPE, 'L', 'BKP contains ArchiveLog', 104 | 'D', 'BKP Datafile Full', 105 | 'Incremental BKP - L'||INCREMENTAL_LEVEL) as backup_type, 106 | BSIZE as "Size (MB)" 107 | FROM ( 108 | SELECT 109 | TRUNC(bp.COMPLETION_TIME) as ctime, 110 | bs.BACKUP_TYPE, 111 | ROUND(SUM(bp.BYTES/1024/1024),2) as bsize, 112 | bs.INCREMENTAL_LEVEL 113 | FROM V$BACKUP_SET bs, V$BACKUP_PIECE bp 114 | WHERE 115 | bs.SET_STAMP = bp.SET_STAMP AND 116 | bs.SET_COUNT = bp.SET_COUNT AND 117 | bp.STATUS = 'A' AND 118 | TRUNC(bp.COMPLETION_TIME) > trunc(SYSDATE)-&NUMBER_OF_DAYS 119 | GROUP BY 120 | TRUNC(bp.COMPLETION_TIME), bs.BACKUP_TYPE, bs.INCREMENTAL_LEVEL 121 | ) 122 | ORDER BY 1 DESC, 2 DESC; 123 | 124 | prompt 125 | prompt ============================================================================ 126 | prompt LIST BACKUPs - LAST &NUMBER_OF_DAYS DAYS 127 | prompt ============================================================================ 128 | SELECT 129 | j.SESSION_RECID, 130 | j.SESSION_STAMP, 131 | j.INPUT_TYPE, 132 | DECODE(j.INPUT_TYPE, 'ARCHIVELOG', 'BACKUP - ArchiveLog', 133 | 'DB FULL', 'BACKUP - Full', 134 | 'RECVR AREA', 'Recovery Area', 135 | 'DATAFILE FULL', 'BACKUP - Full', 136 | 'DATAFILE INCR', 'Datafile Incr - L'||x.INCREMENTAL_LEVEL, 137 | 'CONTROLFILE', 'Controlfile', 138 | 'SPFILE', 'SPFile', 139 | 'BACKUP - L'||x.INCREMENTAL_LEVEL) as backup_type, 140 | j.STATUS, 141 | DECODE(TO_CHAR(j.START_TIME, 'd'), 1, 'Sun', 142 | 2, 'Mon', 143 | 3, 'Tue', 144 | 4, 'Wed', 145 | 5, 'Thu', 146 | 6, 'Fri', 147 | 7, 'Sat') as dow, 148 | TO_CHAR(j.START_TIME, 'YYYY-MM-DD HH24:mi:ss') as start_time, 149 | TO_CHAR(j.END_TIME , 'YYYY-MM-DD HH24:mi:ss') as end_time, 150 | j.TIME_TAKEN_DISPLAY as time_taken, 151 | j.INPUT_BYTES_DISPLAY as input_size, 152 | j.OUTPUT_BYTES_DISPLAY as output_size, 153 | j.INPUT_BYTES_PER_SEC_DISPLAY as input_size_sec, 154 | j.OUTPUT_BYTES_PER_SEC_DISPLAY as output_size_sec, 155 | x.COMPRESSED, 156 | j.COMPRESSION_RATIO, 157 | j.OUTPUT_DEVICE_TYPE as dev 158 | FROM V$RMAN_BACKUP_JOB_DETAILS j 159 | LEFT JOIN (SELECT 160 | d.SESSION_RECID , d.SESSION_STAMP, 161 | d.BACKUP_TYPE , d.CONTROLFILE_INCLUDED, 162 | d.INCREMENTAL_LEVEL, d.PIECES, 163 | d.COMPRESSED 164 | FROM V$BACKUP_SET_DETAILS d 165 | JOIN V$BACKUP_SET s ON 166 | s.set_stamp = d.set_stamp AND 167 | s.set_count = d.set_count 168 | WHERE s.input_file_scan_only = 'NO' 169 | GROUP BY d.SESSION_RECID, d.SESSION_STAMP, d.BACKUP_TYPE, d.CONTROLFILE_INCLUDED, d.INCREMENTAL_LEVEL, d.PIECES, d.COMPRESSED 170 | ) x 171 | ON x.SESSION_RECID = j.SESSION_RECID AND 172 | x.SESSION_STAMP = j.SESSION_STAMP 173 | LEFT JOIN (SELECT 174 | rs.COMMAND_ID, rs.OPERATION, 175 | rs.OBJECT_TYPE 176 | FROM V$RMAN_STATUS rs 177 | WHERE rs.OPERATION NOT IN ('CATALOG','LIST','RMAN','CROSSCHECK','REPORT SCHEMA') 178 | ) rs 179 | ON rs.COMMAND_ID = j.COMMAND_ID 180 | WHERE 181 | rs.OBJECT_TYPE LIKE 'DB%' 182 | GROUP BY 183 | j.SESSION_RECID, j.SESSION_STAMP, j.STATUS, j.START_TIME, j.END_TIME, j.TIME_TAKEN_DISPLAY, 184 | j.INPUT_TYPE, j.INPUT_BYTES_DISPLAY, j.OUTPUT_BYTES_DISPLAY, j.INPUT_BYTES_PER_SEC_DISPLAY, j.OUTPUT_BYTES_PER_SEC_DISPLAY, j.OUTPUT_DEVICE_TYPE,j.COMPRESSION_RATIO,rs.OPERATION, rs.OBJECT_TYPE, x.INCREMENTAL_LEVEL, x.COMPRESSED 185 | HAVING 186 | MAX(TRUNC(j.START_TIME)) > TRUNC(SYSDATE)-&NUMBER_OF_DAYS 187 | ORDER BY j.START_TIME DESC; 188 | 189 | prompt 190 | prompt ============================================================================ 191 | prompt ALL OPERATIONS - LAST &NUMBER_OF_DAYS DAYS 192 | prompt ============================================================================ 193 | prompt INPUT SIZE ==> Sum of all input file sizes backed up by this job. 194 | prompt OUTPUT SIZE ==> Output size of all pieces generated by this job. 195 | prompt INPUT RATE|(PER SEC) ==> Input read-rate-per-second. Because of RMAN compression. 196 | prompt OUTPUT RATE|(PER SEC) ==> The OUTPUT RATE|(PER SEC) cannot be used as measurement of backup speed. The appropriate column to measure backup speed is INPUT RATE (PER SEC). 197 | prompt CF ==> Number of controlfile backups included in the backup set. 198 | prompt DF ==> Number of datafile full backups included in the backup set. 199 | prompt L0 ==> Number of datafile incremental Level 0 backups included in the backup set. 200 | prompt L1 ==> Number of datafile incremental Level 1 backups included in the backup set. 201 | prompt ARC ==> Number of archived log backups included in the backup set. 202 | prompt INSTANCE ==> Instance where the job was executed and the output is available. 203 | prompt COMP. RATIO|(MB PER SEC)==> The ratio between read and written data. 204 | prompt ============================================================================ 205 | SELECT 206 | j.SESSION_RECID, 207 | j.SESSION_STAMP, 208 | j.INPUT_TYPE, 209 | DECODE(j.INPUT_TYPE, 'ARCHIVELOG', 'BACKUP - ArchiveLog', 210 | 'DB FULL', 'BACKUP - Full', 211 | 'RECVR AREA', 'Recovery Area', 212 | 'DATAFILE FULL', 'BACKUP - Full', 213 | 'DATAFILE INCR', 'Datafile Incr - L'||xx.INCREMENTAL_LEVEL, 214 | 'CONTROLFILE', 'Controlfile', 215 | 'SPFILE', 'SPFile', 216 | 'BACKUP - L'||xx.INCREMENTAL_LEVEL) as backup_type, 217 | j.STATUS, 218 | DECODE(TO_CHAR(j.START_TIME, 'd'), 1, 'Sun', 219 | 2, 'Mon', 220 | 3, 'Tue', 221 | 4, 'Wed', 222 | 5, 'Thu', 223 | 6, 'Fri', 224 | 7, 'Sat') as dow, 225 | TO_CHAR(j.START_TIME, 'YYYY-MM-DD HH24:mi:ss') as start_time, 226 | TO_CHAR(j.END_TIME , 'YYYY-MM-DD HH24:mi:ss') as end_time, 227 | j.TIME_TAKEN_DISPLAY as time_taken, 228 | j.INPUT_BYTES_DISPLAY as input_size, 229 | j.OUTPUT_BYTES_DISPLAY as output_size, 230 | j.INPUT_BYTES_PER_SEC_DISPLAY as input_size_sec, 231 | j.OUTPUT_BYTES_PER_SEC_DISPLAY as output_size_sec, 232 | x.CFILE, 233 | x.DATAFILE_FULL, 234 | x.LEVEL0, 235 | x.LEVEL1, 236 | x.ARCHIVES_INCLUDED, 237 | xx.INCREMENTAL_LEVEL as incremental_level, 238 | ro.INST_ID as instance, 239 | SUM(xx.PIECES) as pieces, 240 | xx.COMPRESSED, 241 | j.COMPRESSION_RATIO, 242 | j.OUTPUT_DEVICE_TYPE as dev 243 | FROM V$RMAN_BACKUP_JOB_DETAILS j 244 | LEFT JOIN (SELECT 245 | d.SESSION_RECID, 246 | d.SESSION_STAMP, 247 | SUM(CASE WHEN d.CONTROLFILE_INCLUDED = 'YES' THEN d.PIECES ELSE 0 END) as cfile, 248 | SUM(CASE WHEN d.CONTROLFILE_INCLUDED = 'NO' AND d.BACKUP_TYPE||d.INCREMENTAL_LEVEL = 'D' THEN d.PIECES ELSE 0 END) as datafile_full, 249 | SUM(CASE WHEN d.BACKUP_TYPE||d.INCREMENTAL_LEVEL = 'I0' THEN d.PIECES ELSE 0 END) as level0, 250 | SUM(CASE WHEN d.BACKUP_TYPE||d.INCREMENTAL_LEVEL = 'I1' THEN d.PIECES ELSE 0 END) as level1, 251 | SUM(CASE WHEN d.BACKUP_TYPE = 'L' THEN d.PIECES ELSE 0 END) as archives_included 252 | FROM V$BACKUP_SET_DETAILS d 253 | JOIN V$BACKUP_SET s ON s.SET_STAMP = d.SET_STAMP AND 254 | s.SET_COUNT = d.SET_COUNT 255 | WHERE s.INPUT_FILE_SCAN_ONLY = 'NO' 256 | GROUP BY d.SESSION_RECID, 257 | d.SESSION_STAMP 258 | ) x 259 | ON x.SESSION_RECID = j.SESSION_RECID AND 260 | x.SESSION_STAMP = j.SESSION_STAMP 261 | LEFT JOIN (SELECT 262 | dd.SESSION_RECID, 263 | dd.SESSION_STAMP, 264 | dd.BACKUP_TYPE, 265 | dd.INCREMENTAL_LEVEL, 266 | SUM(dd.PIECES) as pieces, 267 | dd.COMPRESSED 268 | FROM V$BACKUP_SET_DETAILS dd 269 | JOIN V$BACKUP_SET ss ON ss.SET_STAMP = dd.SET_STAMP AND 270 | ss.SET_COUNT = dd.SET_COUNT 271 | WHERE ss.INPUT_FILE_SCAN_ONLY = 'NO' 272 | GROUP BY dd.SESSION_RECID, 273 | dd.SESSION_STAMP, 274 | dd.BACKUP_TYPE, 275 | dd.INCREMENTAL_LEVEL, 276 | dd.COMPRESSED 277 | ) xx 278 | ON xx.SESSION_RECID = j.SESSION_RECID AND 279 | xx.SESSION_STAMP = j.SESSION_STAMP 280 | LEFT JOIN (SELECT 281 | o.SESSION_RECID, 282 | o.SESSION_STAMP, 283 | MIN(INST_ID) as inst_id 284 | FROM GV$RMAN_OUTPUT o 285 | GROUP BY o.SESSION_RECID, 286 | o.SESSION_STAMP 287 | ) ro 288 | ON ro.SESSION_RECID = j.SESSION_RECID AND 289 | ro.SESSION_STAMP = j.SESSION_STAMP 290 | WHERE 291 | TRUNC(j.START_TIME) > TRUNC(SYSDATE)-&NUMBER_OF_DAYS 292 | GROUP BY 293 | j.SESSION_RECID, 294 | j.SESSION_STAMP, 295 | j.INPUT_TYPE, 296 | j.STATUS, 297 | j.START_TIME, 298 | j.END_TIME , 299 | j.TIME_TAKEN_DISPLAY, 300 | j.INPUT_BYTES_DISPLAY, 301 | j.OUTPUT_BYTES_DISPLAY, 302 | j.INPUT_BYTES_PER_SEC_DISPLAY, 303 | j.OUTPUT_BYTES_PER_SEC_DISPLAY, 304 | x.CFILE, 305 | x.DATAFILE_FULL, 306 | x.LEVEL0, 307 | x.LEVEL1, 308 | x.ARCHIVES_INCLUDED, 309 | ro.inst_id, 310 | xx.COMPRESSED, 311 | xx.INCREMENTAL_LEVEL , 312 | j.COMPRESSION_RATIO, 313 | j.OUTPUT_DEVICE_TYPE 314 | ORDER BY j.START_TIME DESC; 315 | 316 | 317 | prompt 318 | prompt ============================================================================ 319 | prompt BACKUP RECORD IN CONTROLFILES 320 | prompt ============================================================================ 321 | SELECT 322 | type, 323 | records_total, 324 | records_used 325 | FROM 326 | v$controlfile_record_section 327 | WHERE 328 | type LIKE '%BACKUP%'; 329 | 330 | prompt 331 | prompt ============================================================================ 332 | prompt AUTOBACKUP - CONTROLFILES AND SPFILES - Last 3 days 333 | prompt ============================================================================ 334 | SELECT 335 | bs.recid, 336 | sp.spfile_included, 337 | TO_CHAR(bs.completion_time, 'dd/mm/yyyy HH24:MI:SS') completion_time, 338 | DECODE(status, 'A', 'Available', 'D', 'Deleted', 'X', 'Expired') status, 339 | handle 340 | FROM 341 | v$backup_set bs, v$backup_piece bp, 342 | (select distinct 343 | set_stamp, 344 | set_count, 345 | 'YES' spfile_included 346 | from 347 | v$backup_spfile) sp 348 | WHERE 349 | bs.set_stamp = bp.set_stamp AND 350 | TRUNC(bs.completion_time) > trunc(sysdate)-&NUMBER_OF_DAYS AND 351 | bs.set_count = bp.set_count AND 352 | bp.status IN ('A', 'X') AND 353 | bs.set_stamp = sp.set_stamp AND 354 | bs.set_count = sp.set_count 355 | ORDER BY 356 | bs.completion_time desc, bs.recid, piece#; 357 | 358 | ALTER SESSION SET OPTIMIZER_MODE=ALL_ROWS; 359 | SET FEEDBACK ON 360 | SET VERIFY ON -------------------------------------------------------------------------------- /SGA/showsga.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/MarioBarduchi/Scripts2DBA/3ff57d0c9d80974c5ae022c207cb35b2a533a1a3/SGA/showsga.sql -------------------------------------------------------------------------------- /SQLPLAN/showplan.sql: -------------------------------------------------------------------------------- 1 | --#/*************************************************************************************************/ 2 | --#/* Script : showplan.sql */ 3 | --#/* Author : Mario Barduchi */ 4 | --#/* E-mail : mario.barduchi@gmail.com */ 5 | --#/* Date : 11/06/2024 */ 6 | --#/* Original : None */ 7 | --#/* Description : Execution plan info - Top 30 most executed plans at the moment, */ 8 | --#/* and other information */ 9 | --#/* Location : /home/oracle/SCRIPTS2DBA */ 10 | --#/* Responsibility : DBA */ 11 | --#/* External Parameters : */ 12 | --#/* Changes Made : */ 13 | --#/* Observations : */ 14 | --#/* Some queries were basesd on: */ 15 | --#/* coe_xfr_sql_profile.sql from Carlos Sierra */ 16 | --#/*************************************************************************************************/ 17 | @../CONFSQL/confsql.sql 18 | SET FEEDBACK OFF 19 | SET COLSEP '|' 20 | ALTER SESSION SET statistics_level='ALL'; 21 | 22 | prompt ======================================================================================================================================================================== 23 | prompt Execution plans 24 | prompt 25 | prompt All execution times, elapsed_time_sec, elapsed_time_min, elapsed_time_hr, cpu_time_sec, buffer_gets, disk_reads, and rows_processed are accumulated from 26 | prompt the moment the SQL enters the Shared Pool. If it expires or is removed from the Shared Pool, these values are reset and start a new count when it re-enters 27 | prompt the Shared Pool. 28 | prompt 29 | prompt SQL_ID: Unique SQL identifier of the parent cursor in the library cache. 30 | prompt 31 | prompt PLAN_HASH_VALUE: The hash value of the current SQL plan for this cursor, used to identify the unique execution plan. 32 | prompt 33 | prompt EXECUTIONS: Total number of executions of the SQL. It does not matter if the SQL was executed at different time intervals since it was brought into the library cache. 34 | prompt 35 | prompt ELAPSED_TIME_SEC, ELAPSED_TIME_MIN and ELAPSED_TIME_HR: Elapsed database time used by this cursor for parsing, executing, and fetching. If the cursor uses parallel 36 | prompt execution, then ELAPSED_TIME is the cumulative time for the query coordinator, plus all parallel query worker processes. In seconds, minutes, and hours. 37 | prompt In some cases, ELAPSED_TIME can exceed the duration of the query. 38 | prompt 39 | prompt CPU_TIME_SEC: CPU time consumed by the SQL for parsing, executing and fetching. This may differ significantly from elapsed_time, as there may be periods when the SQL 40 | prompt is waiting for something, like memory, disk, or other resources, to continue CPU processing. 41 | prompt 42 | prompt BUFFER_GETS: Number of buffer cache reads performed by the SQL. Ideally, the higher the BUFFER_GETS and the lower the disk_reads, the better the SQL performance. 43 | prompt 44 | prompt DISK_READS: Similar to BUFFER_GETS, it is the total number of physical reads made directly from disk by the SQL. 45 | prompt 46 | prompt ROWS_PROCESSED: Total number of rows read and processed by the SQL to return a result. 47 | prompt 48 | prompt PLAN_COUNT: The number of distinct execution plans that are active and associated with a SQL_ID. It does not consider the history. 49 | prompt 50 | prompt Important: These criteria were defined by me, based on my experience, and are not necessarily based on manuals. It is just a starting point for me to analyze a SQL. 51 | prompt 52 | prompt ======================================================================================================================================================================== 53 | prompt Child Cursors 54 | prompt 55 | prompt Child Cursors are variations of the same SQL in the Shared Pool. They arise when changes are made that prevent the original plan from being reused. Too many child 56 | prompt cursors can, but not necessarily, be an indicator of excessive parsing problems. 57 | prompt 58 | prompt When multiple Child Cursors can occur for the same SQL: 59 | prompt - Differences in Bind Variables (Adaptive Cursor Sharing). 60 | prompt - Change in Table Statistics. 61 | prompt - Change in Session Parameters. 62 | prompt - Changes in Privileges (GRANT/REVOKE). 63 | prompt - Sessions with different NLS configurations. 64 | prompt - Changing Structures (DDL such as ALTER TABLE, CREATE INDEX). 65 | prompt ======================================================================================================================================================================== 66 | 67 | COLUMN sql_id FORMAT A15 HEADING 'SQL ID' 68 | COLUMN plan_hash_value FORMAT 9999999999 HEADING 'Plan Hash Value' 69 | COLUMN executions FORMAT 999,999,999,999 HEADING 'Executions' 70 | COLUMN elapsed_time_sec FORMAT 999,999,999.99 HEADING 'Elapsed Time (Sec)' 71 | COLUMN cpu_time_sec FORMAT 999,999,999.99 HEADING 'CPU Time (Sec)' 72 | COLUMN elapsed_time_min FORMAT 999,999,999.99 HEADING 'Elapsed Time (Min)' 73 | COLUMN elapsed_time_hr FORMAT 999,999,999.99 HEADING 'Elapsed Time (Hr)' 74 | COLUMN buffer_gets FORMAT 999,999,999,999 HEADING 'Buffer Gets' 75 | COLUMN disk_reads FORMAT 999,999,999,999 HEADING 'Disk Reads' 76 | COLUMN rows_processed FORMAT 999,999,999,999 HEADING 'Rows Processed' 77 | COLUMN plan_count FORMAT 99999 HEADING 'Plan Count' 78 | COLUMN child_cursors FORMAT 99999 HEADING 'Child Cursors' 79 | COLUMN dr FORMAT A5 HEADING 'DR' 80 | COLUMN bg FORMAT A5 HEADING 'BG' 81 | COLUMN et FORMAT A5 HEADING 'ET' 82 | COLUMN chm FORMAT A6 HEADING 'CC (M)' 83 | COLUMN chh FORMAT A6 HEADING 'CC (H)' 84 | 85 | -- Hints 86 | -- LEADING(v): Informs Oracle to prioritize the v table during the execution plan. 87 | -- USE_NL(v): Suggests using a Nested Loop Join, which can be, but is not necessarily, more efficient depending on the statistics and the size of the v$sql table. 88 | select /*+ LEADING(v) USE_NL(v) */ * 89 | from ( 90 | select v.sql_id, 91 | v.plan_hash_value, 92 | v.executions, 93 | round(v.elapsed_time / 1e6, 2) as elapsed_time_sec, 94 | round(v.elapsed_time / 1e6 / 60, 2) as elapsed_time_min, 95 | round(v.elapsed_time / 1e6 / 3600, 2) as elapsed_time_hr, 96 | round(v.cpu_time / 1e6, 2) as cpu_time_sec, 97 | v.buffer_gets, 98 | v.disk_reads, 99 | v.rows_processed, 100 | (select count(distinct plan_hash_value) from v$sql where sql_id = v.sql_id ) as plan_count, 101 | (select count(*) from v$sql where sql_id = v.sql_id ) as child_cursors, 102 | case 103 | when v.disk_reads > 500000000 then ' X ' 104 | else '' 105 | end as dr, 106 | case 107 | when v.buffer_gets > 1000000000 then ' X ' 108 | else '' 109 | end as bg, 110 | case 111 | when round(v.elapsed_time / 1e6, 2) > 200000 then ' X ' 112 | else '' 113 | end as et, 114 | case 115 | when (select count(*) from v$sql where sql_id = v.sql_id) between 11 and 50 then ' X ' 116 | else '' 117 | end as chm, 118 | case 119 | when (select count(*) from v$sql where sql_id = v.sql_id) > 50 then ' X ' 120 | else '' 121 | end as chh 122 | from v$sql v 123 | where v.plan_hash_value > 0 124 | order by v.cpu_time desc 125 | ) 126 | where rownum <= 30; 127 | 128 | prompt 129 | prompt Identifies SQLs that could be problematic. Marks as X if: 130 | prompt - DR - Disk Reads - SQLs with very long execution times (over 100,000 seconds). 131 | prompt - BG - Buffer Gets - SQLs that excessively use buffer cache (over 1 billion buffer gets). 132 | prompt - ET - Elapsed Time - SQLs that perform many disk reads (over 100 million disk reads). 133 | prompt - CHM - Child Cursors (Medium) - Excessive parsing may occur (Child Cursors between 11 and 50). 134 | prompt - CHH - Child Cursors (High) - Possible contention in the Shared Pool (Child Cursors > 50). 135 | prompt ======================================================================================================================================================================== 136 | 137 | SET COLSEP '' 138 | SET SERVEROUTPUT ON 139 | 140 | prompt 141 | prompt ========================================================================================================= 142 | ACCEPT sql_id CHAR PROMPT 'Do you want to see details of any SQL_ID? (Press Enter to finish): ' 143 | prompt ========================================================================================================= 144 | 145 | DECLARE 146 | v_sql_id VARCHAR2(20) := TRIM('&&sql_id'); 147 | v_dummy VARCHAR2(20); 148 | BEGIN 149 | IF v_sql_id IS NULL OR LENGTH(v_sql_id) = 0 THEN 150 | RETURN; 151 | ELSE 152 | DBMS_OUTPUT.PUT_LINE(CHR(10)); 153 | DBMS_OUTPUT.PUT_LINE('============================================'); 154 | DBMS_OUTPUT.PUT_LINE('Execution Plans for SQL_ID: ' || v_sql_id); 155 | DBMS_OUTPUT.PUT_LINE('============================================'); 156 | DBMS_OUTPUT.PUT_LINE(RPAD('Plan Hash Value', 20) || RPAD('Avg Elapsed Time (s)', 25) || RPAD('Status', 25)); 157 | DBMS_OUTPUT.PUT_LINE('------------------- ------------------------ ---------------------'); 158 | 159 | FOR rec IN ( 160 | WITH p AS ( 161 | SELECT plan_hash_value FROM gv$sql_plan 162 | WHERE sql_id = v_sql_id AND other_xml IS NOT NULL 163 | UNION 164 | SELECT plan_hash_value FROM dba_hist_sql_plan 165 | WHERE sql_id = v_sql_id AND other_xml IS NOT NULL 166 | ), m AS ( 167 | SELECT plan_hash_value, 168 | SUM(elapsed_time) / SUM(executions) avg_et_secs 169 | FROM gv$sql 170 | WHERE sql_id = v_sql_id AND executions > 0 171 | GROUP BY plan_hash_value 172 | ), a AS ( 173 | SELECT plan_hash_value, 174 | SUM(elapsed_time_total) / SUM(executions_total) avg_et_secs 175 | FROM dba_hist_sqlstat 176 | WHERE sql_id = v_sql_id AND executions_total > 0 177 | GROUP BY plan_hash_value 178 | ), active_plans AS ( 179 | SELECT DISTINCT plan_hash_value FROM gv$sql_plan WHERE sql_id = v_sql_id 180 | ) 181 | SELECT p.plan_hash_value, 182 | ROUND(NVL(m.avg_et_secs, a.avg_et_secs) / 1e6, 3) avg_et_secs, 183 | CASE 184 | WHEN p.plan_hash_value IN (SELECT plan_hash_value FROM active_plans) THEN 'Active' 185 | ELSE 'Historical Execution Plan' 186 | END AS status 187 | FROM p 188 | LEFT JOIN m ON p.plan_hash_value = m.plan_hash_value 189 | LEFT JOIN a ON p.plan_hash_value = a.plan_hash_value 190 | ORDER BY status, avg_et_secs NULLS LAST 191 | ) LOOP 192 | DBMS_OUTPUT.PUT_LINE(RPAD(rec.plan_hash_value, 20) || RPAD(NVL(TO_CHAR(rec.avg_et_secs, '999,999,999.999'), ' '), 25) || RPAD(NVL(rec.status, ' '), 25)); 193 | END LOOP; 194 | 195 | DBMS_OUTPUT.PUT_LINE(CHR(10)); 196 | DBMS_OUTPUT.PUT_LINE('============================================'); 197 | DBMS_OUTPUT.PUT_LINE(' Child Cursors for SQL_ID: ' || v_sql_id); 198 | DBMS_OUTPUT.PUT_LINE('============================================'); 199 | DBMS_OUTPUT.PUT_LINE(RPAD('Child Number', 18) || RPAD('Reason', 50)); 200 | DBMS_OUTPUT.PUT_LINE('----------------- ------------------------------------------------'); 201 | 202 | FOR rec2 IN ( 203 | SELECT s.child_number, 204 | REGEXP_SUBSTR(TO_CLOB(s.reason), '(.*?)', 1, 1, NULL, 1) AS clean_reason 205 | FROM v$sql_shared_cursor s 206 | WHERE s.sql_id = v_sql_id 207 | ORDER BY s.child_number 208 | ) LOOP 209 | DBMS_OUTPUT.PUT_LINE(RPAD(TO_CHAR(rec2.child_number, '999'), 21) || RPAD(rec2.clean_reason, 50)); 210 | END LOOP; 211 | 212 | DBMS_OUTPUT.PUT_LINE(CHR(10)); 213 | DBMS_OUTPUT.PUT_LINE('============================================'); 214 | DBMS_OUTPUT.PUT_LINE(' Execution plan for SQL_ID: ' || v_sql_id); 215 | DBMS_OUTPUT.PUT_LINE('============================================'); 216 | 217 | FOR rec3 IN ( 218 | SELECT * FROM TABLE(DBMS_XPLAN.DISPLAY_CURSOR(v_sql_id, (SELECT child_number FROM v$sql WHERE sql_id = v_sql_id AND last_load_time IS NOT NULL ORDER BY last_load_time DESC, child_number ASC FETCH FIRST 1 ROWS ONLY), 'ALLSTATS ALL')) -- last_load_time: indicates when the cursor was loaded or "re-parsed" for the last time in the shared pool. 219 | ) LOOP 220 | DBMS_OUTPUT.PUT_LINE(rec3.plan_table_output); 221 | END LOOP; 222 | 223 | END IF; 224 | END; 225 | / --------------------------------------------------------------------------------