├── 00_readme_first.txt ├── LICENSE.txt ├── README.md ├── as.sql ├── calibrate_io.sql ├── cdb_as.sql ├── cdb_tables.sql ├── check_px.sql ├── comp_ratio.sql ├── contributing.md ├── dba_tables.sql ├── dplan.sql ├── dump_block.sql ├── esfc_keep_tables.sql ├── find_trace.sql ├── flush_sql.sql ├── fs.sql ├── fsx.sql ├── fsx2.sql ├── fsx3.sql ├── fsx4.sql ├── fsxo.sql ├── gather_table_stats.sql ├── get_compression_ratio_12c.sql ├── mystat.sql ├── obj_by_hex.sql ├── offload_percent.sql ├── parms.sql ├── parmsd.sql ├── part_size2.sql ├── pool_mem.sql ├── si.sql ├── ss_off.sql ├── ss_on.sql ├── table_size.sql ├── table_size2.sql ├── valid_events.sql ├── whoami.sql └── whoami_12c.sql /00_readme_first.txt: -------------------------------------------------------------------------------- 1 | Dear reader, 2 | 3 | thank you for your interest in Expert Oracle Exadata, 2nd edition. 4 | 5 | Throughout the book you witnessed a pleathora of useful diagnostic 6 | scripts. While the contents of many was shown in the body of the book, 7 | some of them are lengthy enough that we decided not to print their 8 | contents in the listings and rather include them here. 9 | 10 | Please make sure to refer to the book for more information and context 11 | of these scripts! Always consult the official Oracle documentation. 12 | 13 | Before you start using _any_ of these scripts: 14 | - You must understand what the script you are about to use actually does 15 | (including any effects) 16 | - You must ensure that you are in compliance with Oracle licensing 17 | - You have to test the script thoroughly in a development environment first 18 | 19 | Although great care has been taken by the authors, it is your 20 | responsibility to remain in compliance with Oracle licensing, your 21 | environment's standards, procedures and change control. 22 | 23 | Have fun! 24 | -------------------------------------------------------------------------------- /LICENSE.txt: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Apress/exp-oracle-exadata/fb0c950f4f1e3159dde3e2d0ff7646eb0adafde5/LICENSE.txt -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Apress Source Code 2 | 3 | This repository accompanies [*Expert Oracle Exadata*](http://www.apress.com/9781430262411) by Martin Bach, Kristofferson Arao, Andy Colvin, Frits Hoogland, Kerry Osborne, Randy Johnson, and Tanel Poder (Apress, 2015). 4 | 5 | [comment]: #cover 6 | ![Cover image](9781430262411.jpg) 7 | 8 | Download the files as a zip using the green button, or clone the repository to your machine using Git. 9 | 10 | ## Releases 11 | 12 | Release v1.0 corresponds to the code in the published book, without corrections or updates. 13 | 14 | ## Contributions 15 | 16 | See the file Contributing.md for more information on how you can contribute to this repository. 17 | -------------------------------------------------------------------------------- /as.sql: -------------------------------------------------------------------------------- 1 | set pagesize 999 2 | set lines 150 3 | col username format a13 4 | col prog format a10 trunc 5 | col sql_text format a41 trunc 6 | col sid format 9999 7 | col child for 99999 8 | col avg_etime for 999,999.99 9 | select sid, substr(program,1,19) prog, address, hash_value, b.sql_id, child_number child, plan_hash_value, executions execs, 10 | (elapsed_time/decode(nvl(executions,0),0,1,executions))/1000000 avg_etime, 11 | sql_text 12 | from v$session a, v$sql b 13 | where status = 'ACTIVE' 14 | and username is not null 15 | and a.sql_id = b.sql_id 16 | and a.sql_child_number = b.child_number 17 | and sql_text not like 'select sid, substr(program,1,19) prog, address, hash_value, b.sql_id, child_number child,%' -- don't show this query 18 | order by sql_id, sql_child_number 19 | / 20 | -------------------------------------------------------------------------------- /calibrate_io.sql: -------------------------------------------------------------------------------- 1 | set serveroutput on 2 | 3 | DECLARE 4 | miops PLS_INTEGER; 5 | mmbps PLS_INTEGER; 6 | alat NUMBER; 7 | BEGIN 8 | 9 | dbms_resource_manager.calibrate_io ( 10 | num_physical_disks => &no_of_disks, 11 | max_latency => 10, 12 | max_iops => miops, 13 | max_mbps => mmbps, 14 | actual_latency => alat 15 | ); 16 | 17 | dbms_output.put_line('max_iops = ' || miops); 18 | dbms_output.put_line('max_mbps = ' || mmbps); 19 | dbms_output.put_line('latency = ' || alat); 20 | end; 21 | / 22 | -------------------------------------------------------------------------------- /cdb_as.sql: -------------------------------------------------------------------------------- 1 | set pagesize 999 2 | set lines 170 3 | col username format a13 4 | col prog format a10 trunc 5 | col sql_text format a41 trunc 6 | col sid format 9999 7 | col child for 99999 8 | col avg_etime for 999,999.99 9 | select a.con_id,sid, substr(program,1,19) prog, address, hash_value, b.sql_id, child_number child, plan_hash_value, executions execs, 10 | (elapsed_time/decode(nvl(executions,0),0,1,executions))/1000000 avg_etime, 11 | sql_text 12 | from v$session a, v$sql b 13 | where status = 'ACTIVE' 14 | and username is not null 15 | and a.sql_id = b.sql_id 16 | and a.sql_child_number = b.child_number 17 | and sql_text not like 'select a.con_id,sid, substr(program,1,19) prog, address, hash_value, b.sql_id, child_number child,%' -- don't show this query 18 | order by sql_id, sql_child_number 19 | / 20 | -------------------------------------------------------------------------------- /cdb_tables.sql: -------------------------------------------------------------------------------- 1 | set lines 150 2 | select con_id, owner, table_name, status, last_analyzed, num_rows, blocks, degree 3 | from cdb_tables 4 | where con_id in (select con_id from v$pdbs where name like nvl('&pdb_name', name)) 5 | and owner like nvl('&owner',owner) 6 | and table_name like nvl('&table_name',table_name) 7 | order by con_id, owner, table_name 8 | / 9 | -------------------------------------------------------------------------------- /check_px.sql: -------------------------------------------------------------------------------- 1 | column value for 999,999 2 | select * from V$PX_PROCESS_SYSSTAT where statistic like '%In Use%'; 3 | -------------------------------------------------------------------------------- /comp_ratio.sql: -------------------------------------------------------------------------------- 1 | set lines 155 2 | compute sum of totalsize_megs on report 3 | break on report 4 | col owner for a10 5 | col segment_name for a20 6 | col segment_type for a10 7 | col totalsize_megs for 999,999.9 8 | col compression_ratio for 999.9 9 | select owner, segment_name, segment_type type, 10 | sum(bytes/1024/1024) as totalsize_megs, 11 | &original_size/sum(bytes/1024/1024) as compression_ratio 12 | from dba_segments 13 | where owner like nvl('&owner',owner) 14 | and segment_name like nvl('&table_name',segment_name) 15 | and segment_type like nvl('&type',segment_type) 16 | group by owner, segment_name, tablespace_name, segment_type 17 | order by 5; 18 | -------------------------------------------------------------------------------- /contributing.md: -------------------------------------------------------------------------------- 1 | # Contributing to Apress Source Code 2 | 3 | Copyright for Apress source code belongs to the author(s). However, under fair use you are encouraged to fork and contribute minor corrections and updates for the benefit of the author(s) and other readers. 4 | 5 | ## How to Contribute 6 | 7 | 1. Make sure you have a GitHub account. 8 | 2. Fork the repository for the relevant book. 9 | 3. Create a new branch on which to make your change, e.g. 10 | `git checkout -b my_code_contribution` 11 | 4. Commit your change. Include a commit message describing the correction. Please note that if your commit message is not clear, the correction will not be accepted. 12 | 5. Submit a pull request. 13 | 14 | Thank you for your contribution! -------------------------------------------------------------------------------- /dba_tables.sql: -------------------------------------------------------------------------------- 1 | set lines 150 2 | col table_name for a40 3 | select owner, table_name, status, last_analyzed, num_rows, blocks, degree 4 | from dba_tables 5 | where owner like nvl('&owner',owner) 6 | and table_name like nvl('&table_name',table_name) 7 | / 8 | -------------------------------------------------------------------------------- /dplan.sql: -------------------------------------------------------------------------------- 1 | set lines 180 2 | select * from table(dbms_xplan.display_cursor('&sql_id','&child_no','typical')) 3 | / 4 | 5 | -------------------------------------------------------------------------------- /dump_block.sql: -------------------------------------------------------------------------------- 1 | @find_trace 2 | alter system dump datafile &fileno block &blockno; 3 | -------------------------------------------------------------------------------- /esfc_keep_tables.sql: -------------------------------------------------------------------------------- 1 | select owner, table_name, status, last_analyzed, num_rows, blocks, degree, cell_flash_cache 2 | from dba_tables 3 | where owner like nvl('&owner',owner) 4 | and table_name like nvl('&table_name',table_name) 5 | and cell_flash_cache like nvl('&cell_flash_cache','KEEP') 6 | / 7 | -------------------------------------------------------------------------------- /find_trace.sql: -------------------------------------------------------------------------------- 1 | 2 | set lines 150 3 | col value for a145 4 | 5 | select value from v$diag_info where name = 'Default Trace File'; 6 | -------------------------------------------------------------------------------- /flush_sql.sql: -------------------------------------------------------------------------------- 1 | set serveroutput on 2 | set pagesize 9999 3 | set linesize 155 4 | var name varchar2(50) 5 | accept sql_id - 6 | prompt 'Enter value for sql_id: ' 7 | 8 | BEGIN 9 | 10 | select address||','||hash_value into :name 11 | from v$sqlarea 12 | where sql_id like '&&sql_id'; 13 | 14 | dbms_shared_pool.purge(:name,'C',1); 15 | 16 | END; 17 | / 18 | 19 | undef sql_id 20 | undef name 21 | -------------------------------------------------------------------------------- /fs.sql: -------------------------------------------------------------------------------- 1 | col sql_text for a60 wrap 2 | set verify off 3 | set pagesize 999 4 | set lines 155 5 | col username format a13 6 | col prog format a22 7 | col sid format 999 8 | col child_number format 99999 heading CHILD 9 | col ocategory format a10 10 | col avg_etime format 9,999,999.99 11 | col avg_pio format 9,999,999.99 12 | col avg_lio format 999,999,999 13 | col etime format 9,999,999.99 14 | 15 | select sql_id, child_number, plan_hash_value plan_hash, executions execs, 16 | (elapsed_time/1000000)/decode(nvl(executions,0),0,1,executions) avg_etime, 17 | buffer_gets/decode(nvl(executions,0),0,1,executions) avg_lio, 18 | sql_text 19 | from v$sql s 20 | where upper(sql_text) like upper(nvl('&sql_text',sql_text)) 21 | and sql_text not like '%from v$sql where sql_text like nvl(%' 22 | and sql_id like nvl('&sql_id',sql_id) 23 | order by 1, 2, 3 24 | / 25 | -------------------------------------------------------------------------------- /fsx.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------------- 2 | -- 3 | -- File name: fsx.sql 4 | -- 5 | -- Purpose: Find SQL and report whether it was Offloaded and % of I/O saved. 6 | -- 7 | -- Author: Kerry Osborne 8 | -- 9 | -- Usage: This scripts prompts for two values. 10 | -- 11 | -- sql_text: a piece of a SQL statement like %select col1, col2 from skew% 12 | -- 13 | -- sql_id: the sql_id of the statement if you know it (leave blank to ignore) 14 | -- 15 | -- Description: 16 | -- 17 | -- This script can be used to locate statements in the shared pool and 18 | -- determine whether they have been executed via Smart Scans. 19 | -- 20 | -- It is based on the observation that the IO_CELL_OFFLOAD_ELIGIBLE_BYTES 21 | -- column in V$SQL is only greater than 0 when a statement is executed 22 | -- using a Smart Scan. The IO_SAVED_% column attempts to show the ratio of 23 | -- of data received from the storage cells to the actual amount of data 24 | -- that would have had to be retrieved on non-Exadata storage. Note that 25 | -- as of 11.2.0.2, there are issues calculating this value with some queries. 26 | -- 27 | -- Note that the AVG_ETIME will not be acurate for parallel queries. The 28 | -- ELAPSED_TIME column contains the sum of all parallel slaves. So the 29 | -- script divides the value by the number of PX slaves used which gives an 30 | -- approximation. 31 | -- 32 | -- Note also that if parallel slaves are spread across multiple nodes on 33 | -- a RAC database the PX_SERVERS_EXECUTIONS column will not be set. 34 | -- 35 | -- See kerryosborne.oracle-guy.com for additional information. 36 | --------------------------------------------------------------------------------------- 37 | set pagesize 999 38 | set lines 190 39 | col sql_text format a70 trunc 40 | col child format 99999 41 | col execs format 9,999 42 | col avg_etime format 99,999.99 43 | col "IO_SAVED_%" format 999.99 44 | col avg_px format 999 45 | col offload for a7 46 | 47 | select sql_id, child_number child, plan_hash_value plan_hash, executions execs, 48 | (elapsed_time/1000000)/decode(nvl(executions,0),0,1,executions)/ 49 | decode(px_servers_executions,0,1,px_servers_executions/decode(nvl(executions,0),0,1,executions)) avg_etime, 50 | px_servers_executions/decode(nvl(executions,0),0,1,executions) avg_px, 51 | decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,'No','Yes') Offload, 52 | decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,0,100*(IO_CELL_OFFLOAD_ELIGIBLE_BYTES-IO_INTERCONNECT_BYTES) 53 | /decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,1,IO_CELL_OFFLOAD_ELIGIBLE_BYTES)) "IO_SAVED_%", 54 | sql_text 55 | from v$sql s 56 | where upper(sql_text) like upper(nvl('&sql_text',sql_text)) 57 | and sql_text not like 'BEGIN :sql_text := %' 58 | and sql_text not like '%IO_CELL_OFFLOAD_ELIGIBLE_BYTES%' 59 | and sql_id like nvl('&sql_id',sql_id) 60 | order by 1, 2, 3 61 | / 62 | -------------------------------------------------------------------------------- /fsx2.sql: -------------------------------------------------------------------------------- 1 | set verify off 2 | set pagesize 999 3 | set lines 190 4 | col sql_text format a40 word_wrap 5 | col child format 99999 6 | col execs format 9,999 7 | col avg_etime format 99,999.99 8 | col avg_cpu format 9,999.99 9 | col avg_lio format 9,999,999 10 | col avg_pio format 9,999,999 11 | col "IO_SAVED_%" format 999.99 12 | col avg_px format 999 13 | col offload for a7 14 | 15 | select sql_id, avg_etime, px, Offload, sql_text from ( 16 | select sql_id, child_number child, plan_hash_value plan_hash, executions execs, 17 | (elapsed_time/1000000)/decode(nvl(executions,0),0,1,executions) avg_etime, 18 | --decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,buffer_gets/decode(nvl(executions,0),0,1,executions),null) avg_lio, 19 | --decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,disk_reads/decode(nvl(executions,0),0,1,executions),null) avg_pio, 20 | px_servers_executions/decode(nvl(executions,0),0,1,executions) px, 21 | decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,'No','Yes') Offload, 22 | decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,0, 23 | 100*(IO_CELL_OFFLOAD_ELIGIBLE_BYTES-IO_INTERCONNECT_BYTES) 24 | /decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,1,IO_CELL_OFFLOAD_ELIGIBLE_BYTES)) "IO_SAVED_%", 25 | sql_text 26 | from v$sql s 27 | where upper(sql_text) like upper(nvl('&sql_text',sql_text)) 28 | and sql_text not like 'BEGIN :sql_text := %' 29 | and sql_text not like '%IO_CELL_OFFLOAD_ELIGIBLE_BYTES%' 30 | and sql_id like nvl('&sql_id',sql_id) 31 | ) 32 | order by 1, 2, 3 33 | / 34 | -------------------------------------------------------------------------------- /fsx3.sql: -------------------------------------------------------------------------------- 1 | set verify off 2 | set pagesize 999 3 | set lines 190 4 | col sql_text format a20 trunc 5 | col child format 99999 6 | col execs format 9,999 7 | col avg_etime format 9,999,999.99 8 | col avg_cpu format 9,999,999.99 9 | col avg_lio format 999,999,999 10 | col avg_pio format 999,999,999 11 | col "IO_SAVED_%" format 999.99 12 | col avg_px format 999 13 | col offload for a7 14 | 15 | select sql_id, child_number child, 16 | decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,'No','Yes') Offload, 17 | executions execs, 18 | IO_CELL_OFFLOAD_ELIGIBLE_BYTES eligible_bytes, sql_text 19 | from v$sql s 20 | where upper(sql_text) like upper(nvl('&sql_text',sql_text)) 21 | and sql_text not like 'BEGIN :sql_text := %' 22 | and sql_text not like '%IO_CELL_OFFLOAD_ELIGIBLE_BYTES%' 23 | and sql_id like nvl('&sql_id',sql_id) 24 | order by 1, 2, 3 25 | / 26 | -------------------------------------------------------------------------------- /fsx4.sql: -------------------------------------------------------------------------------- 1 | set verify off 2 | set pagesize 999 3 | set lines 190 4 | col sql_text format a40 trunc 5 | col child format 99999 heading CHILD 6 | col execs format 9,999,999 7 | col avg_etime format 99,999.99 8 | col avg_cpu format 9,999,999.99 9 | col avg_lio format 999,999,999 10 | col avg_pio format 999,999,999 11 | col "IO_SAVED_%" format 999.99 12 | col avg_px format 999 13 | col offload for a7 14 | 15 | select sql_id, child_number child, 16 | decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,'No','Yes') Offload, 17 | decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,0, 18 | 100*(IO_CELL_OFFLOAD_ELIGIBLE_BYTES-IO_INTERCONNECT_BYTES) 19 | /decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,1,IO_CELL_OFFLOAD_ELIGIBLE_BYTES)) "IO_SAVED_%", 20 | (elapsed_time/1000000)/decode(nvl(executions,0),0,1,executions) avg_etime, 21 | --decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,buffer_gets/decode(nvl(executions,0),0,1,executions),null) avg_lio, 22 | --decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,disk_reads/decode(nvl(executions,0),0,1,executions),null) avg_pio, 23 | sql_text 24 | from v$sql s 25 | where upper(sql_text) like upper(nvl('&sql_text',sql_text)) 26 | and sql_text not like 'BEGIN :sql_text := %' 27 | and sql_text not like '%IO_CELL_OFFLOAD_ELIGIBLE_BYTES%' 28 | and sql_id like nvl('&sql_id',sql_id) 29 | order by 1, 2, 3 30 | / 31 | -------------------------------------------------------------------------------- /fsxo.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------------- 2 | -- 3 | -- File name: fsx.sql 4 | -- 5 | -- Purpose: Find SQL and report whether it was Offloaded and % of I/O saved. 6 | -- 7 | -- Author: Kerry Osborne 8 | -- 9 | -- Usage: This scripts prompts for two values. 10 | -- 11 | -- sql_text: a piece of a SQL statement like %select col1, col2 from skew% 12 | -- 13 | -- sql_id: the sql_id of the statement if you know it (leave blank to ignore) 14 | -- 15 | -- Description: 16 | -- 17 | -- This script can be used to locate statements in the shared pool and 18 | -- determine whether they have been executed via Smart Scans. 19 | -- 20 | -- It is based on the observation that the IO_CELL_OFFLOAD_ELIGIBLE_BYTES 21 | -- column in V$SQL is only greater than 0 when a statement is executed 22 | -- using a Smart Scan. The IO_SAVED_% column attempts to show the ratio of 23 | -- of data received from the storage cells to the actual amount of data 24 | -- that would have had to be retrieved on non-Exadata storage. Note that 25 | -- as of 11.2.0.2, there are issues calculating this value with some queries. 26 | -- 27 | -- Note that the AVG_ETIME will not be acurate for parallel queries. The 28 | -- ELAPSED_TIME column contains the sum of all parallel slaves. So the 29 | -- script divides the value by the number of PX slaves used which gives an 30 | -- approximation. 31 | -- 32 | -- Note also that if parallel slaves are spread across multiple nodes on 33 | -- a RAC database the PX_SERVERS_EXECUTIONS column will not be set. 34 | -- 35 | -- See kerryosborne.oracle-guy.com for additional information. 36 | --------------------------------------------------------------------------------------- 37 | set pagesize 999 38 | set lines 190 39 | col sql_text format a70 trunc 40 | col child format 99999 41 | col execs format 9,999 42 | col avg_etime format 99,999.99 43 | col "IO_SAVED_%" format 999.99 44 | col avg_px format 999 45 | col offload for a7 46 | 47 | select sql_id, child_number child, plan_hash_value plan_hash, executions execs, 48 | (elapsed_time/1000000)/decode(nvl(executions,0),0,1,executions)/ 49 | decode(px_servers_executions,0,1,px_servers_executions/decode(nvl(executions,0),0,1,executions)) avg_etime, 50 | px_servers_executions/decode(nvl(executions,0),0,1,executions) avg_px, 51 | decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,'No','Yes') Offload, 52 | decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,0,100*(IO_CELL_OFFLOAD_ELIGIBLE_BYTES-IO_INTERCONNECT_BYTES) 53 | /decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,1,IO_CELL_OFFLOAD_ELIGIBLE_BYTES)) "IO_SAVED_%", 54 | sql_text 55 | from v$sql s 56 | where upper(sql_text) like upper(nvl('&sql_text',sql_text)) 57 | and sql_text not like 'BEGIN :sql_text := %' 58 | and sql_text not like '%IO_CELL_OFFLOAD_ELIGIBLE_BYTES%' 59 | and sql_id like nvl('&sql_id',sql_id) 60 | and IO_CELL_OFFLOAD_ELIGIBLE_BYTES > 0 61 | order by 1, 2, 3 62 | / 63 | -------------------------------------------------------------------------------- /gather_table_stats.sql: -------------------------------------------------------------------------------- 1 | begin 2 | dbms_stats.gather_table_stats( 3 | '&owner','&table_name', 4 | method_opt => '&method_opt' 5 | ); 6 | end; 7 | / 8 | -------------------------------------------------------------------------------- /get_compression_ratio_12c.sql: -------------------------------------------------------------------------------- 1 | set sqlblanklines on 2 | set serveroutput on 3 | set feedback off 4 | accept owner - 5 | prompt 'Enter Value for owner: ' - 6 | default 'KSO' 7 | accept table_name - 8 | prompt 'Enter Value for table_name: ' - 9 | default 'SKEW' 10 | accept comp_type - 11 | prompt 'Enter Value for compression_type (QL|QH|AL|AH): ' - 12 | default 'QH' 13 | 14 | DECLARE 15 | 16 | l_blkcnt_cmp BINARY_INTEGER; 17 | l_blkcnt_uncmp BINARY_INTEGER; 18 | l_row_cmp BINARY_INTEGER; 19 | l_row_uncmp BINARY_INTEGER; 20 | l_cmp_ratio NUMBER; 21 | l_comptype_str VARCHAR2 (200); 22 | l_comptype NUMBER; 23 | BEGIN 24 | 25 | case '&&comp_type' 26 | when 'QL' then l_comptype := DBMS_COMPRESSION.COMP_QUERY_LOW; 27 | when 'QH' then l_comptype := DBMS_COMPRESSION.COMP_QUERY_HIGH; 28 | when 'AL' then l_comptype := DBMS_COMPRESSION.COMP_ARCHIVE_LOW; 29 | when 'AH' then l_comptype := DBMS_COMPRESSION.COMP_ARCHIVE_HIGH; 30 | else raise_application_error(-20001, 'unknown compression type-specify one of QL|QH|AL|AH'); 31 | end case; 32 | 33 | DBMS_COMPRESSION.get_compression_ratio ( 34 | scratchtbsname => 'USERS', 35 | ownname => '&owner', 36 | objname => '&table_name', 37 | subobjname => NULL, 38 | comptype => l_comptype, 39 | blkcnt_cmp => l_blkcnt_cmp, 40 | blkcnt_uncmp => l_blkcnt_uncmp, 41 | row_cmp => l_row_cmp, 42 | row_uncmp => l_row_uncmp, 43 | cmp_ratio => l_cmp_ratio, 44 | comptype_str => l_comptype_str 45 | ); 46 | 47 | dbms_output.put_line(' '); 48 | dbms_output.put_line(' '); 49 | dbms_output.put_line(' '); 50 | dbms_output.put_line(' '); 51 | DBMS_OUTPUT.put_line ('Estimated Compression Ratio using '||l_comptype_str||': '|| round(l_cmp_ratio,3)); 52 | dbms_output.put_line(' '); 53 | 54 | END; 55 | / 56 | undef owner 57 | undef table_name 58 | undef comp_type 59 | set feedback on 60 | -------------------------------------------------------------------------------- /mystat.sql: -------------------------------------------------------------------------------- 1 | col name for a60 2 | col value for 99999999999999 3 | select name, value 4 | from v$mystat s, v$statname n 5 | where n.statistic# = s.statistic# 6 | and name like nvl('&stat_name',name) 7 | / 8 | -------------------------------------------------------------------------------- /obj_by_hex.sql: -------------------------------------------------------------------------------- 1 | col object_name for a30 2 | select owner, object_name, object_type 3 | from dba_objects 4 | where data_object_id = to_number(replace('&hex_value','0x',''),'XXXXXX'); 5 | -------------------------------------------------------------------------------- /offload_percent.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------------- 2 | -- 3 | -- File name: offload_percent.sql 4 | -- 5 | -- Purpose: Caclulate % of long running statements that were offloaded. 6 | -- 7 | -- Author: Kerry Osborne 8 | -- 9 | -- Usage: This scripts prompts for three values. 10 | -- 11 | -- sql_text: a piece of a SQL statement like %select col1, col2 from skew% 12 | -- The default is to return all statements. 13 | -- 14 | -- min_etime: the minimum avg. elapsed time in seconds 15 | -- This parameter allows limiting the output to long running statements. 16 | -- The default is 0 which returns all statements. 17 | -- 18 | -- min_avg_lio: the minimum avg. elapsed time in seconds 19 | -- This parameter allows limiting the output to long running statements. 20 | -- The default is 500,000. 21 | -- 22 | -- Description: 23 | -- 24 | -- This script can be used to provide a quick check on whether statements 25 | -- are being offloaded or not on Exadata platforms. 26 | -- 27 | -- It is based on the observation that the IO_CELL_OFFLOAD_ELIGIBLE_BYTES 28 | -- column in V$SQL is only greater than 0 when a statement is executed 29 | -- using a Smart Scan. 30 | -- 31 | -- The default values will aggregate data for all statements that have an 32 | -- avg_lio value of greater than 500,000. You can change this minimum value 33 | -- or further limit the set of statements that will be evaluated by providing 34 | -- a piece of SQL text, 'select%' for example, or setting a minimum avg. 35 | -- elapsed time value. 36 | -- 37 | -- See kerryosborne.oracle-guy.com for additional information. 38 | --------------------------------------------------------------------------------------- 39 | set pagesize 999 40 | set lines 190 41 | col sql_text format a70 trunc 42 | col child format 99999 43 | col execs format 9,999 44 | col avg_etime format 99,999.99 45 | col "OFFLOADED_%" format a11 46 | col avg_px format 999 47 | col offload for a7 48 | 49 | select 50 | offloaded+not_offloaded total, offloaded, 51 | lpad(to_char(round(100*offloaded/ (offloaded+not_offloaded),2))||'%',11,' ') "OFFLOADED_%" 52 | from ( 53 | select sum(decode(offload,'Yes',1,0)) offloaded, 54 | sum(decode(offload,'No',1,0)) not_offloaded 55 | from ( 56 | select * from ( 57 | select sql_id, child_number child, plan_hash_value plan_hash, executions execs, 58 | (elapsed_time/1000000)/decode(nvl(executions,0),0,1,executions)/ 59 | decode(px_servers_executions,0,1,px_servers_executions/decode(nvl(executions,0),0,1,executions)) avg_etime, 60 | px_servers_executions/decode(nvl(executions,0),0,1,executions) avg_px, 61 | decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,'No','Yes') Offload, 62 | decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,0,100*(IO_CELL_OFFLOAD_ELIGIBLE_BYTES-IO_INTERCONNECT_BYTES) 63 | /decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,1,IO_CELL_OFFLOAD_ELIGIBLE_BYTES)) "IO_SAVED_%", 64 | -- buffer_gets lio, 65 | buffer_gets/decode(nvl(executions,0),0,1,executions) avg_lio, 66 | sql_text 67 | from v$sql s 68 | where upper(sql_text) like upper(nvl('&sql_text',sql_text)) 69 | and sql_text not like 'BEGIN :sql_text := %' 70 | and sql_text not like '%IO_CELL_OFFLOAD_ELIGIBLE_BYTES%') 71 | where avg_etime > nvl('&min_etime','0') 72 | ) 73 | where avg_lio > nvl('&min_avg_lio','500000') 74 | ) 75 | / 76 | -------------------------------------------------------------------------------- /parms.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------------- 2 | -- 3 | -- File name: parms.sql 4 | -- Purpose: Display parameters and values. 5 | - 6 | -- Author: Kerry Osborne 7 | -- 8 | -- Usage: This scripts prompts for three values, all of which can be left blank. 9 | -- 10 | -- name: the name (or piece of a name) of the parameter(s) you wish to see 11 | -- 12 | -- isset: "TRUE" or "T" to see only nondefault parameters 13 | -- 14 | -- show_hidden: "Y" to show hidden parameters as well 15 | -- 16 | --------------------------------------------------------------------------------------- 17 | set lines 155 18 | col name for a50 19 | col value for a70 20 | col isdefault for a8 21 | col ismodified for a10 22 | col isset for a10 23 | select name, value, isdefault, ismodified, isset 24 | from 25 | ( 26 | select flag,name,value,isdefault,ismodified, 27 | case when isdefault||ismodified = 'TRUEFALSE' then 'FALSE' else 'TRUE' end isset 28 | from 29 | ( 30 | select 31 | decode(substr(i.ksppinm,1,1),'_',2,1) flag 32 | , i.ksppinm name 33 | , sv.ksppstvl value 34 | , sv.ksppstdf isdefault 35 | -- , decode(bitand(sv.ksppstvf,7),1,'MODIFIED',4,'SYSTEM_MOD','FALSE') ismodified 36 | , decode(bitand(sv.ksppstvf,7),1,'TRUE',4,'TRUE','FALSE') ismodified 37 | from sys.x$ksppi i 38 | , sys.x$ksppsv sv 39 | where i.indx = sv.indx 40 | ) 41 | ) 42 | where name like nvl('%¶meter%',name) 43 | and upper(isset) like upper(nvl('%&isset%',isset)) 44 | and flag not in (decode('&show_hidden','Y',3,2)) 45 | order by flag,replace(name,'_','') 46 | / 47 | -------------------------------------------------------------------------------- /parmsd.sql: -------------------------------------------------------------------------------- 1 | ---------------------------------------------------------------------------------------- 2 | -- 3 | -- File name: parmsd.sql 4 | -- Purpose: Display parameters and descriptions. 5 | - 6 | -- Author: Kerry Osborne 7 | -- 8 | -- Usage: This scripts prompts for one value which can be left blank. 9 | -- 10 | -- name: the name (or piece of a name) of the parameter(s) you wish to see 11 | -- 12 | --------------------------------------------------------------------------------------- 13 | set lines 155 14 | col name for a50 15 | col value for a30 trunc 16 | col description for a50 wrap 17 | col isdefault for a8 18 | col ismodified for a10 19 | col isset for a10 20 | select name, value, description 21 | from 22 | ( 23 | select flag,name,value,isdefault,ismodified, 24 | case when isdefault||ismodified = 'TRUEFALSE' then 'FALSE' else 'TRUE' end isset , 25 | description 26 | from 27 | ( 28 | select 29 | decode(substr(i.ksppinm,1,1),'_',2,1) flag 30 | , i.ksppinm name 31 | , sv.ksppstvl value 32 | , sv.ksppstdf isdefault 33 | -- , decode(bitand(sv.ksppstvf,7),1,'MODIFIED',4,'SYSTEM_MOD','FALSE') ismodified 34 | , decode(bitand(sv.ksppstvf,7),1,'TRUE',4,'TRUE','FALSE') ismodified 35 | , i.KSPPDESC description 36 | from sys.x$ksppi i 37 | , sys.x$ksppsv sv 38 | where i.indx = sv.indx 39 | ) 40 | ) 41 | where name like nvl('%¶meter%',name) 42 | and upper(isset) like upper(nvl('%&isset%',isset)) 43 | and flag not in (decode('&show_hidden','Y',3,2)) 44 | order by flag,replace(name,'_','') 45 | / 46 | -------------------------------------------------------------------------------- /part_size2.sql: -------------------------------------------------------------------------------- 1 | set lines 155 2 | compute sum of totalsize_megs on report 3 | break on report on owner on segment_name 4 | col owner for a20 5 | col segment_name for a20 6 | col part_name for a20 7 | col segment_type for a10 8 | col totalsize_megs for 999,999.9 9 | select s.owner, segment_name, t.partition_name part_name, 10 | sum(bytes/1024/1024) as totalsize_megs, compress_for 11 | from dba_segments s, dba_tab_partitions t 12 | where s.owner = t.table_owner 13 | and t.table_name = s.segment_name 14 | and s.owner like nvl('&owner',s.owner) 15 | and segment_name like nvl('&table_name',segment_name) 16 | group by s.owner, segment_name, t.partition_name, compress_for 17 | order by 3; 18 | -------------------------------------------------------------------------------- /pool_mem.sql: -------------------------------------------------------------------------------- 1 | col area for a30 2 | col megs for 999,999.0 3 | compute sum of megs on report 4 | break on report 5 | select area,sum(megs) megs from ( 6 | select case when name in ('fixed_sga','free memory', 'buffer_cache','log_buffer') 7 | then name 8 | else pool end Area 9 | ,(bytes/(1024*1024)) Megs from v$sgastat) 10 | group by area 11 | / 12 | 13 | -------------------------------------------------------------------------------- /si.sql: -------------------------------------------------------------------------------- 1 | col name for a70 2 | col value for 99999999999999 3 | select name, value 4 | from v$mystat s, v$statname n 5 | where n.statistic# = s.statistic# 6 | and name = 'cell physical IO bytes saved by storage index'; 7 | 8 | col name clear 9 | col value clear 10 | -------------------------------------------------------------------------------- /ss_off.sql: -------------------------------------------------------------------------------- 1 | alter session set "_serial_direct_read"=always; 2 | set echo on 3 | alter session set cell_offload_processing=false; 4 | alter session set "_kcfis_storageidx_disabled"=true; 5 | set echo off 6 | -------------------------------------------------------------------------------- /ss_on.sql: -------------------------------------------------------------------------------- 1 | set echo on 2 | alter session set "_serial_direct_read"=always; 3 | alter session set cell_offload_processing=true; 4 | set echo off 5 | -------------------------------------------------------------------------------- /table_size.sql: -------------------------------------------------------------------------------- 1 | set lines 155 2 | compute sum of totalsize_megs on report 3 | break on report 4 | col owner for a20 5 | col segment_name for a30 6 | col segment_type for a10 7 | col totalsize_megs for 999,999.9 8 | select * from ( 9 | select owner, segment_name, segment_type type, 10 | sum(bytes/1024/1024) as totalsize_megs, 11 | tablespace_name 12 | from dba_segments 13 | where owner like nvl('&owner',owner) 14 | and segment_name like nvl('&table_name',segment_name) 15 | and segment_type like nvl('&type',segment_type) 16 | group by owner, segment_name, tablespace_name, segment_type 17 | order by 4 desc 18 | ) 19 | where rownum < 30 20 | order by 4; 21 | -------------------------------------------------------------------------------- /table_size2.sql: -------------------------------------------------------------------------------- 1 | set lines 155 2 | compute sum of totalsize_megs on report 3 | break on report 4 | col owner for a20 5 | col segment_name for a30 6 | col segment_type for a10 7 | col totalsize_megs for 999,999.9 8 | select s.owner, segment_name, 9 | sum(bytes/1024/1024) as totalsize_megs, compress_for 10 | from dba_segments s, dba_tables t 11 | where s.owner = t.owner 12 | and t.table_name = s.segment_name 13 | and s.owner like nvl('&owner',s.owner) 14 | and t.table_name like nvl('&table_name',segment_name) 15 | group by s.owner, segment_name, compress_for 16 | order by 3; 17 | -------------------------------------------------------------------------------- /valid_events.sql: -------------------------------------------------------------------------------- 1 | select name from v$event_name 2 | where name like nvl('&event_name',name) 3 | order by 1 4 | / 5 | -------------------------------------------------------------------------------- /whoami.sql: -------------------------------------------------------------------------------- 1 | set line 132 2 | col username for a15 3 | col schemaname for a15 4 | SELECT s.username, s.user#, s.sid, s.serial#, s.prev_hash_value, schemaname, p.spid os_pid 5 | FROM V$SESSION S, v$process p 6 | WHERE audsid = SYS_CONTEXT('userenv','sessionid') 7 | and p.addr = s.paddr 8 | and s.username is not null 9 | / 10 | -------------------------------------------------------------------------------- /whoami_12c.sql: -------------------------------------------------------------------------------- 1 | set line 150 2 | col username for a15 3 | SELECT s.username, s.user#, s.sid, s.serial#, s.prev_hash_value, schemaname, p.spid os_pid, p.stid 4 | FROM V$SESSION S, v$process p 5 | WHERE audsid = SYS_CONTEXT('userenv','sessionid') 6 | and p.addr = s.paddr 7 | and s.username is not null 8 | / 9 | --------------------------------------------------------------------------------