diff --git a/Alberto/README.txt b/Alberto/README.txt new file mode 100644 index 0000000..625c129 --- /dev/null +++ b/Alberto/README.txt @@ -0,0 +1,11 @@ +xplan utility - copyright (C) 2008-2012 Alberto Dell'Era, www.adellera.it + +Uncompress this .zip in a directory of your choice. + +Change local directory to that directory (or add it to your SQLPATH environment variable). + +Log in sqlplus, than run the script +@xplan + +See xplan.sql comment header for more informations. + diff --git a/Alberto/xplan.display.sql b/Alberto/xplan.display.sql new file mode 100644 index 0000000..c801e60 --- /dev/null +++ b/Alberto/xplan.display.sql @@ -0,0 +1,214 @@ + +-- ---------------------------------------------------------------------------------------------- +-- +-- Utility: XPLAN +-- +-- Script: xplan.display.sql +-- +-- Version: 1.2 +-- +-- Author: Adrian Billington +-- www.oracle-developer.net +-- (c) oracle-developer.net +-- +-- Description: A free-standing SQL wrapper over DBMS_XPLAN. Provides access to the +-- DBMS_XPLAN.DISPLAY pipelined function for an explained SQL statement. +-- +-- The XPLAN utility has one purpose: to include the parent operation ID (PID) +-- and an execution order column (OID) in the plan output. This makes plan +-- interpretation easier for larger or more complex execution plans. +-- +-- See the following example for details. +-- +-- Example: DBMS_XPLAN output (format BASIC): +-- ------------------------------------------------ +-- | Id | Operation | Name | +-- ------------------------------------------------ +-- | 0 | SELECT STATEMENT | | +-- | 1 | MERGE JOIN | | +-- | 2 | TABLE ACCESS BY INDEX ROWID| DEPT | +-- | 3 | INDEX FULL SCAN | PK_DEPT | +-- | 4 | SORT JOIN | | +-- | 5 | TABLE ACCESS FULL | EMP | +-- ------------------------------------------------ +-- +-- Equivalent XPLAN output (format BASIC): +-- ------------------------------------------------------------ +-- | Id | Pid | Ord | Operation | Name | +-- ------------------------------------------------------------ +-- | 0 | | 6 | SELECT STATEMENT | | +-- | 1 | 0 | 5 | MERGE JOIN | | +-- | 2 | 1 | 2 | TABLE ACCESS BY INDEX ROWID| DEPT | +-- | 3 | 2 | 1 | INDEX FULL SCAN | PK_DEPT | +-- | 4 | 1 | 4 | SORT JOIN | | +-- | 5 | 4 | 3 | TABLE ACCESS FULL | EMP | +-- ------------------------------------------------------------ +-- +-- Usage: @xplan.display.sql [plan_table] [statement_id] [plan_format] +-- +-- Parameters: 1) plan_table - OPTIONAL (defaults to PLAN_TABLE) +-- 2) statement_id - OPTIONAL (defaults to NULL) +-- 3) plan_format - OPTIONAL (defaults to TYPICAL) +-- +-- Examples: 1) Plan for last explained SQL statement +-- ------------------------------------- +-- @xplan.display.sql +-- +-- 2) Plan for a specific statement_id +-- -------------------------------- +-- @xplan.display.sql "" "my_statement_id" +-- +-- 3) Plan for last explained SQL statement using a non-standard plan table +-- --------------------------------------------------------------------- +-- @xplan.display.sql "my_plan_table" +-- +-- 4) Plan for last explained SQL statement with a non-default format +-- --------------------------------------------------------------- +-- @xplan.display.sql "" "" "basic +projection" +-- +-- 5) Plan for a specific statement_id and non-default format +-- ------------------------------------------------------- +-- @xplan.display.sql "" "my_statement_id" "advanced" +-- +-- 6) Plan for last explained SQL statement with a non-default plan table and non-default format +-- ------------------------------------------------------------------------------------------ +-- @xplan.display.sql "my_plan_table" "my_statement_id" "advanced" +-- +-- Versions: This utility will work for all versions of 10g and upwards. +-- +-- Required: 1) Access to a plan table that corresponds to the Oracle version being used. +-- +-- Notes: An XPLAN PL/SQL package is also available. This has wrappers for all of the +-- DBMS_XPLAN pipelined functions, but requires the creation of objects. +-- +-- Credits: 1) James Padfield for the hierarchical query to order the plan operations. +-- +-- Disclaimer: http://www.oracle-developer.net/disclaimer.php +-- +-- ---------------------------------------------------------------------------------------------- + +set define on +define v_xp_version = 1.2 + +-- Initialise variables 1,2,3 in case they aren't supplied... +-- ---------------------------------------------------------- +set termout off +column 1 new_value 1 +column 2 new_value 2 +column 3 new_value 3 +select null as "1" +, null as "2" +, null as "3" +from dual +where 1=2; + +-- Set the plan table... +-- --------------------- +column plan_table new_value v_xp_plan_table +select nvl('&1', 'PLAN_TABLE') as plan_table +from dual; + +-- Finally prepare the inputs to the main Xplan SQL... +-- --------------------------------------------------- +column plan_id new_value v_xp_plan_id +column stmt_id new_value v_xp_stmt_id +column format new_value v_xp_format +select nvl(max(plan_id), -1) as plan_id +, max(statement_id) keep (dense_rank first order by plan_id desc) as stmt_id +, nvl(max('&3'), 'typical') as format +from &v_xp_plan_table +where id = 0 +and nvl(statement_id, '~') = coalesce('&2', statement_id, '~'); + +-- Main Xplan SQL... +-- ----------------- +set termout on lines 150 pages 1000 +col plan_table_output format a150 + +with sql_plan_data as ( + select id, parent_id + from &v_xp_plan_table + where plan_id = &v_xp_plan_id + order by id + ) +, hierarchy_data as ( + select id, parent_id + from sql_plan_data + start with id = 0 + connect by prior id = parent_id + order siblings by id desc + ) +, ordered_hierarchy_data as ( + select id + , parent_id as pid + , row_number() over (order by rownum desc) as oid + , max(id) over () as maxid + from hierarchy_data + ) +, xplan_data as ( + select /*+ ordered use_nl(o) */ + rownum as r + , x.plan_table_output as plan_table_output + , o.id + , o.pid + , o.oid + , o.maxid + , count(*) over () as rc + from table(dbms_xplan.display('&v_xp_plan_table','&v_xp_stmt_id','&v_xp_format')) x + left outer join + ordered_hierarchy_data o + on (o.id = case + when regexp_like(x.plan_table_output, '^\|[\* 0-9]+\|') + then to_number(regexp_substr(x.plan_table_output, '[0-9]+')) + end) + ) +select plan_table_output +from xplan_data +model + dimension by (rownum as r) + measures (plan_table_output, + id, + maxid, + pid, + oid, + rc, + greatest(max(length(maxid)) over () + 3, 6) as csize, + cast(null as varchar2(128)) as inject) + rules sequential order ( + inject[r] = case + when id[cv()+1] = 0 + or id[cv()+3] = 0 + or id[cv()-1] = maxid[cv()-1] + then rpad('-', csize[cv()]*2, '-') + when id[cv()+2] = 0 + then '|' || lpad('Pid |', csize[cv()]) || lpad('Ord |', csize[cv()]) + when id[cv()] is not null + then '|' || lpad(pid[cv()] || ' |', csize[cv()]) || lpad(oid[cv()] || ' |', csize[cv()]) + end, + plan_table_output[r] = case + when inject[cv()] like '---%' + then inject[cv()] || plan_table_output[cv()] + when inject[cv()] is not null + then regexp_replace(plan_table_output[cv()], '\|', inject[cv()], 1, 2) + else plan_table_output[cv()] + end || + case + when cv(r) = rc[cv()] + then chr(10) || chr(10) || + 'About' || chr(10) || + '------' || chr(10) || + ' - XPlan v&v_xp_version by Adrian Billington (http://www.oracle-developer.net)' + end + ) +order by r; + +-- Teardown... +-- ----------- +undefine v_xp_plan_table +undefine v_xp_plan_id +undefine v_xp_stmt_id +undefine v_xp_format +undefine v_xp_version +undefine 1 +undefine 2 +undefine 3 diff --git a/Alberto/xplan.display_awr.sql b/Alberto/xplan.display_awr.sql new file mode 100644 index 0000000..f24c86e --- /dev/null +++ b/Alberto/xplan.display_awr.sql @@ -0,0 +1,239 @@ + +-- ---------------------------------------------------------------------------------------------- +-- +-- Utility: XPLAN +-- +-- Script: xplan.display_awr.sql +-- +-- Version: 1.2 +-- +-- Author: Adrian Billington +-- www.oracle-developer.net +-- (c) oracle-developer.net +-- +-- Description: A free-standing SQL wrapper over DBMS_XPLAN. Provides access to the +-- DBMS_XPLAN.DISPLAY_AWR pipelined function for a given SQL_ID and optional +-- plan hash value. +-- +-- The XPLAN utility has one purpose: to include the parent operation ID (PID) +-- and an execution order column (OID) in the plan output. This makes plan +-- interpretation easier for larger or more complex execution plans. +-- +-- See the following example for details. +-- +-- Example: DBMS_XPLAN output (format BASIC): +-- ------------------------------------------------ +-- | Id | Operation | Name | +-- ------------------------------------------------ +-- | 0 | SELECT STATEMENT | | +-- | 1 | MERGE JOIN | | +-- | 2 | TABLE ACCESS BY INDEX ROWID| DEPT | +-- | 3 | INDEX FULL SCAN | PK_DEPT | +-- | 4 | SORT JOIN | | +-- | 5 | TABLE ACCESS FULL | EMP | +-- ------------------------------------------------ +-- +-- Equivalent XPLAN output (format BASIC): +-- ------------------------------------------------------------ +-- | Id | Pid | Ord | Operation | Name | +-- ------------------------------------------------------------ +-- | 0 | | 6 | SELECT STATEMENT | | +-- | 1 | 0 | 5 | MERGE JOIN | | +-- | 2 | 1 | 2 | TABLE ACCESS BY INDEX ROWID| DEPT | +-- | 3 | 2 | 1 | INDEX FULL SCAN | PK_DEPT | +-- | 4 | 1 | 4 | SORT JOIN | | +-- | 5 | 4 | 3 | TABLE ACCESS FULL | EMP | +-- ------------------------------------------------------------ +-- +-- Usage: @xplan.display_awr.sql [plan_hash_value] [plan_format] +-- +-- Parameters: 1) sql_id - MANDATORY +-- 2) plan_hash_value - OPTIONAL (defaults to all available for the SQL ID) +-- 3) plan_format - OPTIONAL (defaults to TYPICAL) +-- +-- Examples: 1) All AWR plans for a SQL_ID +-- -------------------------- +-- @xplan.display_awr.sql 9vfvgsk7mtkr4 +-- +-- 2) All AWR plans for a SQL_ID with a non-default format +-- ---------------------------------------------------- +-- @xplan.display_awr.sql 9vfvgsk7mtkr4 "" "basic +projection" +-- +-- 3) AWR plan for a SQL_ID and specific PLAN_HASH_VALUE +-- -------------------------------------------------- +-- @xplan.display_awr.sql 9vfvgsk7mtkr4 63301235 +-- +-- 4) AWR plan for a SQL_ID, specific PLAN_HASH_VALUE and non-default format +-- ---------------------------------------------------------------------- +-- @xplan.display_awr.sql 9vfvgsk7mtkr4 63301235 "advanced" +-- +-- Versions: This utility will work for all versions of 10g and upwards. +-- +-- Required: *** IMPORTANT: PLEASE READ *** +-- +-- 1) Oracle license implications +-- --------------------------- +-- The AWR functionality of XPLAN accesses a DBA_HIST% AWR view which means +-- that it requires an Oracle Tuning and Diagnostic Pack license. Please +-- ensure that you are licensed to use this feature: the author accepts +-- no responsibility for any use of this functionality in an unlicensed database. +-- +-- 2) Access to the DBA_HIST_SQL_PLAN AWR view. +-- +-- Notes: An XPLAN PL/SQL package is also available. This has wrappers for all of the +-- DBMS_XPLAN pipelined functions, but requires the creation of objects. +-- +-- Credits: 1) James Padfield for the hierarchical query to order the plan operations. +-- +-- Disclaimer: http://www.oracle-developer.net/disclaimer.php +-- +-- ---------------------------------------------------------------------------------------------- + +set define on +define v_xa_version = 1.2 + +-- Initialise variables 1,2,3 in case they aren't supplied... +-- ---------------------------------------------------------- +set termout off +column 1 new_value 1 +column 2 new_value 2 +column 3 new_value 3 +select null as "1" +, null as "2" +, null as "3" +from dual +where 1=2; + +-- Define the parameters... +-- ------------------------ +column dbid new_value v_xa_dbid +column sql_id new_value v_xa_sql_id +column format new_value v_xa_format +column plan_hash_value new_value v_xa_plan_hash_value +select dbid +, '&1' as sql_id +, nvl('&2', 'NULL') as plan_hash_value +, nvl('&3', 'TYPICAL') as format +from gv$database +where inst_id = sys_context('userenv','instance'); + +-- Main Xplan SQL... +-- ----------------- +set termout on lines 150 pages 1000 +col plan_table_output format a150 + +prompt _ _____________________________________________________________________ +prompt _ +prompt _ XPlan v&v_xa_version by Adrian Billington (http://www.oracle-developer.net) +prompt _ +prompt _ +prompt _ *** IMPORTANT: PLEASE READ *** +prompt _ +prompt _ A licence for the Oracle Tuning and Diagnostics Pack is needed to +prompt _ use this utility. Continue at your own risk: the author accepts +prompt _ no responsibility for any use of this functionality in an unlicensed +prompt _ database. +prompt _ +prompt _ To cancel: press Ctrl-C +prompt _ To continue: press Enter +prompt _ _____________________________________________________________________ +prompt +pause + +with sql_plan_data as ( + select id, parent_id, plan_hash_value + from dba_hist_sql_plan + where sql_id = '&v_xa_sql_id' + and plan_hash_value = nvl(&v_xa_plan_hash_value, plan_hash_value) + and dbid = &v_xa_dbid + ) +, hierarchy_data as ( + select id, parent_id, plan_hash_value + from sql_plan_data + start with id = 0 + connect by prior id = parent_id + and prior plan_hash_value = plan_hash_value + order siblings by id desc + ) +, ordered_hierarchy_data as ( + select id + , parent_id as pid + , plan_hash_value as phv + , row_number() over (partition by plan_hash_value order by rownum desc) as oid + , max(id) over (partition by plan_hash_value) as maxid + from hierarchy_data + ) +, xplan_data as ( + select /*+ ordered use_nl(o) */ + rownum as r + , x.plan_table_output as plan_table_output + , o.id + , o.pid + , o.oid + , o.maxid + , p.phv + , count(*) over () as rc + from ( + select distinct phv + from ordered_hierarchy_data + ) p + cross join + table(dbms_xplan.display_awr('&v_xa_sql_id',p.phv,&v_xa_dbid,'&v_xa_format')) x + left outer join + ordered_hierarchy_data o + on ( o.phv = p.phv + and o.id = case + when regexp_like(x.plan_table_output, '^\|[\* 0-9]+\|') + then to_number(regexp_substr(x.plan_table_output, '[0-9]+')) + end) + ) +select plan_table_output +from xplan_data +model + dimension by (phv, rownum as r) + measures (plan_table_output, + id, + maxid, + pid, + oid, + greatest(max(length(maxid)) over () + 3, 6) as csize, + cast(null as varchar2(128)) as inject, + rc) + rules sequential order ( + inject[phv,r] = case + when id[cv(),cv()+1] = 0 + or id[cv(),cv()+3] = 0 + or id[cv(),cv()-1] = maxid[cv(),cv()-1] + then rpad('-', csize[cv(),cv()]*2, '-') + when id[cv(),cv()+2] = 0 + then '|' || lpad('Pid |', csize[cv(),cv()]) || lpad('Ord |', csize[cv(),cv()]) + when id[cv(),cv()] is not null + then '|' || lpad(pid[cv(),cv()] || ' |', csize[cv(),cv()]) || lpad(oid[cv(),cv()] || ' |', csize[cv(),cv()]) + end, + plan_table_output[phv,r] = case + when inject[cv(),cv()] like '---%' + then inject[cv(),cv()] || plan_table_output[cv(),cv()] + when inject[cv(),cv()] is not null + then regexp_replace(plan_table_output[cv(),cv()], '\|', inject[cv(),cv()], 1, 2) + else plan_table_output[cv(),cv()] + end || + case + when cv(r) = rc[cv(),cv()] + then chr(10) || + 'About' || chr(10) || + '------' || chr(10) || + ' - XPlan v&v_xa_version by Adrian Billington (http://www.oracle-developer.net)' + end + ) +order by r; + +-- Teardown... +-- ----------- +undefine v_xa_sql_id +undefine v_xa_plan_hash_value +undefine v_xa_dbid +undefine v_xa_format +undefine v_xa_version +undefine 1 +undefine 2 +undefine 3 diff --git a/Alberto/xplan.display_cursor.sql b/Alberto/xplan.display_cursor.sql new file mode 100644 index 0000000..3cb92de --- /dev/null +++ b/Alberto/xplan.display_cursor.sql @@ -0,0 +1,219 @@ + +-- ---------------------------------------------------------------------------------------------- +-- +-- Utility: XPLAN +-- +-- Script: xplan.display_cursor.sql +-- +-- Version: 1.2 +-- +-- Author: Adrian Billington +-- www.oracle-developer.net +-- (c) oracle-developer.net +-- +-- Description: A free-standing SQL wrapper over DBMS_XPLAN. Provides access to the +-- DBMS_XPLAN.DISPLAY_CURSOR pipelined function for a given SQL_ID and CHILD_NO. +-- +-- The XPLAN utility has one purpose: to include the parent operation ID (PID) +-- and an execution order column (OID) in the plan output. This makes plan +-- interpretation easier for larger or more complex execution plans. +-- +-- See the following example for details. +-- +-- Example: DBMS_XPLAN output (format BASIC): +-- ------------------------------------------------ +-- | Id | Operation | Name | +-- ------------------------------------------------ +-- | 0 | SELECT STATEMENT | | +-- | 1 | MERGE JOIN | | +-- | 2 | TABLE ACCESS BY INDEX ROWID| DEPT | +-- | 3 | INDEX FULL SCAN | PK_DEPT | +-- | 4 | SORT JOIN | | +-- | 5 | TABLE ACCESS FULL | EMP | +-- ------------------------------------------------ +-- +-- Equivalent XPLAN output (format BASIC): +-- ------------------------------------------------------------ +-- | Id | Pid | Ord | Operation | Name | +-- ------------------------------------------------------------ +-- | 0 | | 6 | SELECT STATEMENT | | +-- | 1 | 0 | 5 | MERGE JOIN | | +-- | 2 | 1 | 2 | TABLE ACCESS BY INDEX ROWID| DEPT | +-- | 3 | 2 | 1 | INDEX FULL SCAN | PK_DEPT | +-- | 4 | 1 | 4 | SORT JOIN | | +-- | 5 | 4 | 3 | TABLE ACCESS FULL | EMP | +-- ------------------------------------------------------------ +-- +-- Usage: @xplan.display_cursor.sql [cursor_child_number] [format] +-- +-- Parameters: 1) sql_id - OPTIONAL (defaults to last executed SQL_ID) +-- 2) sql_child_number - OPTIONAL (defaults to 0) +-- 3) plan_format - OPTIONAL (defaults to TYPICAL) +-- +-- Examples: 1) Plan for last executed SQL (needs serveroutput off) +-- --------------------------------------------------- +-- @xplan.display_cursor.sql +-- +-- 2) Plan for a SQL_ID with default child number +-- ------------------------------------------- +-- @xplan.display_cursor.sql 9vfvgsk7mtkr4 +-- +-- 3) Plan for a SQL_ID with specific child number +-- -------------------------------------------- +-- @xplan.display_cursor.sql 9vfvgsk7mtkr4 1 +-- +-- 4) Plan for a SQL_ID with default child number and non-default format +-- ------------------------------------------------------------------ +-- @xplan.display_cursor.sql 9vfvgsk7mtkr4 "" "basic +projection" +-- +-- 5) Plan for a SQL_ID, specific child number and non-default format +-- --------------------------------------------------------------- +-- @xplan.display_cursor.sql 9vfvgsk7mtkr4 1 "advanced" +-- +-- Versions: This utility will work for all versions of 10g and upwards. +-- +-- Required: 1) Access to GV$SESSION, GV$SQL_PLAN +-- +-- Notes: An XPLAN PL/SQL package is also available. This has wrappers for all of the +-- DBMS_XPLAN pipelined functions, but requires the creation of objects. +-- +-- Credits: 1) James Padfield for the hierarchical query to order the plan operations. +-- 2) Paul Vale for the suggestion to turn XPLAN.DISPLAY_CURSOR into a standalone +-- SQL script, including a prototype. +-- +-- Disclaimer: http://www.oracle-developer.net/disclaimer.php +-- +-- ---------------------------------------------------------------------------------------------- + +set define on +define v_xc_version = 1.2 + +-- Fetch the previous SQL details in case they're not supplied... +-- -------------------------------------------------------------- +set termout off +column prev_sql_id new_value v_xc_prev_sql_id +column prev_child_number new_value v_xc_prev_child_no +select prev_sql_id +, prev_child_number +from gv$session +where inst_id = sys_context('userenv','instance') +and sid = sys_context('userenv','sid') +and username is not null +and prev_hash_value <> 0; + +-- Initialise variables 1,2,3 in case they aren't supplied... +-- ---------------------------------------------------------- +column 1 new_value 1 +column 2 new_value 2 +column 3 new_value 3 +select null as "1" +, null as "2" +, null as "3" +from dual +where 1=2; + +-- Finally prepare the inputs to the main Xplan SQL... +-- --------------------------------------------------- +column sql_id new_value v_xc_sql_id +column child_no new_value v_xc_child_no +column format new_value v_xc_format +select nvl('&1', '&v_xc_prev_sql_id') as sql_id +, to_number(nvl('&2', '&v_xc_prev_child_no')) as child_no +, nvl('&3', 'typical') as format +from dual; + +-- Main Xplan SQL... +-- ----------------- +set termout on lines 150 pages 1000 +col plan_table_output format a150 + +with sql_plan_data as ( + select id, parent_id + from gv$sql_plan + where inst_id = sys_context('userenv','instance') + and sql_id = '&v_xc_sql_id' + and child_number = to_number('&v_xc_child_no') + ) +, hierarchy_data as ( + select id, parent_id + from sql_plan_data + start with id = 0 + connect by prior id = parent_id + order siblings by id desc + ) +, ordered_hierarchy_data as ( + select id + , parent_id as pid + , row_number() over (order by rownum desc) as oid + , max(id) over () as maxid + from hierarchy_data + ) +, xplan_data as ( + select /*+ ordered use_nl(o) */ + rownum as r + , x.plan_table_output as plan_table_output + , o.id + , o.pid + , o.oid + , o.maxid + , count(*) over () as rc + from table(dbms_xplan.display_cursor('&v_xc_sql_id',to_number('&v_xc_child_no'),'&v_xc_format')) x + left outer join + ordered_hierarchy_data o + on (o.id = case + when regexp_like(x.plan_table_output, '^\|[\* 0-9]+\|') + then to_number(regexp_substr(x.plan_table_output, '[0-9]+')) + end) + ) +select plan_table_output +from xplan_data +model + dimension by (rownum as r) + measures (plan_table_output, + id, + maxid, + pid, + oid, + greatest(max(length(maxid)) over () + 3, 6) as csize, + cast(null as varchar2(128)) as inject, + rc) + rules sequential order ( + inject[r] = case + when id[cv()+1] = 0 + or id[cv()+3] = 0 + or id[cv()-1] = maxid[cv()-1] + then rpad('-', csize[cv()]*2, '-') + when id[cv()+2] = 0 + then '|' || lpad('Pid |', csize[cv()]) || lpad('Ord |', csize[cv()]) + when id[cv()] is not null + then '|' || lpad(pid[cv()] || ' |', csize[cv()]) || lpad(oid[cv()] || ' |', csize[cv()]) + end, + plan_table_output[r] = case + when inject[cv()] like '---%' + then inject[cv()] || plan_table_output[cv()] + when inject[cv()] is not null + then regexp_replace(plan_table_output[cv()], '\|', inject[cv()], 1, 2) + else plan_table_output[cv()] + end || + case + when cv(r) = rc[cv()] + then chr(10) || + 'About' || chr(10) || + '------' || chr(10) || + ' - XPlan v&v_xc_version by Adrian Billington (http://www.oracle-developer.net)' + end + ) +order by r; + + +-- Teardown... +-- ----------- +undefine v_xc_sql_id +undefine v_xc_child_no +undefine v_xc_format +undefine v_xc_prev_sql_id +undefine v_xc_prev_child_no +undefine v_xc_version +undefine 1 +undefine 2 +undefine 3 diff --git a/Alberto/xplan.package.sql b/Alberto/xplan.package.sql new file mode 100644 index 0000000..818be45 --- /dev/null +++ b/Alberto/xplan.package.sql @@ -0,0 +1,550 @@ + +-- ---------------------------------------------------------------------------------------------- +-- +-- Script: xplan.package.sql +-- +-- Version: 1.2 +-- +-- Author: Adrian Billington +-- www.oracle-developer.net +-- +-- Description: Creates a package named XPLAN as a wrapper over DBMS_XPLAN. Provides access to +-- the following DBMS_XPLAN pipelined functions: +-- +-- 1. DISPLAY; +-- 2. DISPLAY_CURSOR; +-- 3. DISPLAY_AWR (optional - see Notes section for licence implications). +-- +-- The XPLAN wrapper package has one purpose: to include the parent operation ID +-- and "order" columns in the plan output. This makes plan interpretation easier +-- for larger or more complex execution plans. See the following example for +-- details. +-- +-- Example: DBMS_XPLAN output (format BASIC): +-- ------------------------------------------------ +-- | Id | Operation | Name | +-- ------------------------------------------------ +-- | 0 | SELECT STATEMENT | | +-- | 1 | MERGE JOIN | | +-- | 2 | TABLE ACCESS BY INDEX ROWID| DEPT | +-- | 3 | INDEX FULL SCAN | PK_DEPT | +-- | 4 | SORT JOIN | | +-- | 5 | TABLE ACCESS FULL | EMP | +-- ------------------------------------------------ +-- +-- Equivalent XPLAN output (format BASIC): +-- -------------------------------------------------------------- +-- | Id | PID | Order | Operation | Name | +-- -------------------------------------------------------------- +-- | 0 | | 6 | SELECT STATEMENT | | +-- | 1 | 0 | 5 | MERGE JOIN | | +-- | 2 | 1 | 2 | TABLE ACCESS BY INDEX ROWID| DEPT | +-- | 3 | 2 | 1 | INDEX FULL SCAN | PK_DEPT | +-- | 4 | 1 | 4 | SORT JOIN | | +-- | 5 | 4 | 3 | TABLE ACCESS FULL | EMP | +-- -------------------------------------------------------------- +-- +-- Usage: SELECT * FROM TABLE(XPLAN.DISPLAY(...)); +-- SELECT * FROM TABLE(XPLAN.DISPLAY_CURSOR(...)); +-- SELECT * FROM TABLE(XPLAN.DISPLAY_AWR(...)); +-- +-- Usage for XPLAN is the same as for DBMS_XPLAN. See the DBMS_XPLAN +-- documentation for all options. +-- +-- Note that the only exception to this is that XPLAN.DISPLAY does not contain +-- the FILTER_PREDS parameter available in 10.2+ versions of DBMS_XPLAN.DISPLAY +-- (this parameter enables us to limit the data being returned from an Explain +-- Plan but is of quite limited use). +-- +-- See the Notes section below for details on the licensing implications of +-- using XPLAN.DISPLAY_AWR. +-- +-- Versions: This utility will work for all versions of 10g and upwards. +-- +-- Required: 1) PLAN_TABLE of at least 10.1 format +-- +-- 2) Either: +-- SELECT ANY DICTIONARY +-- Or: +-- SELECT on V$DATABASE +-- SELECT on V$SQL_PLAN +-- SELECT on V$SESSION +-- SELECT on V$MYSTAT +-- SELECT on DBA_HIST_SQL_PLAN +-- Or: +-- SELECT_CATALOG_ROLE +-- +-- 3) CREATE TYPE, CREATE PROCEDURE +-- +-- Note that the SQL statements that access V$ views are all dynamic and the +-- package uses invoker rights. This means that the package will compile in +-- constrained developer environments where explicit privileges on V$ views +-- are not granted and access to the views is only available via roles such as +-- SELECT_CATALOG_ROLE. +-- +-- Notes: *** IMPORTANT: PLEASE READ *** +-- +-- 1) Oracle license implications +-- --------------------------- +-- The AWR functionality of XPLAN accesses a DBA_HIST% view which means +-- that it requires an Oracle Diagnostic Pack license. The XPLAN.DISPLAY_AWR +-- pipelined function is therefore disabled by default. It can be included +-- by modifying two substitution variables at the start of the script. Please +-- ensure that you are licensed to use this feature: the author accepts +-- no responsibility for any use of this functionality in an unlicensed database. +-- +-- Installation: Installation requires SQL*Plus or any IDE that supports substitution +-- variables and SQL*Plus SET commands. To install, simply run the script in +-- the target schema. +-- +-- Creates: 1) XPLAN_OT object type +-- 2) XPLAN_NTT collection type +-- 3) XPLAN package +-- +-- Removal: 1) DROP PACKAGE xplan; +-- 3) DROP TYPE xplan_ntt; +-- 4) DROP TYPE xplan_ot; +-- +-- Credits: James Padfield for the hierarchical query to order the plan operations. +-- +-- Disclaimer: http://www.oracle-developer.net/disclaimer.php +-- +-- ---------------------------------------------------------------------------------------------- + +-- +-- Define the "commenting-out" substitution variables for the AWR elements of this utility. The +-- default is commented out. To include the AWR functionality, change the variables to " " (i.e. +-- a single space). +-- + +SET DEFINE ON +DEFINE _awr_start = "/*" +DEFINE _awr_end = "*/" + +-- +-- Supporting types for the pipelined functions... +-- + +CREATE OR REPLACE TYPE xplan_ot AS OBJECT +( plan_table_output VARCHAR2(300) ); +/ + +CREATE OR REPLACE TYPE xplan_ntt AS + TABLE OF xplan_ot; +/ + +-- +-- Xplan package... +-- + +CREATE OR REPLACE PACKAGE xplan AUTHID CURRENT_USER AS + + FUNCTION display( p_table_name IN VARCHAR2 DEFAULT 'PLAN_TABLE', + p_statement_id IN VARCHAR2 DEFAULT NULL, + p_format IN VARCHAR2 DEFAULT 'TYPICAL' ) + RETURN xplan_ntt PIPELINED; + + FUNCTION display_cursor( p_sql_id IN VARCHAR2 DEFAULT NULL, + p_cursor_child_no IN INTEGER DEFAULT 0, + p_format IN VARCHAR2 DEFAULT 'TYPICAL' ) + RETURN xplan_ntt PIPELINED; + +&_awr_start + FUNCTION display_awr( p_sql_id IN VARCHAR2, + p_plan_hash_value IN INTEGER DEFAULT NULL, + p_db_id IN INTEGER DEFAULT NULL, + p_format IN VARCHAR2 DEFAULT 'TYPICAL' ) + RETURN xplan_ntt PIPELINED; +&_awr_end + +END xplan; +/ + +CREATE OR REPLACE PACKAGE BODY xplan AS + + TYPE ntt_map_binds IS TABLE OF VARCHAR2(100); + + TYPE rt_map IS RECORD + ( ord PLS_INTEGER + , pid PLS_INTEGER ); + + TYPE aat_map IS TABLE OF rt_map + INDEX BY PLS_INTEGER; + + g_map aat_map; + g_hdrs PLS_INTEGER; + g_len PLS_INTEGER; + g_pad VARCHAR2(300); + + ---------------------------------------------------------------------------- + PROCEDURE reset_state IS + BEGIN + g_hdrs := 0; + g_len := 0; + g_pad := NULL; + g_map.DELETE; + END reset_state; + + ---------------------------------------------------------------------------- + FUNCTION info RETURN xplan_ot IS + BEGIN + RETURN xplan_ot(CHR(10) || + 'About' || CHR(10) || + '-----' || CHR(10) || + ' - XPlan v1.2 by Adrian Billington (http://www.oracle-developer.net)' ); + END info; + + ---------------------------------------------------------------------------- + PROCEDURE build_map( p_sql IN VARCHAR2, + p_binds IN ntt_map_binds ) IS + + TYPE rt_id_data IS RECORD + ( id PLS_INTEGER + , pid PLS_INTEGER + , ord PLS_INTEGER ); + + TYPE aat_id_data IS TABLE OF rt_id_data + INDEX BY PLS_INTEGER; + + aa_ids aat_id_data; + v_cursor SYS_REFCURSOR; + v_sql VARCHAR2(32767); + + BEGIN + + -- Build SQL template... + -- --------------------- + v_sql := 'WITH sql_plan_data AS ( ' || + p_sql || ' + ) + , hierarchical_sql_plan_data AS ( + SELECT id + , parent_id + FROM sql_plan_data + START WITH id = 0 + CONNECT BY PRIOR id = parent_id + ORDER SIBLINGS BY id DESC + ) + SELECT id + , parent_id + , ROW_NUMBER() OVER (ORDER BY ROWNUM DESC) AS ord + FROM hierarchical_sql_plan_data'; + + -- Binds will differ according to plan type... + -- ------------------------------------------- + CASE p_binds.COUNT + WHEN 0 + THEN + OPEN v_cursor FOR v_sql; + WHEN 1 + THEN + OPEN v_cursor FOR v_sql USING p_binds(1); + WHEN 2 + THEN + OPEN v_cursor FOR v_sql USING p_binds(1), + TO_NUMBER(p_binds(2)); + WHEN 3 + THEN + OPEN v_cursor FOR v_sql USING p_binds(1), + TO_NUMBER(p_binds(2)), + TO_NUMBER(p_binds(3)); + END CASE; + + -- Fetch the IDs and order data... + -- ------------------------------- + FETCH v_cursor BULK COLLECT INTO aa_ids; + CLOSE v_cursor; + + -- Populate the map array... + -- ------------------------- + FOR i IN 1 .. aa_ids.COUNT LOOP + g_map(aa_ids(i).id).ord := aa_ids(i).ord; + g_map(aa_ids(i).id).pid := aa_ids(i).pid; + END LOOP; + + -- Use the map to determine padding needed to slot in our columns... + -- ----------------------------------------------------------------- + IF g_map.COUNT > 0 THEN + g_len := LEAST(LENGTH(g_map.LAST) + 13, 14); + g_pad := LPAD('-', g_len, '-'); + END IF; + + END build_map; + + ---------------------------------------------------------------------------- + FUNCTION prepare_row( p_curr IN VARCHAR2, + p_next IN VARCHAR2 ) RETURN xplan_ot IS + + v_id PLS_INTEGER; + v_row VARCHAR2(4000); + v_hdr VARCHAR2(64) := '%|%Id%|%Operation%|%'; + + BEGIN + + -- Intercept the plan section to include new columns for the + -- the parent ID and operation order that we mapped earlier. + -- The plan output itself will be bound by dashed lines. + -- We need to add in additional dashes, column headings + -- and column values... + -- ------------------------------------------------------------- + + IF p_curr LIKE '---%' THEN + + IF p_next LIKE v_hdr THEN + g_hdrs := 1; + v_row := g_pad || p_curr; + ELSIF g_hdrs BETWEEN 1 AND 3 THEN + g_hdrs := g_hdrs + 1; + v_row := g_pad || p_curr; + ELSE + v_row := p_curr; + END IF; + + ELSIF p_curr LIKE v_hdr THEN + + v_row := REGEXP_REPLACE( + p_curr, '\|', + RPAD('|', GREATEST(g_len-12, 2)) || 'PID ' || + RPAD('|', GREATEST(g_len-13, 2)) || 'Order |', + 1, 2 + ); + + ELSIF REGEXP_LIKE(p_curr, '^\|[\* 0-9]+\|') THEN + + v_id := REGEXP_SUBSTR(p_curr, '[0-9]+'); + v_row := REGEXP_REPLACE( + p_curr, '\|', + '|' || LPAD(NVL(TO_CHAR(g_map(v_id).pid),' '), GREATEST(g_len-12, 4)) + || ' |' || LPAD(g_map(v_id).ord, GREATEST(g_len-13, 6)) || ' |', + 1, 2 + ); + ELSE + v_row := p_curr; + END IF; + + RETURN xplan_ot(v_row); + + END prepare_row; + + ---------------------------------------------------------------------------- + FUNCTION display( p_table_name IN VARCHAR2 DEFAULT 'PLAN_TABLE', + p_statement_id IN VARCHAR2 DEFAULT NULL, + p_format IN VARCHAR2 DEFAULT 'TYPICAL' ) + RETURN xplan_ntt PIPELINED IS + + v_plan_table VARCHAR2(128) := NVL(p_table_name, 'PLAN_TABLE'); + v_sql VARCHAR2(512); + v_binds ntt_map_binds := ntt_map_binds(); + + BEGIN + + reset_state(); + + -- Prepare the inputs for the parent ID and order map... + -- ----------------------------------------------------- + v_sql := 'SELECT id, parent_id + FROM ' || v_plan_table || ' + WHERE plan_id = (SELECT MAX(plan_id) + FROM ' || v_plan_table || ' + WHERE id = 0 %bind%) + ORDER BY id'; + + IF p_statement_id IS NULL THEN + v_sql := REPLACE(v_sql, '%bind%'); + ELSE + v_sql := REPLACE(v_sql, '%bind%', 'AND statement_id = :bv_statement_id'); + v_binds := ntt_map_binds(p_statement_id); + END IF; + + -- Build the map... + -- -------------------------------------------------- + build_map(v_sql, v_binds); + + -- Now we can call DBMS_XPLAN to output the plan... + -- ------------------------------------------------ + PIPE ROW (info); + + FOR r_plan IN ( SELECT plan_table_output AS p + , LEAD(plan_table_output) OVER (ORDER BY ROWNUM) AS np + FROM TABLE( + DBMS_XPLAN.DISPLAY( + v_plan_table, p_statement_id, p_format + )) + ORDER BY + ROWNUM) + LOOP + IF g_map.COUNT > 0 THEN + PIPE ROW (prepare_row(r_plan.p, r_plan.np)); + ELSE + PIPE ROW (xplan_ot(r_plan.p)); + END IF; + END LOOP; + + PIPE ROW (info); + + reset_state(); + RETURN; + + END display; + + ---------------------------------------------------------------------------- + FUNCTION display_cursor( p_sql_id IN VARCHAR2 DEFAULT NULL, + p_cursor_child_no IN INTEGER DEFAULT 0, + p_format IN VARCHAR2 DEFAULT 'TYPICAL' ) + RETURN xplan_ntt PIPELINED IS + + v_sql_id VARCHAR2(30); + v_child_no INTEGER; + v_sql VARCHAR2(256); + v_binds ntt_map_binds := ntt_map_binds(); + + BEGIN + + reset_state(); + + -- Set a SQL_ID if default parameters passed... + -- -------------------------------------------- + IF p_sql_id IS NULL THEN + EXECUTE IMMEDIATE 'SELECT prev_sql_id, prev_child_number + FROM v$session + WHERE sid = (SELECT m.sid FROM v$mystat m WHERE ROWNUM = 1) + AND username IS NOT NULL + AND prev_hash_value <> 0' + INTO v_sql_id, v_child_no; + ELSE + v_sql_id := p_sql_id; + v_child_no := NVL(p_cursor_child_no,0); + END IF; + + -- Prepare the inputs for the parent ID and order map... + -- ----------------------------------------------------- + v_sql := 'SELECT id, parent_id + FROM v$sql_plan + WHERE sql_id = :bv_sql_id + AND child_number = :bv_child_no'; + + v_binds := ntt_map_binds(v_sql_id, v_child_no); + + -- Build the plan map from the SQL... + -- ---------------------------------------- + build_map(v_sql, v_binds); + + -- Now we can call DBMS_XPLAN to output the plan... + -- ------------------------------------------------ + FOR r_plan IN ( SELECT plan_table_output AS p + , LEAD(plan_table_output) OVER (ORDER BY ROWNUM) AS np + FROM TABLE( + DBMS_XPLAN.DISPLAY_CURSOR( + v_sql_id, v_child_no, p_format + )) + ORDER BY + ROWNUM) + LOOP + IF g_map.COUNT > 0 THEN + PIPE ROW (prepare_row(r_plan.p, r_plan.np)); + ELSE + PIPE ROW (xplan_ot(r_plan.p)); + END IF; + END LOOP; + + PIPE ROW (info); + + reset_state(); + RETURN; + + END display_cursor; + +&_awr_start + ---------------------------------------------------------------------------- + FUNCTION display_awr( p_sql_id IN VARCHAR2, + p_plan_hash_value IN INTEGER DEFAULT NULL, + p_db_id IN INTEGER DEFAULT NULL, + p_format IN VARCHAR2 DEFAULT 'TYPICAL' ) + RETURN xplan_ntt PIPELINED IS + + TYPE rt_awr IS RECORD + ( sql_id VARCHAR2(30) + , plan_hash_value INTEGER + , dbid INTEGER ); + + TYPE aat_awr IS TABLE OF rt_awr + INDEX BY PLS_INTEGER; + + aa_awr aat_awr; + v_sql VARCHAR2(256); + v_binds ntt_map_binds := ntt_map_binds(); + + BEGIN + + reset_state(); + + -- Prepare the inputs for the parent ID and order map... + -- ----------------------------------------------------- + v_sql := 'SELECT id, parent_id + FROM dba_hist_sql_plan + WHERE sql_id = :bv_sql_id + AND plan_hash_value = :bv_plan_hash_value + AND dbid = :bv_dbid'; + + -- Determine all plans for the sql_id... + -- ------------------------------------- + EXECUTE IMMEDIATE 'SELECT DISTINCT + sql_id + , plan_hash_value + , dbid + FROM dba_hist_sql_plan + WHERE sql_id = :bv_sql_id + AND plan_hash_value = NVL(:bv_plan_hash_value, plan_hash_value) + AND dbid = NVL(:bv_db_id, (SELECT dbid FROM v$database)) + ORDER BY + plan_hash_value' + BULK COLLECT INTO aa_awr + USING p_sql_id, p_plan_hash_value, p_db_id; + + FOR i IN 1 .. aa_awr.COUNT LOOP + + -- Prepare the binds and build the order map... + -- -------------------------------------------- + v_binds := ntt_map_binds(aa_awr(i).sql_id, + aa_awr(i).plan_hash_value, + aa_awr(i).dbid); + + -- Build the plan map from the SQL... + -- ---------------------------------- + build_map(v_sql, v_binds); + + -- Now we can call DBMS_XPLAN to output the plan... + -- ------------------------------------------------ + FOR r_plan IN ( SELECT plan_table_output AS p + , LEAD(plan_table_output) OVER (ORDER BY ROWNUM) AS np + FROM TABLE( + DBMS_XPLAN.DISPLAY_AWR( + aa_awr(i).sql_id, aa_awr(i).plan_hash_value, + aa_awr(i).dbid, p_format + )) + ORDER BY + ROWNUM) + LOOP + IF g_map.COUNT > 0 THEN + PIPE ROW (prepare_row(r_plan.p, r_plan.np)); + ELSE + PIPE ROW (xplan_ot(r_plan.p)); + END IF; + END LOOP; + + END LOOP; + + PIPE ROW (info); + + reset_state(); + RETURN; + + END display_awr; +&_awr_end + +END xplan; +/ + +UNDEFINE _awr_start +UNDEFINE _awr_end + diff --git a/Alberto/xplan.sql b/Alberto/xplan.sql new file mode 100644 index 0000000..d99820b --- /dev/null +++ b/Alberto/xplan.sql @@ -0,0 +1,439 @@ +-------------------------------------------------------------------------------- +-- xplan - fetches and prints from the library cache the statements whose text matches +-- a given "like" expression, and their plan, statistics, plan statistics. +-- For every table accessed by the statement, it prints the table's columns, +-- indexes, constraints, and all CBO related statistics of the table and its indexes, +-- including partition-level ones. +-- +-- The goal is to provide all the informations needed to investigate the +-- statement in a concise and complete format. +-- +-- For a (commented) output example, see www.adellera.it/scripts_etcetera/xplan +-- +-- This script does NOT require creation of any database objects, a very handy +-- feature inspired by Tanel Poder's "Snapper" utility (http://www.tanelpoder.com/files/scripts/snapper.sql). +-- This script requires SELECT ANY DICTIONARY and SELECT ANY TABLE privileges. +-- +-- Usage: @xplan +-- Examples: @xplan "select%from dual" "" +-- @xplan "select%from dual" "order_by=elapsed_time desc" +-- @xplan "select%from dual" "order_by=elapsed_time desc,access_predicates=N" +-- @xplan "" "" +-- If is "last" => display last executed cursor by current session (10g+ only) +-- (same as dbms_xplan.display_cursor with sql_id and cursor_child_no set to null) +-- +-- Options: plan_stats : raw|per_exec|last (default last) +-- How to print cumulative gv$sql_plan_statistics (e.g. cr_buffer_gets, elapsed_time) +-- raw : prints the raw value +-- per_exec : prints the raw value / gv$sql.executions +-- last : use the last_ value (e.g. last_cr_buffer_gets, last_elapsed_time) +-- access_predicates: y|n (default y) +-- Whether to print or not the access and filter predicates +-- (useful only in 9i to work around bug 2525630 or one of its variants) +-- lines : (default 150) +-- Sets the output width +-- module: (default null) +-- Select only statements whose gv$sql.module matches the sql-like expression. +-- action: (default null) +-- Select only statements whose gv$sql.action matches the sql-like expression. +-- hash : (default null) +-- Select only statements whose gv$sql.hash_value matches the provided integer +-- sql_id: (default null) +-- Select only statements whose gv$sql.sql_id matches the provided string (10g+ only) +-- inst_id: (default : instance which the sqlplus session is connected to) +-- Select only statements from the instance whose id matches the provided integer (RAC only; +-- the default is ok for non-RAC systems) +-- parsed_by: | +-- Select only statements whose gv$sql.parsing_user_id is equal to either or +-- the user_id associated with the user whose username is +-- child_number: (default null) +-- Select only statements whose gv$sql.child_number matches the provided integer +-- dbms_xplan: y|n (default n) +-- If y, adds the output of dbms_xplan.display_cursor to the script output (10g+ only). +-- dbms_metadata: y|n|all (default n) +-- If y or all, adds the output of dbms_metadata.get_ddl to the script output, for each table and index. +-- If y no segment attribute (STORAGE, TABLESPACE, etc) is printed; if yes, all attributes are printed. . +-- plan_details: y|n (default n) [alias pd] +-- Print plan details (qb_name, object_alias, object_type, object#(and base table obj#), Projection, Remarks) +-- plan_env: y|n (default y) +-- Print optimizer environment parameters, and interesting other paramaters. +-- In 10g+ : print gv$sys_optimizer_environment/gv$system_parameter at the report top, then +-- values from gv$sql_optimizer_environment different from gv$sys_optimizer_environment for each stmt. +-- In 9i: print main optimizer environment params from gv$system_parameter, and $system_parameter, at the report top only. +-- ash_profile_mins: (default 15 in 10g+) +-- Print wait profile from gv$active_session_history (10g+ only). +-- Only a window minutes wide is considered. 0 means "do not print". +-- Warning: of course if this parameter is > 0, you are using ASH/AWR; make sure you are licensed to use it. +-- tabinfos: y|n|bottom (default y) [alias ti] +-- Print all available informations about tables accessed by the statement. +-- y : print infos after each statement +-- bottom : print infos at the bottom of the report +-- objinfos: y|n (default y) [alias oi] +-- Print all available informations about non-table objects that the statement depends on (v$object_dependency) +-- y : print infos after each statement +-- bottom : print infos at the bottom of the report +-- partinfos: y|n (default y) [alias pi] +-- If y, print partitions/subpartitions informations when printing tables accessed by the statement. +-- self: y|n (default y) +-- If y, print self (=not including children) statistics of row source operations +-- order_by: (default: null) +-- Order statements by the specified columns/expressions. Ties are ordered by sql_text and child_number. +-- Use the semicolon instead of the comma in expressions. +-- For example: "order_by=elapsed_time desc;buffer_gets" +-- "order_by=elapsed_time/decode(executions;0;null;executions) desc;buffer_gets" +-- numbers_with_comma: y|n (default y) +-- If y, display numbers with commas (e.g. 1,234,567.8) +-- spool_name : name of spool file (default: xplan.lst; default extension: .LST) +-- spool_files: single|by_hash|by_sql_id (default: see below) +-- Produce a single spool file or one for each different gv$sql.hash_value or gv$sql.sql_id. +-- If not specified, it defaults to "by_sql_id" if sql_id is set, to "by_hash" if hash is set, +-- otherwise to "single". +-- Author: Alberto Dell'Era +-- Copyright: (c) 2008-2013 Alberto Dell'Era http://www.adellera.it +-------------------------------------------------------------------------------- + +define XPLAN_VERSION="2.6.5 20-Oct-2013" +define XPLAN_COPYRIGHT="(C) Copyright 2008-2013 Alberto Dell''Era, www.adellera.it" + +set null "" trimspool on define on escape off pages 50000 tab off arraysize 100 +set echo off verify off feedback off termout off timing off + +spool xplan_setup.lst + +-- debug: +/* +set echo on verify on feedback on termout on +*/ + +define SQL_LIKE="&1" +define XPLAN_OPTIONS="&2" + +alter session set nls_territory='america'; +alter session set nls_language='american'; + +-- fetch prev_sql_id and prev_hash_value (such as dbms_xplan.display_cursor does) - 10g only +variable PREV_SQL_ID varchar2(15) +variable PREV_CHILD_NUMBER number +declare + invalid_userenv_par exception; + pragma exception_init (invalid_userenv_par, -2003); +begin /* xplan_exec_marker */ + -- following statement is from 10.2.0.3 dbms_xplan.display_cursor + execute immediate 'select /* xplan_exec_marker */ prev_sql_id, prev_child_number from v$session' + ||' where sid=userenv(''sid'') and username is not null and prev_hash_value <> 0' + into :PREV_SQL_ID, :PREV_CHILD_NUMBER; +exception + when invalid_userenv_par then -- happens in 9i only + :PREV_SQL_ID := null; + :PREV_CHILD_NUMBER := null; +end; +/ +print PREV_SQL_ID +print PREV_CHILD_NUMBER + +alter session set cursor_sharing=exact; + +set termout on +@@xplan_defines.sql +set termout off + +spool off + +spool &MAIN_BLOCK_SPOOL. + +set lines &LINE_SIZE. + +set termout on +-- following statement is just in case the next one fails (due to old versions of sqlplus) +set serveroutput on size 1000000 format wrapped +set serveroutput on &SERVEROUT_SIZE_CLAUSE format wrapped + +declare /* xplan_exec_marker */ &ERROR_BEFORE_MAIN_BLOCK. -- main block +@@xplan_utilities_vars.sql +@@xplan_mcf_vars.sql +@@xplan_scf_vars.sql +@@xplan_optim_env_vars.sql +@@xplan_tabinfos_vars.sql +@@xplan_objinfos_vars.sql +@@xplan_ash_vars.sql + + m_sql_like varchar2(300 char) := :SQL_LIKE; + m_action_like varchar2(300 char) := :ACTION_LIKE; + m_module_like varchar2(300 char) := :MODULE_LIKE; + m_hash_value number := :OPT_HASH_VALUE; + m_sql_id varchar2(30 char) := :OPT_SQL_ID; + m_parsing_user_id number := null; + m_child_number number := :OPT_CHILD_NUMBER; + + m_stmt long; + m_stmt_truncated boolean; + m_line varchar2(500 char); + + l_num_stmts_found int := 0; + l_stmt_hash_or_id_as_string varchar2(13 char); + l_stmt_hash_or_id_param varchar2(6 char); + l_stmt_length number; + + -- referenced sql hash values + type referenced_sql_hashid_t is table of varchar2(1) index by varchar2(13); + m_referenced_sql_hashids referenced_sql_hashid_t; + +@@xplan_utilities_body.sql +@@xplan_mcf_body.sql +@@xplan_scf_body.sql +@@xplan_optim_env_body.sql +@@xplan_tabinfos_body.sql +@@xplan_objinfos_body.sql +@@xplan_ash_body.sql +@@xplan_print_plan.sql + +begin + if :OPT_SPOOL_FILES = 'single' then + print ('xplan version &XPLAN_VERSION. &XPLAN_COPYRIGHT.'); + print ('db_name='||:DB_NAME||' instance_name='||:INSTANCE_NAME||' version='||:V_DB_VERSION||' (compatible = '||:V_DB_VERSION_COMPAT||')'); + end if; + + -- If is 'last' => display last executed cursor by current session + if lower(m_sql_like) = 'last' then + &COMM_IF_GT_9I. raise_application_error (-20090, 'cannot pass = "last" before 10g'); + m_sql_id := :PREV_SQL_ID; + m_child_number := :PREV_CHILD_NUMBER; + print ('displaying last executed cursor - sql_id='||m_sql_id||', child_number='||m_child_number); + end if; + + -- convert into m_parsing_user_id (convert name to user_id if necessary) + if :OPT_PARSED_BY is not null then + if is_integer (:OPT_PARSED_BY) then + m_parsing_user_id := to_number (:OPT_PARSED_BY); + else + m_parsing_user_id := get_cache_user_id (:OPT_PARSED_BY); + end if; + end if; + + if :OPT_SPOOL_FILES = 'single' then + -- print optimizer env sys-level parameters (10g+: gv$sys_optimizer_env; 9i:gv$parameter) + optim_env_init_print_sys_pars; + -- print system statistics + optim_env_print_sys_stats; + end if; + + &COMM_IF_NO_DBMS_METADATA. if :OPT_DBMS_METADATA = 'ALL' then + &COMM_IF_NO_DBMS_METADATA. dbms_metadata.set_transform_param( dbms_metadata.session_transform, 'SEGMENT_ATTRIBUTES', true); + &COMM_IF_NO_DBMS_METADATA. else + &COMM_IF_NO_DBMS_METADATA. dbms_metadata.set_transform_param( dbms_metadata.session_transform, 'SEGMENT_ATTRIBUTES', false); + &COMM_IF_NO_DBMS_METADATA. end if; + + for stmt in (select /*+ xplan_exec_marker */ + t.*, + decode (executions, 0, to_number(null), executions) execs + from sys.gv_$sql t + where inst_id = :OPT_INST_ID + and (parse_calls > 0 or executions > 0) +&COMM_IF_NO_SQL_LIKE. and lower(sql_text) like lower(m_sql_like) escape '\' + and (m_action_like is null or lower(action ) like lower(m_action_like) escape '\') + and (m_module_like is null or lower(module ) like lower(m_module_like) escape '\') +-- following commenting-out is to optimize access by hash value (if specified => fixed index is used) +&COMM_IF_NO_HASH. and hash_value = m_hash_value +&COMM_IF_LT_10G. and (m_sql_id is null or sql_id = m_sql_id) + and (m_parsing_user_id is null or parsing_user_id = m_parsing_user_id) + and (m_child_number is null or child_number = m_child_number) + and not lower (sql_text) like ('%dbms\_application\_info.%') escape '\' + and not lower (sql_text) like ('%xplan\_exec\_marker%') escape '\' + order by &MAIN_ORDER_BY. sql_text, child_number) + loop + l_num_stmts_found := l_num_stmts_found + 1; + + if :OPT_SPOOL_FILES = 'single' then + print (rpad ('=', least(&LINE_SIZE.,50), '=')); + + -- main statement attributes + m_line := ''; + &COMM_IF_LT_10G. if stmt.sql_id is not null then m_line := m_line || 'sql_id=' || stmt.sql_id || ' '; end if; + if stmt.hash_value is not null then m_line := m_line || 'hash=' || stmt.hash_value || ' '; end if; + if stmt.child_number is not null then m_line := m_line || 'child_number=' || stmt.child_number || ' '; end if; + if stmt.plan_hash_value is not null then m_line := m_line || 'plan_hash=' || stmt.plan_hash_value || ' '; end if; + if stmt.module is not null then m_line := m_line || 'module=' || stmt.module || ' '; end if; + if stmt.action is not null then m_line := m_line || 'action=' || stmt.action || ' '; end if; + print (m_line); + + m_line := ''; + m_line := m_line || 'first_load: ' || to_char ( to_date (stmt.first_load_time, 'yyyy-mm-dd/hh24:mi:ss'),'yyyy/mm/dd hh24:mi:ss'); + m_line := m_line || ' last_load: ' || to_char ( to_date (stmt. last_load_time, 'yyyy-mm-dd/hh24:mi:ss'),'yyyy/mm/dd hh24:mi:ss'); + &COMM_IF_LT_10GR2. m_line := m_line || ' last_active: '|| to_char (stmt.last_active_time,'yyyy/mm/dd hh24:mi:ss'); + print (m_line); + + m_line := ''; + m_line := m_line || 'parsed_by='|| get_cache_username (stmt.parsing_user_id); + m_line := m_line || ' inst_id='|| stmt.inst_id; + &COMM_IF_LT_10G. if stmt.sql_profile is not null then m_line := m_line ||' sql_profile=' || stmt.sql_profile; end if; + &COMM_IF_LT_10G. if stmt.program_id <> 0 then + &COMM_IF_LT_10G. m_line := m_line || ' program="' || get_cache_program_info (stmt.program_id) || '" line='||stmt.program_line#; + &COMM_IF_LT_10G. end if; + print (m_line); + + -- print main execution statistics (from gv$sql) + mcf_reset (p_default_execs => stmt.executions, p_stat_default_decimals => 0, p_stex_default_decimals => 1); + mcf_add_line_char ('gv$sql statname', 'total', '/exec'); + mcf_add_line ('executions' , stmt.executions , to_number(null)); + mcf_add_line ('rows_processed' , stmt.rows_processed); + mcf_add_line ('buffer_gets' , stmt.buffer_gets ); + mcf_add_line ('disk_reads' , stmt.disk_reads ); + &COMM_IF_LT_10G. mcf_add_line ('direct_writes' , stmt.direct_writes ); + mcf_add_line ('elapsed (usec)' , stmt.elapsed_time ); + mcf_add_line ('cpu_time (usec)', stmt.cpu_time ); + mcf_add_line ('sorts' , stmt.sorts ); + mcf_add_line ('fetches' , stmt.fetches ); + &COMM_IF_LT_10G. mcf_add_line ('end_of_fetch_c' , stmt.end_of_fetch_count); + mcf_add_line ('parse_calls' , stmt.parse_calls ); + mcf_add_line ('sharable_mem' , stmt.sharable_mem , to_number(null)); + mcf_add_line ('persistent_mem' , stmt.persistent_mem, to_number(null)); + mcf_add_line ('runtime_mem' , stmt.runtime_mem , to_number(null)); + mcf_add_line ('users_executing', stmt.users_executing); + + &COMM_IF_LT_10G. mcf_add_line ('application wait (usec)', stmt.application_wait_time); + &COMM_IF_LT_10G. mcf_add_line ('concurrency wait (usec)', stmt.concurrency_wait_time); + &COMM_IF_LT_10G. mcf_add_line ('cluster wait (usec)', stmt.cluster_wait_time ); + &COMM_IF_LT_10G. mcf_add_line ('user io wait (usec)', stmt.user_io_wait_time ); + &COMM_IF_LT_10G. mcf_add_line ('plsql exec wait (usec)', stmt.plsql_exec_time ); + &COMM_IF_LT_10G. mcf_add_line ('java exec wait (usec)', stmt.java_exec_time ); + + mcf_prepare_output (p_num_columns => 3); + loop + m_line := mcf_next_output_line; + exit when m_line is null; + print (m_line); + end loop; + + -- statement text + m_stmt := null; l_stmt_length := 0; + for x in (select /*+ xplan_exec_marker */ sql_text + from sys.gv_$sqltext_with_newlines + where inst_id = :OPT_INST_ID + and address = stmt.address + and hash_value = stmt.hash_value + order by piece) + loop + l_stmt_length := l_stmt_length + length ( x.sql_text ); + if l_stmt_length >= 32760-50 then + m_stmt_truncated := true; + else + m_stmt := m_stmt || x.sql_text; + end if; + end loop; + if m_stmt_truncated then + m_stmt := rtrim(m_stmt) || chr(13) || chr(10) || '** --TRUNCATED STATEMENT-- **' || chr(13) || chr(10); + end if; + print_stmt_lines ( m_stmt ); + + -- object dependency infos: print and remember + if :OPT_OBJINFOS = 'Y' then + print_obj_dep_and_store (p_inst_id => :OPT_INST_ID, + p_address => stmt.address, + p_hash_value => stmt.hash_value); + end if; + + -- bind sensitive, bind aware (11g Adaptive Cursor Sharing) + &COMM_IF_LT_11G.m_line := ''; + &COMM_IF_LT_11G. if stmt.is_bind_sensitive = 'Y' then m_line := m_line || 'bind_sensitive '; end if; + &COMM_IF_LT_11G. if stmt.is_bind_aware = 'Y' then m_line := m_line || 'bind_aware ' ; end if; + &COMM_IF_LT_11G. if stmt.is_shareable = 'N' then m_line := m_line || 'not_shareable ' ; end if; + &COMM_IF_LT_11G. print(m_line); + &COMM_IF_LT_11G. if stmt.is_bind_aware = 'Y' then + &COMM_IF_LT_11G. for x in (select rtrim(predicate,chr(0)) as predicate, rtrim(low,chr(0)) as low, rtrim(high,chr(0)) as high + &COMM_IF_LT_11G. from sys.gv_$sql_cs_selectivity + &COMM_IF_LT_11G. where inst_id = :OPT_INST_ID + &COMM_IF_LT_11G. and address = stmt.address + &COMM_IF_LT_11G. and hash_value = stmt.hash_value + &COMM_IF_LT_11G. and child_number = stmt.child_number + &COMM_IF_LT_11G. order by rtrim(predicate,chr(0)) ) + &COMM_IF_LT_11G. loop + &COMM_IF_LT_11G. print(x.predicate||' '||x.low||' <-> '||x.high); + &COMM_IF_LT_11G. end loop; + &COMM_IF_LT_11G. end if; + + -- statement plan + print_plan (p_inst_id => :OPT_INST_ID, + p_address => stmt.address , p_hash_value => stmt.hash_value, + p_child_number => stmt.child_number, p_executions => stmt.executions, + p_first_load_time => to_date (stmt.first_load_time, 'yyyy-mm-dd/hh24:mi:ss'), + p_last_load_time => to_date (stmt.last_load_time, 'yyyy-mm-dd/hh24:mi:ss') + &COMM_IF_LT_10GR2., p_last_active_time => stmt.last_active_time + &COMM_IF_LT_11G. , p_sql_plan_baseline => stmt.sql_plan_baseline + ); + else -- if :OPT_SPOOL_FILES = ... ("by_hash" and "by_sql_id" branches) + &COMM_IF_LT_10G. if :OPT_SPOOL_FILES = 'by_hash' then + l_stmt_hash_or_id_as_string := lpad (trim(stmt.hash_value),10,'0'); + l_stmt_hash_or_id_param := 'hash'; + &COMM_IF_LT_10G. else + &COMM_IF_LT_10G. l_stmt_hash_or_id_as_string := stmt.sql_id; + &COMM_IF_LT_10G. l_stmt_hash_or_id_param := 'sql_id'; + &COMM_IF_LT_10G. end if; + if stmt.hash_value > 0 and not m_referenced_sql_hashids.exists(l_stmt_hash_or_id_as_string) then + m_referenced_sql_hashids (l_stmt_hash_or_id_as_string) := 'X'; + declare + l_spool_name_last_dot number := instr (:OPT_SPOOL_NAME, '.', -1); + l_spool_name_wo_ext varchar2(100 char) := substr (:OPT_SPOOL_NAME, 1, l_spool_name_last_dot-1); + l_spool_name_ext varchar2(100 char) := substr (:OPT_SPOOL_NAME, l_spool_name_last_dot+1); + l_curr_spool_name varchar2(120 char); + begin + l_curr_spool_name := l_spool_name_wo_ext||'_'||l_stmt_hash_or_id_as_string + ||'_i'||:OPT_INST_ID||'.'||l_spool_name_ext; + -- note: last option value overrides all the previous ones + dbms_output.put_line ('@xplan "'||m_sql_like||'" "'||:XPLAN_OPTIONS|| + ','||l_stmt_hash_or_id_param||'='||l_stmt_hash_or_id_as_string||',spool_files=single,spool_name='||l_curr_spool_name||'"'); + end; + end if; + end if; -- if :OPT_SPOOL_FILES = 'single' + end loop; -- gv$sql + + -- print tabinfos at the bottom, if requested + if :OPT_SPOOL_FILES = 'single' then + if :OPT_TABINFOS = 'BOTTOM' then + print ('================== ALL TABINFOS =================='); + if m_all_referenced_object_ids.count = 0 then + print ('no tabinfos found.'); + else + declare + l_curr_id varchar2(30); + begin + l_curr_id := m_all_referenced_object_ids.first; + loop + exit when l_curr_id is null; + -- print tabinfos (no cache) + print_table_infos (l_curr_id); + l_curr_id := m_all_referenced_object_ids.next (l_curr_id); + end loop; + end; + end if; + end if; + end if; + + -- print non-table object infos + if :OPT_SPOOL_FILES = 'single' and :OPT_OBJINFOS = 'Y' then + print_objinfos; + end if; + + if l_num_stmts_found = 0 then + if :OPT_SPOOL_FILES = 'single' then + print ('no statement found.'); + elsif :OPT_SPOOL_FILES in ('by_hash','by_sql_id') then + print ('-- no statement found.'); + end if; + end if; + + if :OPT_SPOOL_FILES = 'single' then + print ('OPTIONS: '||:CURRENT_XPLAN_OPTIONS); + print ('SQL_LIKE="'||m_sql_like||'"'); + end if; + + if :OPT_ASH_PROFILE_MINS != 0 then + print ('-- Warning: since ash_profile_mins('||:OPT_ASH_PROFILE_MINS||') != 0, you are using ASH/AWR; make sure you are licensed to use it.'); + end if; +end; +/ + +set serveroutput off + +spool off + +@ &BOTTOM_SCRIPT. diff --git a/Alberto/xplan_ash_body.sql b/Alberto/xplan_ash_body.sql new file mode 100644 index 0000000..e50d9fc --- /dev/null +++ b/Alberto/xplan_ash_body.sql @@ -0,0 +1,195 @@ +-------------------------------------------------------------------------------- +-- Author: Alberto Dell'Era +-- Copyright: (c) 2008-2013 Alberto Dell'Era http://www.adellera.it +-------------------------------------------------------------------------------- + +&COMM_IF_LT_10G. procedure ash_info_initialize( p_inst_id int ) +&COMM_IF_LT_10G. is +&COMM_IF_LT_10G. l_code varchar2(100); +&COMM_IF_LT_10G. l_ash_info ash_info_t; +&COMM_IF_LT_10G. begin +&COMM_IF_LT_10G. if m_ash_over_thr_initialized then +&COMM_IF_LT_10G. return; +&COMM_IF_LT_10G. end if; +&COMM_IF_LT_10G. m_ash_over_thr_initialized := true; + +&COMM_IF_LT_10G. for r in (select /*+ xplan_exec_marker */ sql_id, sql_child_number, +&COMM_IF_LT_10G. min(sample_time) as sample_time_min, max(sample_time) as sample_time_max, count(*) as cnt +&COMM_IF_LT_10G. from sys.gv_$active_session_history +&COMM_IF_LT_10G. where inst_id = p_inst_id +&COMM_IF_LT_10G. and sql_id is not null +&COMM_IF_LT_10G. and sql_child_number >= 0 +&COMM_IF_LT_10G. -- optimizations for targeted searches +&COMM_IF_LT_10G. and (m_action_like is null or lower(action ) like lower(m_action_like) escape '\') +&COMM_IF_LT_10G. and (m_module_like is null or lower(module ) like lower(m_module_like) escape '\') +&COMM_IF_LT_10G. and (m_sql_id is null or sql_id = m_sql_id) +&COMM_IF_LT_10G. and (m_parsing_user_id is null or user_id = m_parsing_user_id) +&COMM_IF_LT_10G. and (m_child_number is null or sql_child_number = m_child_number) +&COMM_IF_LT_10G. -- end of optimizations for targeted searches +&COMM_IF_LT_10G. group by sql_id, sql_child_number +&COMM_IF_LT_10G. having count(*) >= m_ash_cnt_thr +&COMM_IF_LT_10G. order by sql_id, sql_child_number) +&COMM_IF_LT_10G. loop +&COMM_IF_LT_10G. l_code := r.sql_id||'.'||r.sql_child_number; +&COMM_IF_LT_10G. l_ash_info.sample_time_min := r.sample_time_min; +&COMM_IF_LT_10G. l_ash_info.sample_time_max := r.sample_time_max; +&COMM_IF_LT_10G. l_ash_info.cnt := r.cnt; +&COMM_IF_LT_10G. m_ash_over_thr(l_code) := l_ash_info; +&COMM_IF_LT_10G. end loop; + +&COMM_IF_LT_10G. -- -- debug print +&COMM_IF_LT_10G. -- l_code := m_ash_over_thr.first; +&COMM_IF_LT_10G. -- while l_code is not null loop +&COMM_IF_LT_10G. -- print( ':: '||l_code||' '||m_ash_over_thr(l_code).cnt||' '||m_ash_over_thr(l_code).sample_time_min||' - '||m_ash_over_thr(l_code).sample_time_max ); +&COMM_IF_LT_10G. -- l_code := m_ash_over_thr.next(l_code); +&COMM_IF_LT_10G. -- end loop; +&COMM_IF_LT_10G. end ash_info_initialize; + +procedure ash_print_stmt_profile ( + p_inst_id sys.gv_$sql.inst_id%type, + p_sql_id varchar2, + p_child_number sys.gv_$sql.child_number%type, + p_first_load_time date, + p_last_load_time date, + p_last_active_time date +) +is + &COMM_IF_LT_10G. l_sample_time_min timestamp(3); + &COMM_IF_LT_10G. l_sample_time_max timestamp(3); + &COMM_IF_LT_10G. l_prof scf_state_t; + &COMM_IF_LT_11G. l_prof2 scf_state_t; + &COMM_IF_LT_10G. l_code varchar2(100); + &COMM_IF_LT_10G. l_ash_info ash_info_t; + &COMM_IF_LT_10G. l_prev_event sys.gv_$active_session_history.event%type; + &COMM_IF_LT_11G. l_prev_line int; +begin + if :OPT_ASH_PROFILE_MINS = 0 then + return; + end if; + + &COMM_IF_GT_9I. print ('gv$active_session_history does not exist before 10g.'); + + &COMM_IF_LT_10G. l_sample_time_min := greatest (p_first_load_time, nvl(p_last_active_time,systimestamp) - (:OPT_ASH_PROFILE_MINS / 1440)); + &COMM_IF_LT_10G. l_sample_time_max := nvl(p_last_active_time,systimestamp); + &COMM_IF_LT_10G. print( l_sample_time_min||' '||l_sample_time_max); + + &COMM_IF_LT_10G. ash_info_initialize(p_inst_id); + + -- return if no enough samples exist in child cursor activity interval + &COMM_IF_LT_10G. l_code := p_sql_id||'.'||p_child_number; + &COMM_IF_LT_10G. if m_ash_over_thr.exists( l_code ) then + &COMM_IF_LT_10G. l_ash_info := m_ash_over_thr ( l_code ); + &COMM_IF_LT_10G. if not (l_sample_time_min between l_ash_info.sample_time_min and l_ash_info.sample_time_max or + &COMM_IF_LT_10G. l_sample_time_max between l_ash_info.sample_time_min and l_ash_info.sample_time_max) then + &COMM_IF_LT_10G. print ('no sample found in v$ash for activity interval'); + &COMM_IF_LT_10G. return; + &COMM_IF_LT_10G. end if; + &COMM_IF_LT_10G. else + &COMM_IF_LT_10G. print ('sample count zero or too low ( < '||m_ash_cnt_thr||' ) in v$ash'); + &COMM_IF_LT_10G. return; + &COMM_IF_LT_10G. end if; + + -- display ASH profile (event,object) + &COMM_IF_LT_10G. l_prev_event := 'x'; + &COMM_IF_LT_10G. for p in (with ewb as ( + &COMM_IF_LT_10G. select name + &COMM_IF_LT_10G. from sys.v_$event_name e + &COMM_IF_LT_10G. where e.wait_class in ('Application', 'Cluster', 'Concurrency', 'User I/O') + &COMM_IF_LT_10G. ), bas as ( + &COMM_IF_LT_10G. select /*+ ordered use_hash(ewb o) */ /* xplan_exec_marker */ + &COMM_IF_LT_10G. -- keep aligned with other profiles using event, current_obj# + &COMM_IF_LT_10G. decode(a.session_state, 'WAITING', a.event, 'ON CPU', 'cpu/runqueue', '**error**') as event, + &COMM_IF_LT_10G. decode(a.session_state, 'WAITING', decode(ewb.name, null, null, nvl(o.object_name, '#'||a.current_obj#) ), null) as object_name + &COMM_IF_LT_10G. from sys.gv_$active_session_history a, ewb, sys.dba_objects o + &COMM_IF_LT_10G. where a.inst_id = p_inst_id + &COMM_IF_LT_10G. and a.sql_id = p_sql_id + &COMM_IF_LT_10G. and a.sql_child_number = p_child_number + &COMM_IF_LT_10G. and a.sample_time between l_sample_time_min and l_sample_time_max + &COMM_IF_LT_10G. and a.event = ewb.name(+) + &COMM_IF_LT_10G. -- it costs too much: and (o.object_type not like 'JAVA%' and o.object_type not in('SYNONYM', 'TYPE', 'PROCEDURE', 'FUNCTION', 'PACKAGE', 'PACKAGE BODY')) + &COMM_IF_LT_10G. and o.object_id(+) is not null + &COMM_IF_LT_10G. and a.current_obj# = o.object_id(+) -- checked this mapping, even for partitioned objects + &COMM_IF_LT_10G. ), gby as ( + &COMM_IF_LT_10G. select event, + &COMM_IF_LT_10G. object_name, + &COMM_IF_LT_10G. count(*) as cnt + &COMM_IF_LT_10G. from bas + &COMM_IF_LT_10G. group by event, object_name + &COMM_IF_LT_10G. ) + &COMM_IF_LT_10G. select event, object_name, + &COMM_IF_LT_10G. sum(cnt) over(partition by event) as cnt_event, + &COMM_IF_LT_10G. 100 * sum(cnt) over(partition by event) / sum(cnt) over() as perc_event, + &COMM_IF_LT_10G. cnt, + &COMM_IF_LT_10G. 100 * cnt / sum(cnt) over(partition by event) as perc_in_event + &COMM_IF_LT_10G. from gby + &COMM_IF_LT_10G. order by cnt_event desc, event, cnt desc + &COMM_IF_LT_10G. ) + &COMM_IF_LT_10G. loop + &COMM_IF_LT_10G. scf_add_elem (l_prof, 'ash event', case when p.event != l_prev_event then p.event end); + &COMM_IF_LT_10G. scf_add_elem (l_prof, 'cnt' , case when p.event != l_prev_event then p.cnt_event end); + &COMM_IF_LT_10G. scf_add_elem (l_prof, '%' , case when p.event != l_prev_event then p.perc_event end); + &COMM_IF_LT_10G. scf_add_elem (l_prof, 'object' , p.object_name ); + &COMM_IF_LT_10G. scf_add_elem (l_prof, 'cnt2' , p.cnt); + &COMM_IF_LT_10G. scf_add_elem (l_prof, '%/event' , p.perc_in_event); + &COMM_IF_LT_10G. l_prev_event := p.event; + &COMM_IF_LT_10G. end loop; + + -- display ASH profile (plan line, event, object) + &COMM_IF_LT_11G. l_prev_event := 'x'; + &COMM_IF_LT_11G. l_prev_line := -11; + &COMM_IF_LT_11G. for p in (with ewb as ( + &COMM_IF_LT_11G. select name + &COMM_IF_LT_11G. from sys.v_$event_name e + &COMM_IF_LT_11G. where e.wait_class in ('Application', 'Cluster', 'Concurrency', 'User I/O') + &COMM_IF_LT_11G. ), bas as ( + &COMM_IF_LT_11G. select /*+ ordered use_hash(ewb o) */ /* xplan_exec_marker */ + &COMM_IF_LT_11G. -- keep aligned with other profiles using event, current_obj# + &COMM_IF_LT_11G. decode(a.session_state, 'WAITING', a.event, 'ON CPU', 'cpu/runqueue', '**error**') as event, + &COMM_IF_LT_11G. decode(a.session_state, 'WAITING', decode(ewb.name, null, null, nvl(o.object_name, '#'||a.current_obj#) ), null) as object_name, + &COMM_IF_LT_11G. sql_plan_line_id + &COMM_IF_LT_11G. from sys.gv_$active_session_history a, ewb, sys.dba_objects o + &COMM_IF_LT_11G. where a.inst_id = p_inst_id + &COMM_IF_LT_11G. and a.sql_id = p_sql_id + &COMM_IF_LT_11G. and a.sql_child_number = p_child_number + &COMM_IF_LT_11G. and a.sample_time between l_sample_time_min and l_sample_time_max + &COMM_IF_LT_11G and a.event = ewb.name(+) + &COMM_IF_LT_11G -- it costs too much: and (o.object_type not like 'JAVA%' and o.object_type not in('SYNONYM', 'TYPE', 'PROCEDURE', 'FUNCTION', 'PACKAGE', 'PACKAGE BODY')) + &COMM_IF_LT_11G and o.object_id(+) is not null + &COMM_IF_LT_11G. and a.current_obj# = o.object_id(+) -- checked this mapping, even for partitioned objects + &COMM_IF_LT_11G. ), gby as ( + &COMM_IF_LT_11G. select sql_plan_line_id, + &COMM_IF_LT_11G. event, + &COMM_IF_LT_11G. object_name, + &COMM_IF_LT_11G. count(*) as cnt + &COMM_IF_LT_11G. from bas + &COMM_IF_LT_11G. group by sql_plan_line_id, event, object_name + &COMM_IF_LT_11G. ) + &COMM_IF_LT_11G. select sql_plan_line_id, event, object_name, + &COMM_IF_LT_11G. sum(cnt) over(partition by sql_plan_line_id) as cnt_line, + &COMM_IF_LT_11G. 100 * sum(cnt) over(partition by sql_plan_line_id) / sum(cnt) over() as perc_line, + &COMM_IF_LT_11G. sum(cnt) over(partition by sql_plan_line_id, event) as cnt_event, + &COMM_IF_LT_11G. 100 * sum(cnt) over(partition by sql_plan_line_id, event) / sum(cnt) over(partition by sql_plan_line_id) as perc_event_in_line, + &COMM_IF_LT_11G. cnt, + &COMM_IF_LT_11G. 100 * cnt / sum(cnt) over(partition by sql_plan_line_id, event) as perc_in_event + &COMM_IF_LT_11G. from gby + &COMM_IF_LT_11G. order by cnt_line desc, sql_plan_line_id, cnt_event desc, event, cnt desc + &COMM_IF_LT_11G. ) + &COMM_IF_LT_11G. loop + &COMM_IF_LT_11G. --print(p.sql_plan_line_id||' '||p.cnt_line||' '||lpad(p.event,22)||' '||p.cnt_event||' '||lpad(nvl(get_cache_obj_name(p.current_obj#),' '),5)||' '||p.cnt); + &COMM_IF_LT_11G. scf_add_elem (l_prof2, 'ash plan line', case when p.sql_plan_line_id != l_prev_line then p.sql_plan_line_id end); + &COMM_IF_LT_11G. scf_add_elem (l_prof2, 'cnt' , case when p.sql_plan_line_id != l_prev_line then p.cnt_line end); + &COMM_IF_LT_11G. scf_add_elem (l_prof2, '%' , case when p.sql_plan_line_id != l_prev_line then p.perc_line end); + &COMM_IF_LT_11G. scf_add_elem (l_prof2, 'event' , case when p.sql_plan_line_id != l_prev_line or p.event != l_prev_event then p.event end); + &COMM_IF_LT_11G. scf_add_elem (l_prof2, 'cnt2' , case when p.sql_plan_line_id != l_prev_line or p.event != l_prev_event then p.cnt_event end); + &COMM_IF_LT_11G. scf_add_elem (l_prof2, '%/line' , case when p.sql_plan_line_id != l_prev_line or p.event != l_prev_event then p.perc_event_in_line end); + &COMM_IF_LT_11G. scf_add_elem (l_prof2, 'object' , p.object_name ); + &COMM_IF_LT_11G. scf_add_elem (l_prof2, 'cnt3' , p.cnt); + &COMM_IF_LT_11G. scf_add_elem (l_prof2, '%/event' , p.perc_in_event); + &COMM_IF_LT_11G. l_prev_event := p.event; + &COMM_IF_LT_11G. l_prev_line := p.sql_plan_line_id; + &COMM_IF_LT_11G. end loop; + + &COMM_IF_LT_10G. scf_print_output (l_prof , 'no profile info found in v$ash.', 'no profile info found in v$ash.'); + &COMM_IF_LT_11G. scf_print_output (l_prof2, 'no profile info found in v$ash.', 'no profile info found in v$ash.'); +end ash_print_stmt_profile; + \ No newline at end of file diff --git a/Alberto/xplan_ash_vars.sql b/Alberto/xplan_ash_vars.sql new file mode 100644 index 0000000..4e30bbf --- /dev/null +++ b/Alberto/xplan_ash_vars.sql @@ -0,0 +1,16 @@ +-------------------------------------------------------------------------------- +-- Author: Alberto Dell'Era +-- Copyright: (c) 2013 Alberto Dell'Era http://www.adellera.it +-------------------------------------------------------------------------------- + +-- sqlid+child_number whose counts are over threshold (m_ash_thr) +&COMM_IF_LT_10G. type ash_info_t is record ( +&COMM_IF_LT_10G. sample_time_min timestamp(3), +&COMM_IF_LT_10G. sample_time_max timestamp(3), +&COMM_IF_LT_10G. cnt int -- count(*) +&COMM_IF_LT_10G. ); + +&COMM_IF_LT_10G. type ash_over_thr_t is table of ash_info_t index by varchar2(100 char); +&COMM_IF_LT_10G. m_ash_over_thr ash_over_thr_t; +&COMM_IF_LT_10G. m_ash_cnt_thr number := 10; +&COMM_IF_LT_10G. m_ash_over_thr_initialized boolean := false; diff --git a/Alberto/xplan_awr.sql b/Alberto/xplan_awr.sql new file mode 100644 index 0000000..57a4b8b --- /dev/null +++ b/Alberto/xplan_awr.sql @@ -0,0 +1,98 @@ +-------------------------------------------------------------------------------- +-- xplan_awr - run automatically xplan.sql on all SQL statements recorded in the AWR view +-- dba_hist_sqlstat whose run-time execution statistic values exceed configurable thresholds, +-- and that are still present in gv$sql. +-- See xplan.sql header for required privileges. +-- Author: Alberto Dell'Era +-- Copyright: (c) 2008, 2009 Alberto Dell'Era http://www.adellera.it +-------------------------------------------------------------------------------- + +set null "" trimspool on define on escape off lines 250 pages 50000 tab off arraysize 100 +set echo off verify off feedback off termout on timing off head off + +spool xplan_awr.lst + +with params as ( + select 1 as num_days, + 08 as hour_start, + 12 as hour_end, + 01 as inst_id_min, + 01 as inst_id_max, + 3.0 as thresh_perc_elapsed, + 10.0 as thresh_perc_cpu, + 10.0 as thresh_perc_buffer_gets, + 7 as thresh_rank_elapsed, + 5 as thresh_rank_cpu, + 5 as thresh_rank_buffer_gets + from dual +), base as ( + select s.instance_number as inst_id, s.snap_id, s.sql_id, + s.elapsed_time_delta, + s.cpu_time_delta, + s.buffer_gets_delta, + s.disk_reads_delta, + s.executions_delta, + sn.end_interval_time + from dba_hist_sqlstat s, dba_hist_snapshot sn + where s.dbid = (select dbid from v$database) + and s.dbid = sn.dbid + and s.instance_number = sn.instance_number + and s.snap_id = sn.snap_id + and sn.end_interval_time >= trunc(systimestamp) - (select num_days from params) + and extract (hour from sn.end_interval_time) + between (select hour_start from params) + and (select hour_end from params) - 1 + and s.instance_number between (select inst_id_min from params) and (select inst_id_max from params) + and s.executions_delta > 0 + and s.parsing_schema_name not in ('SYS', 'SYSTEM') +), classif as ( + select base.*, + 100 * ratio_to_report (elapsed_time_delta) over(partition by inst_id, snap_id) as elapsed_time_delta_perc, + 100 * ratio_to_report (cpu_time_delta ) over(partition by inst_id, snap_id) as cpu_time_delta_perc, + 100 * ratio_to_report (buffer_gets_delta ) over(partition by inst_id, snap_id) as buffer_gets_delta_perc, + 100 * ratio_to_report (disk_reads_delta ) over(partition by inst_id, snap_id) as disk_reads_delta_perc, + 100 * ratio_to_report (executions_delta ) over(partition by inst_id, snap_id) as executions_delta_perc, + rank() over (partition by inst_id, snap_id order by elapsed_time_delta desc) as elapsed_time_delta_rank, + rank() over (partition by inst_id, snap_id order by cpu_time_delta desc) as cpu_time_delta_rank, + rank() over (partition by inst_id, snap_id order by buffer_gets_delta desc) as buffer_gets_delta_rank, + rank() over (partition by inst_id, snap_id order by disk_reads_delta desc) as disk_reads_delta_rank, + rank() over (partition by inst_id, snap_id order by executions_delta desc) as executions_delta_rank + from base +), selection as ( + select classif.* + from classif + where elapsed_time_delta_perc >= (select thresh_perc_elapsed from params) + or cpu_time_delta_perc >= (select thresh_perc_cpu from params) + or buffer_gets_delta_perc >= (select thresh_perc_buffer_gets from params) + or elapsed_time_delta_rank <= (select thresh_rank_elapsed from params) + or cpu_time_delta_rank <= (select thresh_rank_cpu from params) + or buffer_gets_delta_rank <= (select thresh_rank_buffer_gets from params) +), still_there as ( + select selection.* + from selection + where (sql_id, inst_id) in (select sql_id, inst_id from gv$sql where executions > 0 and parse_calls > 0) +), pre_display as ( + select still_there.*, rank() over (partition by sql_id, inst_id order by elapsed_time_delta_perc) as display_row + from still_there +), display as ( + select '-- ' || sql_id + || ' sn: ' || to_char (end_interval_time, 'yyyymmdd_hh24miss') + || ' time:' || to_char(elapsed_time_delta, '999999999990') || to_char (round (elapsed_time_delta_perc, 0),'90.0') || '% ' || to_char (round (elapsed_time_delta_rank, 0),'90') || '#' + || ' cpu:' || to_char(cpu_time_delta , '999999999990') || to_char (round (cpu_time_delta_perc , 0),'90.0') || '% ' || to_char (round (cpu_time_delta_rank , 0),'90') || '#' + || ' gets:' || to_char(buffer_gets_delta , '999999990' ) || to_char (round (buffer_gets_delta_perc , 0),'90.0') || '% ' || to_char (round (buffer_gets_delta_rank , 0),'90') || '#' + || ' disk:' || to_char(disk_reads_delta , '999999990' ) || to_char (round (disk_reads_delta_perc , 0),'90.0') || '% ' || to_char (round (disk_reads_delta_rank , 0),'90') || '#' + as header + , sql_id, inst_id, display_row + from pre_display + union all + select '@xplan "" "sql_id=' || sql_id || ',inst_id='||inst_id||',tabinfos=bottom"' + , sql_id, inst_id, 1e6 as display_row + from pre_display + where display_row = 1 +) +select header from display +order by sql_id, inst_id, display_row; + +spool off + +@xplan_awr.lst diff --git a/Alberto/xplan_defines.sql b/Alberto/xplan_defines.sql new file mode 100644 index 0000000..d72af3f --- /dev/null +++ b/Alberto/xplan_defines.sql @@ -0,0 +1,397 @@ +-------------------------------------------------------------------------------- +-- Author: Alberto Dell'Era +-- Copyright: (c) 2008-2013 Alberto Dell'Era http://www.adellera.it +-------------------------------------------------------------------------------- + +variable ERROR_BEFORE_MAIN_BLOCK varchar2(50 char) + +variable CURRENT_ERROR varchar2(50 char) +exec /* xplan_exec_marker */ :CURRENT_ERROR := ''; + +-- set version defines, get parameters +variable V_DB_MAJOR_VERSION number +variable V_DB_MINOR_VERSION number +variable V_DB_VERSION varchar2(20 char) +variable V_DB_VERSION_COMPAT varchar2(20 char) +variable DB_NAME varchar2(30 char) +variable INSTANCE_NAME varchar2(30 char) +declare /* xplan_exec_marker */ + l_dummy_bi1 binary_integer; + l_dummy_bi2 binary_integer; + l_version_dot_1 binary_integer; + l_version_dot_2 binary_integer; +begin + sys.dbms_utility.db_version (:V_DB_VERSION, :V_DB_VERSION_COMPAT); + l_version_dot_1 := instr (:V_DB_VERSION, '.'); + l_version_dot_2 := instr (:V_DB_VERSION, '.', 1, 2); + :V_DB_MAJOR_VERSION := to_number (substr (:V_DB_VERSION, 1, l_version_dot_1 - 1)); + :V_DB_MINOR_VERSION := to_number (substr (:V_DB_VERSION, l_version_dot_1+1, l_version_dot_2 - l_version_dot_1 - 1)); + l_dummy_bi1 := sys.dbms_utility.get_parameter_value ('db_name' , l_dummy_bi2, :DB_NAME ); + l_dummy_bi1 := sys.dbms_utility.get_parameter_value ('instance_name', l_dummy_bi2, :INSTANCE_NAME); +end; +/ + +-- set version-dependent commenting-out defines +define COMM_IF_LT_11G="error" +define COMM_IF_LT_10GR2="error" +define COMM_IF_LT_10G="error" +define COMM_IF_GT_9I="error" +col COMM_IF_LT_11G noprint new_value COMM_IF_LT_11G +col COMM_IF_LT_10GR2 noprint new_value COMM_IF_LT_10GR2 +col COMM_IF_LT_10G noprint new_value COMM_IF_LT_10G +col COMM_IF_GT_9I noprint new_value COMM_IF_GT_9I +col COMM_IF_GT_10G noprint new_value COMM_IF_GT_10G +select /*+ xplan_exec_marker */ + case when :v_db_major_version < 11 then '--' else '' end COMM_IF_LT_11G, + case when :v_db_major_version < 10 or (:v_db_major_version = 10 and :v_db_minor_version < 2) then '--' else '' end COMM_IF_LT_10GR2, + case when :v_db_major_version < 10 then '--' else '' end COMM_IF_LT_10G, + case when :v_db_major_version > 9 then '--' else '' end COMM_IF_GT_9I, + case when :v_db_major_version >= 11 or (:v_db_major_version = 10 and :v_db_minor_version >= 2) then '--' else '' end COMM_IF_GT_10G + from dual; + +-- set servroutput size clause to max possible (+infinite in10g+) +define SERVEROUT_SIZE_CLAUSE="error" +col SERVEROUT_SIZE_CLAUSE noprint new_value SERVEROUT_SIZE_CLAUSE +select /*+ xplan_exec_marker */ + case when :v_db_major_version < 10 then 'size 1000000' else 'size unlimited' end SERVEROUT_SIZE_CLAUSE + from dual; + +-- set SQL_LIKE bind variable (10g handles single-quotes much better ) +-- also, set :XPLAN_OPTIONS +variable XPLAN_OPTIONS varchar2(200 char) +exec /* xplan_exec_marker */ if :CURRENT_ERROR is null then :CURRENT_ERROR := 'sql_like invalid'; end if; +variable SQL_LIKE varchar2(4000) +begin /*+ xplan_exec_marker */ + :SQL_LIKE := + &COMM_IF_GT_9I. '&SQL_LIKE.' ; + &COMM_IF_LT_10G. q'|&SQL_LIKE.|'; + :CURRENT_ERROR := ''; + :XPLAN_OPTIONS := '&XPLAN_OPTIONS.'; +end; +/ + +-- set options defines +variable OPT_INST_ID number +variable OPT_PLAN_STATS varchar2(10 char) +variable OPT_ACCESS_PREDICATES varchar2(1) +variable OPT_LINES number +variable OPT_ASH_PROFILE_MINS number +variable OPT_MODULE varchar2(100 char) +variable OPT_ACTION varchar2(100 char) +variable OPT_HASH_VALUE varchar2(30 char) +variable OPT_SQL_ID varchar2(30 char) +variable OPT_PARSED_BY varchar2(30 char) +variable OPT_CHILD_NUMBER number +variable OPT_DBMS_XPLAN varchar2(1) +variable OPT_DBMS_METADATA varchar2(3) +variable OPT_PLAN_DETAILS varchar2(1) +variable OPT_PLAN_ENV varchar2(1) +variable OPT_TABINFOS varchar2(6 char) +variable OPT_OBJINFOS varchar2(1) +variable OPT_PARTINFOS varchar2(1) +variable OPT_SELF varchar2(1) +variable OPT_ORDER_BY varchar2(100 char) +variable OPT_SPOOL_NAME varchar2(100 char) +variable OPT_SPOOL_FILES varchar2(30 char) +variable OPT_NUMBER_COMMAS varchar2(1) + +exec /* xplan_exec_marker */ if :CURRENT_ERROR is null then :CURRENT_ERROR := 'processing XPLAN_OPTIONS'; end if; + +declare /* xplan_exec_marker */ -- process options + l_opt_string varchar2(200 char) := :XPLAN_OPTIONS||','; + l_curr_opt_str varchar2(200 char); + l_first_colon int; l_first_eq int; + l_name varchar2(30 char); + l_value varchar2(200 char); +begin + if :CURRENT_ERROR != 'processing XPLAN_OPTIONS' then + raise_application_error (-20001, 'skipping due to previous error'); + end if; + + -- set defaults + :OPT_INST_ID := userenv('Instance'); + :OPT_PLAN_STATS := 'last'; + :OPT_ACCESS_PREDICATES := 'Y'; + :OPT_LINES := 250; + :OPT_ASH_PROFILE_MINS := null; + :OPT_MODULE := null; + :OPT_ACTION := null; + :OPT_HASH_VALUE := null; + :OPT_SQL_ID := null; + :OPT_PARSED_BY := null; + :OPT_CHILD_NUMBER := null; + :OPT_DBMS_XPLAN := 'N'; + :OPT_DBMS_METADATA := 'N'; + :OPT_PLAN_DETAILS := 'N'; + :OPT_PLAN_ENV := 'Y'; + :OPT_TABINFOS := 'Y'; + :OPT_OBJINFOS := 'Y'; + :OPT_PARTINFOS := 'Y'; + :OPT_SELF := 'Y'; + :OPT_ORDER_BY := ''; + :OPT_SPOOL_NAME := null; + :OPT_SPOOL_FILES := null; + :OPT_NUMBER_COMMAS := 'Y'; + + -- override defaults from XPLAN_OPTIONS + loop + l_first_colon := instr (l_opt_string, ','); + exit when l_first_colon = 0 or l_first_colon is null; + l_curr_opt_str := substr (l_opt_string, 1, l_first_colon-1); + l_opt_string := substr (l_opt_string, l_first_colon+1); + if trim(l_curr_opt_str) is not null then + l_first_eq := instr (l_curr_opt_str, '='); + if l_first_eq <= 1 or l_first_eq is null then + raise_application_error (-20001, 'invalid option ="'||l_curr_opt_str||'".'); + end if; + l_name := trim(lower(substr (l_curr_opt_str, 1, l_first_eq-1))); + l_value := trim(lower(substr (l_curr_opt_str, l_first_eq+1))); + if l_name is null then + raise_application_error (-20002, 'invalid option ="'||l_curr_opt_str||'".'); + end if; + if l_name in ('inst_id') then + :OPT_INST_ID := to_number (l_value); + elsif l_name = 'plan_stats' then + if l_value in ('raw','per_exec','last') then + :OPT_PLAN_STATS := l_value; + else + raise_application_error (-20003, 'invalid value "'||l_value||'" for option '||l_name||'.'); + end if; + elsif l_name = 'access_predicates' then + if l_value in ('y','n') then + :OPT_ACCESS_PREDICATES := upper (l_value); + else + raise_application_error (-20004, 'invalid value "'||l_value||'" for option '||l_name||'.'); + end if; + elsif l_name in ('lines','linesize') then + :OPT_LINES := to_number (l_value); + elsif l_name = 'module' then + :OPT_MODULE := l_value; + elsif l_name = 'action' then + :OPT_ACTION := l_value; + elsif l_name in ('hash', 'hash_value') then + :OPT_HASH_VALUE := to_number (l_value); + elsif l_name = 'sql_id' then + :OPT_SQL_ID := trim(l_value); + &COMM_IF_GT_9I. if :OPT_SQL_ID is not null then raise_application_error (-20005, 'cannot use sql_id before 10g'); end if; + elsif l_name = 'parsed_by' then + :OPT_PARSED_BY := upper(l_value); + elsif l_name = 'child_number' then + :OPT_CHILD_NUMBER := to_number (l_value); + elsif l_name = 'dbms_xplan' then + if l_value in ('y','n') then + :OPT_DBMS_XPLAN := upper (l_value); + &COMM_IF_GT_9I. if :OPT_DBMS_XPLAN = 'Y' then raise_application_error (-20006, 'cannot use dbms_xplan before 10g'); end if; + else + raise_application_error (-20007, 'invalid value "'||l_value||'" for option '||l_name||'.'); + end if; + elsif l_name = 'dbms_metadata' then + if l_value in ('y','n','all') then + :OPT_DBMS_METADATA := upper (l_value); + else + raise_application_error (-20008, 'invalid value "'||l_value||'" for option '||l_name||'.'); + end if; + elsif l_name in ('plan_details', 'pd') then + if l_value in ('y','n') then + :OPT_PLAN_DETAILS := upper (l_value); + &COMM_IF_GT_9I. if :OPT_PLAN_DETAILS = 'Y' then raise_application_error (-20008, 'cannot display plan_details before 10g'); end if; + else + raise_application_error (-20009, 'invalid value "'||l_value||'" for option '||l_name||'.'); + end if; + elsif l_name = 'plan_env' then + if l_value in ('y','n') then + :OPT_PLAN_ENV := upper (l_value); + else + raise_application_error (-20010, 'invalid value "'||l_value||'" for option '||l_name||'.'); + end if; + elsif l_name in ('ash_profile_mins','ash_profile_min') then + :OPT_ASH_PROFILE_MINS := to_number (l_value); + if :OPT_ASH_PROFILE_MINS >= 0 and :OPT_ASH_PROFILE_MINS = trunc (:OPT_ASH_PROFILE_MINS) then + null; + else + raise_application_error (-20011, 'invalid value "'||l_value||'" for option '||l_name||'.'); + end if; + &COMM_IF_GT_9I. if :OPT_ASH_PROFILE_MINS != 0 then raise_application_error (-20012, 'cannot use ASH before 10g'); end if; + elsif l_name in ('tabinfos', 'ti') then + if l_value in ('y','n','bottom') then + :OPT_TABINFOS := upper (l_value); + else + raise_application_error (-20013, 'invalid value "'||l_value||'" for option '||l_name||'.'); + end if; + elsif l_name in ('objinfos', 'oi') then + if l_value in ('y','n') then + :OPT_OBJINFOS := upper (l_value); + else + raise_application_error (-20014, 'invalid value "'||l_value||'" for option '||l_name||'.'); + end if; + elsif l_name in ('partinfos', 'pi') then + if l_value in ('y','n') then + :OPT_PARTINFOS := upper (l_value); + else + raise_application_error (-20015, 'invalid value "'||l_value||'" for option '||l_name||'.'); + end if; + elsif l_name = 'order_by' then + :OPT_ORDER_BY := replace (trim(l_value), ';', ',') || ','; + elsif l_name = 'spool_name' then + :OPT_SPOOL_NAME := l_value; + if instr (:OPT_SPOOL_NAME, '.') = 0 then + :OPT_SPOOL_NAME := :OPT_SPOOL_NAME || '.lst'; + end if; + elsif l_name = 'spool_files' then + if l_value in ('single', 'by_hash', 'by_sql_id') then + :OPT_SPOOL_FILES := l_value; + else + raise_application_error (-20016, 'invalid value "'||l_value||'" for option '||l_name||'.'); + end if; + &COMM_IF_GT_9I. if :OPT_SPOOL_FILES = 'by_sql_id' then raise_application_error (-20017, 'cannot name files using sql_id before 10g'); end if; + elsif l_name = 'self' then + if l_value in ('y','n') then + :OPT_SELF := upper (l_value); + else + raise_application_error (-20017, 'invalid value "'||l_value||'" for option '||l_name||'.'); + end if; + elsif l_name = 'numbers_with_comma' then + if l_value in ('y','n') then + :OPT_NUMBER_COMMAS := upper (l_value); + else + raise_application_error (-20018, 'invalid value "'||l_value||'" for option '||l_name||'.'); + end if; + else + raise_application_error (-20099, 'invalid option name for "'||l_curr_opt_str||'".'); + end if; + end if; + end loop; + + -- handle ash_profile_mins not set + &COMM_IF_LT_10G. if :OPT_ASH_PROFILE_MINS is null then + &COMM_IF_LT_10G. :OPT_ASH_PROFILE_MINS := 1440; + &COMM_IF_LT_10G. end if; + + -- handle spool_files not set + if :OPT_SPOOL_FILES is null then + if :OPT_SQL_ID is not null then + :OPT_SPOOL_FILES := 'by_sql_id'; + elsif :OPT_HASH_VALUE is not null then + :OPT_SPOOL_FILES := 'by_hash'; + else + :OPT_SPOOL_FILES := 'single'; + end if; + end if; + + -- handle spool_name not set + if :OPT_SPOOL_NAME is null then + if :OPT_SPOOL_FILES = 'single' then + :OPT_SPOOL_NAME := 'xplan'||'_i'||:OPT_INST_ID||'.lst'; + else + :OPT_SPOOL_NAME := 'xplan.lst'; + end if; + end if; + + :CURRENT_ERROR := null; +end; +/ + +-- print current options values +variable CURRENT_XPLAN_OPTIONS varchar2(500 char) +begin +select /*+ xplan_exec_marker */ + 'inst_id=' || :OPT_INST_ID + || ' plan_stats='||:OPT_PLAN_STATS + || ' access_predicates='||:OPT_ACCESS_PREDICATES + || ' lines='||:OPT_LINES + || ' ash_profile_mins='||:OPT_ASH_PROFILE_MINS + || ' module='||:OPT_MODULE + || ' action='||:OPT_ACTION + || ' hash='||:OPT_HASH_VALUE + || ' sql_id='||:OPT_SQL_ID + || ' parsed_by='||:OPT_PARSED_BY + || ' child_number='||:OPT_CHILD_NUMBER + || ' dbms_xplan='||:OPT_DBMS_XPLAN + || ' dbms_metadata='||:OPT_DBMS_METADATA + || ' plan_details='||:OPT_PLAN_DETAILS + || ' plan_env='||:OPT_PLAN_ENV + || ' tabinfos='||:OPT_TABINFOS + || ' objinfos='||:OPT_OBJINFOS + || ' partinfos='||:OPT_PARTINFOS + || ' self='||:OPT_SELF + || ' order_by='||:OPT_ORDER_BY + || ' numbers_with_comma='||:OPT_NUMBER_COMMAS + || ' spool_name='||:OPT_SPOOL_NAME + || ' spool_files='||:OPT_SPOOL_FILES + into :CURRENT_XPLAN_OPTIONS + from dual; +end; +/ + +-- set internal defines +define PLAN_LAST_OR_NULL="error" +col PLAN_LAST_OR_NULL noprint new_value PLAN_LAST_OR_NULL +select /*+ xplan_exec_marker */ case when :OPT_PLAN_STATS = 'last' then 'LAST_' else null end as PLAN_LAST_OR_NULL from dual; + +define PLAN_AVG_PER_EXEC="error" +col PLAN_AVG_PER_EXEC noprint new_value PLAN_AVG_PER_EXEC +select /*+ xplan_exec_marker */ case when :OPT_PLAN_STATS = 'per_exec' then 'Y' else 'N' end as PLAN_AVG_PER_EXEC from dual; + +define COMM_IF_NO_PREDS="error" +col COMM_IF_NO_PREDS noprint new_value COMM_IF_NO_PREDS +select /*+ xplan_exec_marker */ case when :OPT_ACCESS_PREDICATES = 'Y' then '' else '--' end as COMM_IF_NO_PREDS from dual; + +define COMM_IF_NO_DBMS_XPLAN="error" +col COMM_IF_NO_DBMS_XPLAN noprint new_value COMM_IF_NO_DBMS_XPLAN +select /*+ xplan_exec_marker */ case when :OPT_DBMS_XPLAN = 'Y' then '' else '--' end as COMM_IF_NO_DBMS_XPLAN from dual; + +define COMM_IF_NO_DBMS_METADATA="error" +col COMM_IF_NO_DBMS_METADATA noprint new_value COMM_IF_NO_DBMS_METADATA +select /*+ METADATA_exec_marker */ case when :OPT_DBMS_METADATA != 'N' then '' else '--' end as COMM_IF_NO_DBMS_METADATA from dual; + +define COMM_IF_NO_HASH="error" +col COMM_IF_NO_HASH noprint new_value COMM_IF_NO_HASH +select /*+ xplan_exec_marker */ case when :OPT_HASH_VALUE is not null then '' else '--' end as COMM_IF_NO_HASH from dual; + +define COMM_IF_NO_SELF="error" +col COMM_IF_NO_SELF noprint new_value COMM_IF_NO_SELF +select /*+ xplan_exec_marker */ case when :OPT_SELF = 'Y' then '' else '--' end as COMM_IF_NO_SELF from dual; + +define COMM_IF_NO_SQL_LIKE="error" +col COMM_IF_NO_SQL_LIKE noprint new_value COMM_IF_NO_SQL_LIKE +select /*+ xplan_exec_marker */ + case when :SQL_LIKE is null or :SQL_LIKE = '%' then '--' else '' end as COMM_IF_NO_SQL_LIKE + from dual; + +define MAIN_BLOCK_SPOOL="error" +define BOTTOM_SCRIPT="error" +col MAIN_BLOCK_SPOOL noprint new_value MAIN_BLOCK_SPOOL +col BOTTOM_SCRIPT noprint new_value BOTTOM_SCRIPT +select /*+ xplan_exec_marker */ + case when :OPT_SPOOL_FILES = 'single' then :OPT_SPOOL_NAME else 'xplan_run.lst' end MAIN_BLOCK_SPOOL, + case when :OPT_SPOOL_FILES = 'single' then 'xplan_null_script.sql' else 'xplan_run.lst' end BOTTOM_SCRIPT + from dual; + +define LINE_SIZE="error" +col LINE_SIZE noprint new_value LINE_SIZE +select /*+ xplan_exec_marker */ + case when :OPT_SPOOL_FILES = 'single' then to_char(:OPT_LINES) else to_char(500) end as LINE_SIZE + from dual; + +define MAIN_ORDER_BY="error" +col MAIN_ORDER_BY noprint new_value MAIN_ORDER_BY +select /*+ xplan_exec_marker */ :OPT_ORDER_BY as MAIN_ORDER_BY from dual; + +define SPOOL_NAME="error" +col SPOOL_NAME noprint new_value SPOOL_NAME +select /*+ xplan_exec_marker */ to_char(:OPT_SPOOL_NAME) as SPOOL_NAME from dual; + +define SPOOL_FILES="error" +col SPOOL_FILES noprint new_value SPOOL_FILES +select /*+ xplan_exec_marker */ to_char(:OPT_SPOOL_FILES) as SPOOL_FILES from dual; + +variable MODULE_LIKE varchar2(100 char) +variable ACTION_LIKE varchar2(100 char) +exec /*+ xplan_exec_marker */ :MODULE_LIKE := :OPT_MODULE; :ACTION_LIKE := :OPT_ACTION; + +define ERROR_BEFORE_MAIN_BLOCK="" +col ERROR_BEFORE_MAIN_BLOCK noprint new_value ERROR_BEFORE_MAIN_BLOCK +select /*+ xplan_exec_marker */ case when :CURRENT_ERROR is null then null + else ' *** error before main block ( '||:CURRENT_ERROR||' ) ***' + end as ERROR_BEFORE_MAIN_BLOCK + from dual; diff --git a/Alberto/xplan_mcf_body.sql b/Alberto/xplan_mcf_body.sql new file mode 100644 index 0000000..3448112 --- /dev/null +++ b/Alberto/xplan_mcf_body.sql @@ -0,0 +1,287 @@ +-------------------------------------------------------------------------------- +-- Author: Alberto Dell'Era +-- Copyright: (c) 2008, 2009 Alberto Dell'Era http://www.adellera.it +-------------------------------------------------------------------------------- + +----------------------------------------------------------- +function mcf_fmt_with_comma(p_left_digits number, p_rite_digits number) +return varchar2 +is + l_left varchar2(50); +begin + if :OPT_NUMBER_COMMAS = 'Y' then + l_left := ltrim( rpad ('9', mod(p_left_digits, 3), '9') || replace (rpad ('9', 3 * trunc(p_left_digits / 3), '9') , '999', ',999'), ','); + else + l_left := rpad ('9', p_left_digits, '9'); + end if; + return l_left || rtrim (rpad ('.', p_rite_digits+1, '9'), '.'); +end mcf_fmt_with_comma; + +----------------------------------------------------------- +procedure mcf_reset ( + p_default_execs number, + p_stat_default_decimals int, + p_stex_default_decimals int -- if null => do not display stat/exec +) +is + l_stat_left_digits int := 29 - p_stat_default_decimals - 1; + l_stat_rite_digits int := p_stat_default_decimals; + l_stex_left_digits int := 29 - p_stex_default_decimals - 1; + l_stex_rite_digits int := p_stex_default_decimals; +begin + mcf_m_default_execs := p_default_execs; + -- formats + mcf_m_stat_fmt := mcf_fmt_with_comma( l_stat_left_digits, l_stat_rite_digits ); + mcf_m_stex_fmt := null; + if p_stex_default_decimals is not null then + mcf_m_stex_fmt := mcf_fmt_with_comma( l_stex_left_digits, l_stex_rite_digits ); + end if; + -- state + mcf_m_lines.delete; + mcf_m_lines_out.delete; +end mcf_reset; + +----------------------------------------------------------- +procedure mcf_add_line_char (p_name varchar2, p_stat varchar2, p_stex varchar2) +is + l_line mcf_t_line; +begin + l_line.mcf_m_name := p_name; + l_line.mcf_m_stat := p_stat; + l_line.mcf_m_stex := nvl (p_stex, ' '); + mcf_m_lines(mcf_m_lines.count) := l_line; +end mcf_add_line_char; + +----------------------------------------------------------- +procedure mcf_add_line (p_name varchar2, p_stat number, p_execs number default -1) +is + l_execs number; +begin + -- ignore if p_stat is null + if p_stat is null then + return; + end if; + + -- use defaults if p_execs = -1 + if p_execs = -1 then + l_execs := mcf_m_default_execs; + else + l_execs := p_execs; + end if; + -- handle execs = 0 by suppressing output + if l_execs = 0 then + l_execs := null; + end if; + -- format and add + mcf_add_line_char (p_name, trim(to_char (p_stat, mcf_m_stat_fmt)), trim(to_char (p_stat / l_execs, mcf_m_stex_fmt))); +end mcf_add_line; + +----------------------------------------------------------- +procedure mcf_prepare_output (p_num_columns int) +is + l_height number; + l_max_name int; + l_max_stat int; + l_max_stex int; + l_i_start int; + l_i_stop int; + l_separ_line varchar2(200 char); + l_temp varchar2(200 char); + l_display_stex boolean default true; +begin + mcf_m_lines_out.delete; + + if mcf_m_stex_fmt is null then + l_display_stex := false; + end if; + + l_height := ceil ( (mcf_m_lines.count-1) / p_num_columns); + + for c in 0..p_num_columns-1 loop + l_max_name := length (mcf_m_lines(0).mcf_m_name); + l_max_stat := length (mcf_m_lines(0).mcf_m_stat); + l_max_stex := length (mcf_m_lines(0).mcf_m_stex); + l_i_start := c*l_height+1; + l_i_stop := least ( (c+1)*l_height, mcf_m_lines.count-1 ); + + for i in l_i_start .. l_i_stop loop + if length (mcf_m_lines(i).mcf_m_name) > l_max_name then l_max_name := length (mcf_m_lines(i).mcf_m_name); end if; + if length (mcf_m_lines(i).mcf_m_stat) > l_max_stat then l_max_stat := length (mcf_m_lines(i).mcf_m_stat); end if; + if length (mcf_m_lines(i).mcf_m_stex) > l_max_stex then l_max_stex := length (mcf_m_lines(i).mcf_m_stex); end if; + end loop; + + l_separ_line := '-' || rpad ('-', l_max_name+2, '-') + || rpad ('-', l_max_stat+2, '-'); + if l_display_stex then + l_separ_line := l_separ_line || rpad ('-', l_max_stex+2, '-'); + end if; + + mcf_m_lines_out(mcf_m_lines_out.count) := l_separ_line; + l_temp := '|' || rpad (mcf_m_lines(0).mcf_m_name, l_max_name, ' ') || ' |' + || rpad (mcf_m_lines(0).mcf_m_stat, l_max_stat, ' ') || ' |'; + if l_display_stex then + l_temp := l_temp || rpad (mcf_m_lines(0).mcf_m_stex, l_max_stex, ' ') || ' |'; + end if; + mcf_m_lines_out(mcf_m_lines_out.count) := l_temp; + mcf_m_lines_out(mcf_m_lines_out.count) := l_separ_line; + for i in l_i_start .. l_i_stop loop + l_temp := '|' || rpad (mcf_m_lines(i).mcf_m_name, l_max_name, ' ') || ' |' + || lpad (mcf_m_lines(i).mcf_m_stat, l_max_stat, ' ') || ' |'; + if l_display_stex then + l_temp := l_temp || lpad (mcf_m_lines(i).mcf_m_stex, l_max_stex, ' ') || ' |'; + end if; + mcf_m_lines_out(mcf_m_lines_out.count) := l_temp; + end loop; + mcf_m_lines_out(mcf_m_lines_out.count) := l_separ_line; + end loop; + + --for i in 0..mcf_m_lines_out.count-1 loop + -- dbms_output.put_line (mcf_m_lines_out(i)|| ' | '); + --end loop; + + mcf_m_output_height := l_height + 4; +end mcf_prepare_output; + +----------------------------------------------------------- +function mcf_next_output_line +return varchar2 +is + l_out varchar2(200 char); + i int; +begin + if mcf_m_lines_out.count = 0 then + return null; + end if; + i := mcf_m_lines_out.first; + loop + l_out := l_out || mcf_m_lines_out(i); + mcf_m_lines_out.delete (i); + i := i + mcf_m_output_height; + exit when not mcf_m_lines_out.exists(i); + l_out := l_out || ' '; + end loop; + return l_out; +end mcf_next_output_line; + +----------------------------------------------------------- +procedure mcf_test +is + l_out varchar2(200 char); +begin + mcf_reset (p_default_execs => 10, p_stat_default_decimals => 0, p_stex_default_decimals => 1); + mcf_add_line_char ('gv$sql statname', 'total', 'total/exec'); + mcf_add_line ('s0', 0, null); + mcf_add_line ('s1____________________', 1); + mcf_add_line ('s2', 2, 10); + mcf_add_line ('s3______________', 3, 10); + mcf_add_line ('s4', 4, 10); + mcf_prepare_output (p_num_columns => 2); + loop + l_out := mcf_next_output_line; + exit when l_out is null; + dbms_output.put_line (l_out); + end loop; +end mcf_test; + +----------------------------------------------------------- +procedure mcf_n_reset +is +begin + mcf_m_n_lines.delete; + mcf_m_n_lines_out.delete; +end mcf_n_reset; + +----------------------------------------------------------- +procedure mcf_n_add_line (c1 varchar2 default null, c2 varchar2 default null, c3 varchar2 default null, + c4 varchar2 default null, c5 varchar2 default null, c6 varchar2 default null, + c7 varchar2 default null, c8 varchar2 default null, c9 varchar2 default null, + c10 varchar2 default null, c11 varchar2 default null, c12 varchar2 default null) +is + l_line mcf_t_n_line; +begin + l_line(1) := c1; l_line(2) := c2; l_line(3) := c3; + l_line(4) := c4; l_line(5) := c5; l_line(6) := c6; + l_line(7) := c7; l_line(8) := c8; l_line(9) := c9; + l_line(10) := c10; l_line(11) := c11; l_line(12) := c12; + mcf_m_n_lines (mcf_m_n_lines.count) := l_line; +end mcf_n_add_line; + +----------------------------------------------------------- +procedure mcf_n_prepare_output (c1_align varchar2 default 'right', c2_align varchar2 default 'right', c3_align varchar2 default 'right', + c4_align varchar2 default 'right', c5_align varchar2 default 'right', c6_align varchar2 default 'right', + c7_align varchar2 default 'right', c8_align varchar2 default 'right', c9_align varchar2 default 'right', + c10_align varchar2 default 'right', c11_align varchar2 default 'right', c12_align varchar2 default 'right', + p_separator varchar2 default ' ') +is + type mcf_t_lengths is table of int index by binary_integer; + type mcf_t_aligns is table of varchar2(5) index by binary_integer; + l_lengths mcf_t_lengths; + l_aligns mcf_t_aligns; + l_line varchar2(300 char); +begin + mcf_m_n_lines_out.delete; + + if mcf_m_n_lines.count = 0 then + return; + end if; + + -- get max columns lengths + for i in mcf_m_n_lines.first .. mcf_m_n_lines.last loop + for j in mcf_m_n_lines(i).first .. mcf_m_n_lines(i).last loop + if not l_lengths.exists(j) then + l_lengths(j) := 0; + end if; + l_lengths(j) := greatest (l_lengths(j), nvl( length (mcf_m_n_lines(i)(j)) , 0) ); + end loop; + end loop; + + l_aligns(1) := lower ( c1_align); l_aligns(2) := lower ( c2_align); l_aligns(3) := lower ( c3_align); + l_aligns(4) := lower ( c4_align); l_aligns(5) := lower ( c5_align); l_aligns(6) := lower ( c6_align); + l_aligns(7) := lower ( c7_align); l_aligns(8) := lower ( c8_align); l_aligns(9) := lower ( c9_align); + l_aligns(10) := lower (c10_align); l_aligns(11) := lower (c11_align); l_aligns(12) := lower (c12_align); + + for i in mcf_m_n_lines.first .. mcf_m_n_lines.last loop + l_line := ''; + for j in mcf_m_n_lines(i).first .. mcf_m_n_lines(i).last loop + if l_lengths(j) > 0 then + l_line := l_line || case when l_aligns(j) = 'right' + then lpad ( nvl(mcf_m_n_lines(i)(j), ' '), l_lengths(j) ) + else rpad ( nvl(mcf_m_n_lines(i)(j), ' '), l_lengths(j) ) + end + || p_separator; + end if; + end loop; + mcf_m_n_lines_out (mcf_m_n_lines_out.count) := substr (l_line, 1, length (l_line) - length (p_separator)); + end loop; +end mcf_n_prepare_output; + +----------------------------------------------------------- +function mcf_n_next_output_line +return varchar2 +is + l_out varchar2 (300 char); +begin + if mcf_m_n_lines_out.count = 0 then + return null; + end if; + l_out := mcf_m_n_lines_out (mcf_m_n_lines_out.first); + mcf_m_n_lines_out.delete (mcf_m_n_lines_out.first); + return l_out; +end mcf_n_next_output_line; + +----------------------------------------------------------- +procedure mcf_n_test +is + l_out varchar2 (300 char); +begin + mcf_n_reset; + mcf_n_add_line ('uno', 'due', null, 'quattro'); + mcf_n_add_line ('1', '2', null, 4); + mcf_n_prepare_output (c2_align => 'left', p_separator => '|'); + loop + l_out := mcf_n_next_output_line; + exit when l_out is null; + dbms_output.put_line ('"'||l_out||'"'); + end loop; +end mcf_n_test; + diff --git a/Alberto/xplan_mcf_vars.sql b/Alberto/xplan_mcf_vars.sql new file mode 100644 index 0000000..c7c9f77 --- /dev/null +++ b/Alberto/xplan_mcf_vars.sql @@ -0,0 +1,25 @@ +-------------------------------------------------------------------------------- +-- Author: Alberto Dell'Era +-- Copyright: (c) 2008, 2009 Alberto Dell'Era http://www.adellera.it +-------------------------------------------------------------------------------- + +type mcf_t_line is record (mcf_m_name varchar2(40), mcf_m_stat varchar2(40), mcf_m_stex varchar2(40)); +type mcf_t_line_arr is table of mcf_t_line index by binary_integer; +type mcf_t_output_array is table of varchar2(150) index by binary_integer; + +type mcf_t_n_line is table of varchar2(150) index by binary_integer; +type mcf_t_n_line_arr is table of mcf_t_n_line index by binary_integer; +type mcf_t_n_output_array is table of varchar2(300) index by binary_integer; + +mcf_m_default_execs number; + +mcf_m_stat_fmt varchar2(50); +mcf_m_stex_fmt varchar2(50); + +mcf_m_lines mcf_t_line_arr; +mcf_m_lines_out mcf_t_output_array; +mcf_m_output_height int; + +mcf_m_n_lines mcf_t_n_line_arr; +mcf_m_n_lines_out mcf_t_n_output_array; + diff --git a/Alberto/xplan_null_script.sql b/Alberto/xplan_null_script.sql new file mode 100644 index 0000000..e69de29 diff --git a/Alberto/xplan_objinfos_body.sql b/Alberto/xplan_objinfos_body.sql new file mode 100644 index 0000000..5bd9650 --- /dev/null +++ b/Alberto/xplan_objinfos_body.sql @@ -0,0 +1,385 @@ +-------------------------------------------------------------------------------- +-- Author: Alberto Dell'Era +-- Copyright: (c) 2008, 2009 Alberto Dell'Era http://www.adellera.it +-------------------------------------------------------------------------------- + +function calc_obj_info_seq (p_owner varchar2, p_seq_name varchar2) +return varchar2 +is + l_str varchar2(200 char); +begin + for s in (select /*+ xplan_exec_marker */ sequence_name, min_value, max_value, increment_by, + cycle_flag, order_flag, cache_size, last_number + from sys.all_sequences + where sequence_owner = p_owner + and sequence_name = p_seq_name) + loop + l_str := l_str || ' cache ' ||s.cache_size; + l_str := l_str || ' last_number=' ||s.last_number; + if s.min_value != 1 then l_str := l_str || ' minvalue '||s.min_value; end if; + if s.max_value != 999999999999999999999999999 then l_str := l_str || ' maxvalue '||s.max_value; end if; + if s.increment_by != 1 then l_str := l_str || ' increment by '||s.increment_by; end if; + if s.cycle_flag != 'N' then l_str := l_str || ' CYCLE'; end if; + if s.order_flag != 'N' then l_str := l_str || ' ORDER'; end if; + return l_str; + end loop; + return '* not found *'; +end calc_obj_info_seq; + +function calc_obj_info_syn (p_owner varchar2, p_syn_name varchar2) +return varchar2 +is + l_str varchar2(100 char); +begin + -- print ('syn ' ||p_owner||' '||p_syn_name); + + for s in (select /*+ ordered use_nl(o) xplan_exec_marker */ a.table_owner, a.table_name, a.db_link, o.object_type + from sys.all_synonyms a, sys.all_objects o + where a.owner = p_owner + and a.synonym_name = p_syn_name + and a.table_owner = o.owner + and a.table_name = o.object_name + and o.object_type not in ('SYNONYM','PACKAGE BODY','TYPE BODY','TABLE PARTITION') + order by 1,2,3,4) + loop + l_str := l_str || lower(s.object_type)||' '||s.table_owner||'.'||s.table_name; + if s.db_link is not null then + l_str := l_str || '@' || s.db_link; + end if; + l_str := l_str || ', '; + end loop; + return rtrim(trim(l_str),','); +end calc_obj_info_syn; + +function calc_type_of_unknown( + p_owner varchar2, + p_name varchar2 +) +return varchar2 +is + l_type_string sys.all_objects.object_type%type; +begin + --print( 'calc_type_of_unknown '||p_owner||'.'||p_name||' trying ...'); + + select /*+ xplan_exec_marker */ o.object_type + into l_type_string + from sys.all_objects o + where owner = p_owner + and object_name = p_name; + + print( 'resolved UNKNOWN_OBJECT_TYPE as '||p_owner||'.'||p_name||' -> '||l_type_string); + return l_type_string; +exception + when no_data_found then + return 'UNKNOWN_OBJECT_TYPE'; + when too_many_rows then + return 'UNKNOWN_OBJECT_TYPE'; +end calc_type_of_unknown; + +procedure print_obj_dep_and_store_1 ( + p_owner varchar2, + p_name varchar2, + p_type_string varchar2 +) +is + l_object_str varchar2(100 char); + l_object_str_unk varchar2(100 char); + l_type_string varchar2(50 char); + l_veedollar_is_fixed_view varchar2(1 char); + l_append_str varchar2(200 char); +begin + -- many objects in 10g and 11g have UNKNOWN_OBJECT_TYPE as their type + -- the following block reconstructs the type if p_owner/p_name identify + -- it unambigously + if p_type_string = 'UNKNOWN_OBJECT_TYPE' then + l_object_str_unk := p_owner || '.' || p_name; + if m_all_non_tab_objects_unk.exists( l_object_str_unk ) then + l_type_string := m_all_non_tab_objects_unk( l_object_str_unk ); + else + l_type_string := calc_type_of_unknown( p_owner, p_name ); + m_all_non_tab_objects_unk( l_object_str_unk ) := l_type_string; + end if; + else + l_type_string := p_type_string; + end if; + + l_object_str := l_type_string || '.' || p_owner || '.' || p_name; + + if m_all_non_tab_objects_skip.exists (l_object_str) then + return; + end if; + + if not m_all_non_tab_objects.exists (l_object_str) then + + if p_type_string = 'PACKAGE' and p_owner = 'SYS' and p_name in ('DBMS_OUTPUT','STANDARD','DBMS_STANDARD') then + m_all_non_tab_objects_skip (l_object_str) := 'X'; + return; + end if; + + -- almost all of the gv$ and v$ are generically reported as views in 9i, 10g(?), 11g, + -- but they are fixed views, hence not present in all_views + -- E.g. SYS.V$OBJECT_USAGE is a view, not a fixed view; almost all others are fixed views + if p_type_string = 'VIEW' and p_owner = 'SYS' and (p_name like 'V$%' or p_name like 'GV$%') then + + select /*+ xplan_exec_marker */ decode (count(*), 0, 'N', 'Y') + into l_veedollar_is_fixed_view + from sys.v_$fixed_view_definition + where view_name = p_name + and rownum = 1; + + if l_veedollar_is_fixed_view = 'Y' then + l_type_string := 'FIXED VIEW'; + l_object_str := l_type_string || '.' || p_owner || '.' || p_name; + end if; + end if; + + if l_type_string = 'SYNONYM' then + m_all_non_tab_objects (l_object_str) := calc_obj_info_syn (p_owner, p_name); + elsif l_type_string = 'SEQUENCE' then + m_all_non_tab_objects (l_object_str) := calc_obj_info_seq (p_owner, p_name); + else + m_all_non_tab_objects (l_object_str) := 'X'; + end if; + end if; + + if l_type_string = 'SYNONYM' then + l_append_str := ' -> ' || m_all_non_tab_objects (l_object_str); + elsif l_type_string = 'SEQUENCE' then + l_append_str := m_all_non_tab_objects (l_object_str); + end if; + + -- print dependency + print ('- depends on ' || lower(l_type_string) || ' ' || p_owner || '.' || p_name || l_append_str); + +end print_obj_dep_and_store_1; + +procedure print_obj_dep_and_store ( + p_inst_id sys.gv_$sql.inst_id%type, + p_address sys.gv_$sql.address%type, + p_hash_value sys.gv_$sql.hash_value%type +) +is +begin + -- found in pro :CURSOR,FUNCTION,LIBRARY,NON-EXISTENT,PACKAGE,PROCEDURE,SEQUENCE,SUMMARY,SYNONYM,TABLE,TRIGGER,TYPE,VIEW + for d in (select /*+ xplan_exec_marker */ + to_owner, + to_name, + -- following decode() is from 11.1.0.7 gv$db_object_cache (same as in 9.2.0.8) + -- see 43767.1 for meaning of NON-EXISTENT and INVALID TYPE + decode(to_type, 0,'CURSOR',1,'INDEX',2,'TABLE', 3,'CLUSTER',4,'VIEW', 5,'SYNONYM',6,'SEQUENCE', + 7,'PROCEDURE',8,'FUNCTION',9,'PACKAGE',10, 'NON-EXISTENT',11,'PACKAGE BODY',12,'TRIGGER',13,'TYPE', + 14, 'TYPE BODY', 15,'OBJECT',16,'USER',17,'DBLINK',18,'PIPE',19,'TABLE PARTITION', 20,'INDEX PARTITION',21,'LOB', + 22,'LIBRARY',23,'DIRECTORY',24,'QUEUE', 25,'INDEX-ORGANIZED TABLE',26,'REPLICATION OBJECT GROUP', + 27,'REPLICATION PROPAGATOR', 28,'JAVA SOURCE',29,'JAVA CLASS',30,'JAVA RESOURCE',31,'JAVA JAR', + 32,'INDEX TYPE',33, 'OPERATOR',34,'TABLE SUBPARTITION',35,'INDEX SUBPARTITION', 36, 'REPLICATED TABLE OBJECT', + 37,'REPLICATION INTERNAL PACKAGE', 38, 'CONTEXT POLICY',39,'PUB_SUB',40,'LOB PARTITION',41,'LOB SUBPARTITION', + 42,'SUMMARY',43,'DIMENSION',44,'APP CONTEXT',45,'STORED OUTLINE',46,'RULESET', 47,'RSRC PLAN', + 48,'RSRC CONSUMER GROUP',49,'PENDING RSRC PLAN', 50,'PENDING RSRC CONSUMER GROUP',51,'SUBSCRIPTION', + 52,'LOCATION', 53,'REMOTE OBJECT', 54,'SNAPSHOT METADATA',55,'XDB', 56,'JAVA SHARED DATA',57,'SECURITY PROFILE', + 'INVALID TYPE') as to_type_string, + to_type + from sys.gv_$object_dependency + where inst_id = p_inst_id + and from_address = p_address + and from_hash = p_hash_value + and to_type not in (0,2,10,25,34,35) + and to_type between 1 and 70 + order by to_type, to_owner, to_name) + loop + print_obj_dep_and_store_1 ( + p_owner => d.to_owner, p_name => d.to_name, + -- do not change UNKNOWN_OBJECT_TYPE string !! + p_type_string => case when d.to_type_string = 'INVALID TYPE' then 'UNKNOWN_OBJECT_TYPE' else d.to_type_string end + ); + end loop; +end print_obj_dep_and_store; + +procedure print_obj_info_view (p_owner varchar2, p_view_name varchar2) +is + l_cols_string long; +begin + for c in (select /*+ xplan_exec_marker */ column_id, column_name, data_type + from sys.all_tab_cols + where owner = p_owner + and table_name = p_view_name + order by column_id) + loop + l_cols_string := l_cols_string||'#'||c.column_id||' '||c.column_name ||'('||c.data_type||'),'; + end loop; + print ('view columns: '||rtrim(l_cols_string,',')); + + print_long (p_query => 'select /*+ xplan_exec_marker */ text from sys.all_views where owner = :1 and view_name = :2', + p_bind_1_name => ':1', p_bind_1_value => p_owner, + p_bind_2_name => ':2', p_bind_2_value => p_view_name); +exception + when no_data_found then + null; +end print_obj_info_view; + +procedure print_obj_info_mview (p_owner varchar2, p_mview_name varchar2) +is + l_cols_string long; + l_table_name varchar2(30 char); + l_object_id number; +begin + for m in (select /*+ xplan_exec_marker */ container_name, compile_state, staleness, last_refresh_date + from sys.all_mviews + where owner = p_owner + and mview_name = p_mview_name) + loop + l_table_name := m.container_name; + print ('compile_state: '||m.compile_state||' staleness: '||m.staleness + ||' last_refresh_date: '||to_char (m.last_refresh_date, 'yyyy-mm-dd/hh24:mi:ss')); + end loop; + + for c in (select /*+ xplan_exec_marker */ column_id, column_name, data_type + from sys.all_tab_cols + where owner = p_owner + and table_name = l_table_name + order by column_id) + loop + l_cols_string := l_cols_string||'#'||c.column_id||' '||c.column_name ||'('||c.data_type||'),'; + end loop; + print ('view columns: '||rtrim(l_cols_string,',')); + + print_long (p_query => 'select /*+ xplan_exec_marker */ query from sys.all_mviews where owner = :1 and mview_name = :2', + p_bind_1_name => ':1', p_bind_1_value => p_owner, + p_bind_2_name => ':2', p_bind_2_value => p_mview_name); + + select /*+ xplan_exec_marker */ object_id + into l_object_id + from sys.all_objects + where owner = p_owner + and object_name = l_table_name + and object_type = 'TABLE'; + + print ('table holding MV data:'); + print_cache_table_infos (l_object_id); +exception + when no_data_found then + null; +end print_obj_info_mview; + +procedure print_obj_info_fixed_view (p_owner varchar2, p_view_name varchar2) +is + l_cols_string long; + l_view_definition sys.v_$fixed_view_definition.view_definition%type; +begin + for c in (select /*+ xplan_exec_marker */ column_id, column_name, data_type + from sys.all_tab_cols + where owner = p_owner + and table_name = replace (p_view_name, 'V$', 'V_$') + order by column_id) + loop + l_cols_string := l_cols_string||'#'||c.column_id||' '||c.column_name ||'('||c.data_type||'),'; + end loop; + print ('fixed view columns: '||rtrim(l_cols_string,',')); + + select /*+ xplan_exec_marker */ view_definition + into l_view_definition + from sys.v_$fixed_view_definition + where view_name = p_view_name; + + print (l_view_definition); +exception + when no_data_found then + null; +end print_obj_info_fixed_view; + +procedure print_obj_info_assoc_stats (p_owner varchar2, p_name varchar2, p_type_str varchar2) +is + l_str varchar2(300 char); + l_str_cost varchar2(300 char); + l_str_stat varchar2(300 char); +begin + if p_type_str not in ('FUNCTION', 'PACKAGE', 'TYPE', 'INDEXTYPE') then + return; + end if; + + for a in (select /*+ xplan_exec_marker */ def_selectivity, def_cpu_cost, def_io_cost, def_net_cost, + statstype_schema, statstype_name + from sys.all_associations + where object_owner = p_owner + and object_name = p_name + and object_type = p_type_str) + loop + l_str := 'ASSOCIATED STATISTICS: '; + if a.def_selectivity is not null then l_str := l_str || ' default selectivity ('||a.def_selectivity||')'; end if; + l_str_cost := ''; + if a.def_cpu_cost is not null then l_str_cost := l_str_cost || ' cpu='||a.def_cpu_cost; end if; + if a.def_io_cost is not null then l_str_cost := l_str_cost || ' io=' ||a.def_io_cost ; end if; + if a.def_net_cost is not null then l_str_cost := l_str_cost || ' net='||a.def_net_cost; end if; + if l_str_cost is not null then + l_str := l_str || ' default cost ('||trim(l_str_cost)||')'; + end if; + if a.statstype_schema is not null then + l_str := l_str || ' using '||a.statstype_schema||'.'||a.statstype_name; + end if; + print (l_str); + end loop; +end print_obj_info_assoc_stats; + +procedure print_obj_info_dba_source (p_owner varchar2, p_name varchar2, p_type_str varchar2) +is +begin + for l in (select /*+ xplan_exec_marker */ text + from sys.all_source + where owner = p_owner + and name = p_name + and type = p_type_str + order by line) + loop + print (l.text); + end loop; +end print_obj_info_dba_source; + +procedure print_objinfos +is + l_dot_1 number; + l_dot_2 number; + l_object_str varchar2(100 char); + l_type_str varchar2(100 char); + l_owner varchar2(100 char); + l_name varchar2(100 char); +begin + l_object_str := m_all_non_tab_objects.first; + loop + exit when l_object_str is null; + + l_dot_1 := instr (l_object_str, '.', 1); + l_dot_2 := instr (l_object_str, '.', l_dot_1+1); + l_type_str := substr (l_object_str, 1, l_dot_1-1); + l_owner := substr (l_object_str, l_dot_1+1, (l_dot_2-l_dot_1-1) ); + l_name := substr (l_object_str, l_dot_2+1 ); + + --print (l_type_str||' '||l_owner||' '||l_name); + if l_type_str not in ('SYNONYM','SEQUENCE','UNKNOWN_OBJECT_TYPE') then + print ('############################################# '|| + case when l_type_str != 'SUMMARY' then lower(l_type_str) else '(summary) materialized view' end + ||' '||l_owner||'.'||l_name||' ###'); + end if; + + if l_type_str in ('SYNONYM','SEQUENCE') then + null; + elsif l_type_str = 'VIEW' then + print_obj_info_view (l_owner, l_name); + elsif l_type_str = 'FIXED VIEW' then + print_obj_info_fixed_view (l_owner, l_name); + -- PACKAGE BODY and TYPE BODY should not be possible for SQL and PL/SQL + elsif l_type_str in ('FUNCTION','PROCEDURE','TYPE','TYPE BODY','PACKAGE','PACKAGE BODY','TRIGGER') then + print_obj_info_assoc_stats (l_owner, l_name, l_type_str); + print_obj_info_dba_source (l_owner, l_name, l_type_str); + elsif l_type_str in ('SUMMARY') then + print_obj_info_mview (l_owner, l_name); + elsif l_type_str in ('INDEX TYPE') then + print_obj_info_assoc_stats (l_owner, l_name, 'INDEXTYPE'); + print ('xplan: infos for index types not implemented'); + elsif l_type_str in ('OPERATOR') then + print ('xplan: infos for operators not implemented'); + end if; + + l_object_str := m_all_non_tab_objects.next (l_object_str); + end loop; +end print_objinfos; + + diff --git a/Alberto/xplan_objinfos_vars.sql b/Alberto/xplan_objinfos_vars.sql new file mode 100644 index 0000000..806a9e4 --- /dev/null +++ b/Alberto/xplan_objinfos_vars.sql @@ -0,0 +1,13 @@ +-------------------------------------------------------------------------------- +-- Author: Alberto Dell'Era +-- Copyright: (c) 2008, 2009 Alberto Dell'Era http://www.adellera.it +-------------------------------------------------------------------------------- + +-- list of all referenced non-table objects +type all_non_tab_objects_t is table of varchar2(200) index by varchar2(110); +m_all_non_tab_objects all_non_tab_objects_t; +-- list of all referenced non-table objects to be skipped +m_all_non_tab_objects_skip all_non_tab_objects_t; +-- list of all objects of unknown type for which an heuristic discovery +-- has been tempted +m_all_non_tab_objects_unk all_non_tab_objects_t; diff --git a/Alberto/xplan_optim_env_body.sql b/Alberto/xplan_optim_env_body.sql new file mode 100644 index 0000000..b1dc3b1 --- /dev/null +++ b/Alberto/xplan_optim_env_body.sql @@ -0,0 +1,192 @@ +-------------------------------------------------------------------------------- +-- Author: Alberto Dell'Era +-- Copyright: (c) 2008-2013 Alberto Dell'Era http://www.adellera.it +-------------------------------------------------------------------------------- + +procedure optim_env_init_print_sys_pars +is + l_line varchar2(500 char); +begin + if :OPT_PLAN_ENV = 'N' then + return; + end if; + + -- put sys optimizer parameters in global hash table + mcf_reset (p_default_execs => to_number(null), -- ignored + p_stat_default_decimals => 0, -- ignored + p_stex_default_decimals => to_number(null) -- suppress disaply if stat/exec + ); + mcf_add_line_char ('optimizer param name', 'value', null); + for r in ( with pars as ( + select /*+ xplan_exec_marker */ name, value, isdefault, 'O' as typ + &COMM_IF_GT_9I. from sys.gv_$system_parameter + &COMM_IF_GT_9I. where inst_id = :OPT_INST_ID + &COMM_IF_GT_9I. and name in ('active_instance_count', 'bitmap_merge_area_size', 'cpu_count', 'cursor_sharing', 'hash_area_size', + &COMM_IF_GT_9I. 'is_recur_flags', 'optimizer_capture_sql_plan_baselines', 'optimizer_dynamic_sampling', + &COMM_IF_GT_9I. 'optimizer_features_enable', 'optimizer_index_caching', 'optimizer_index_cost_adj', 'optimizer_mode', + &COMM_IF_GT_9I. 'optimizer_secure_view_merging', 'optimizer_use_invisible_indexes', 'optimizer_use_pending_statistics', + &COMM_IF_GT_9I. 'optimizer_use_sql_plan_baselines', 'parallel_ddl_mode', 'parallel_degree', 'parallel_dml_mode', + &COMM_IF_GT_9I. 'parallel_execution_enabled', 'parallel_query_default_dop', 'parallel_query_mode', 'parallel_threads_per_cpu', + &COMM_IF_GT_9I. 'pga_aggregate_target', 'query_rewrite_enabled', 'query_rewrite_integrity', 'result_cache_mode', + &COMM_IF_GT_9I. 'skip_unusable_indexes', 'sort_area_retained_size', 'sort_area_size', 'star_transformation_enabled', + &COMM_IF_GT_9I. 'statistics_level', 'transaction_isolation_level', 'workarea_size_policy') + &COMM_IF_LT_10G from sys.gv_$sys_optimizer_env + &COMM_IF_LT_10G. where inst_id = :OPT_INST_ID + union all + select /*+ xplan_exec_marker */ name, value, isdefault, ' ' as typ + from sys.gv_$system_parameter + where inst_id = :OPT_INST_ID + and (name in ('disk_asynch_io', 'filesystemio_options', 'db_block_size', 'db_writer_processes', 'dbwr_io_slaves', + 'event', 'log_buffer', 'memory_target', 'processes', 'sessions', 'session_cached_cursors', 'sga_target', + 'shared_servers', 'undo_management', 'undo_retention', 'use_large_pages') + or name like 'parallel%' + or name like 'db\_%cache\_size' escape '\' + or name like '%pool\_size%' escape '\' + or name like 'query\_rewrite\_%' escape '\' + or name like 'result\_cache\_%' escape '\' + or name like 'shared\_pool\_%' escape '\' + ) + ), pars_adapted as ( + select name, + lower( nvl(value,'*null*') ) as value, + case when lower(isdefault) in ('true','yes') then 'yes' else 'false' end as isdefault, + typ + from pars + ) + select name, value, isdefault, typ + from pars_adapted + -- repeat General only if value is different from Optimizer + where (typ = 'O' or (typ = ' ' and (name, value, isdefault) not in (select name, value, isdefault from pars_adapted where typ='O'))) + order by name, typ) + loop + if r.typ = 'O' then + m_optim_env_sys_params(r.name) := r.value; + end if; + mcf_add_line_char (case when r.isdefault in ('yes','true') then r.name else upper(r.name) end, r.value||' '||r.typ, null); + end loop; + + -- display sys optimizer parameters + print ('parameters instance(sys) settings (O=optimizer parameter, name in bold=non-default):'); + mcf_prepare_output (p_num_columns => 3); + loop + l_line := mcf_next_output_line; + exit when l_line is null; + print (l_line); + end loop; +end optim_env_init_print_sys_pars; + +procedure optim_env_print_sql_pars ( + p_address raw, + p_hash_value number, + p_child_number number +) +is + &COMM_IF_LT_10G. l_line varchar2(500 char); + &COMM_IF_LT_10G. l_num_params_found int := 0; +begin + if :OPT_PLAN_ENV = 'N' then + return; + end if; + + &COMM_IF_GT_9I. print ('gv$sql_optimizer_env does not exist before 10g.'); + + -- display sql optimizer parameters + &COMM_IF_LT_10G. mcf_reset (p_default_execs => to_number(null), -- ignored + &COMM_IF_LT_10G. p_stat_default_decimals => 0, -- ignored + &COMM_IF_LT_10G. p_stex_default_decimals => to_number(null) -- suppress disaply if stat/exec + &COMM_IF_LT_10G. ); + &COMM_IF_LT_10G. mcf_add_line_char ('optimizer param name', 'value', null); + &COMM_IF_LT_10G. for r in (select /*+ xplan_exec_marker */ name, lower( nvl(value,'*null*') ) as value + &COMM_IF_LT_10G. from sys.gv_$sql_optimizer_env + &COMM_IF_LT_10G. where inst_id = :OPT_INST_ID + &COMM_IF_LT_10G. and address = p_address + &COMM_IF_LT_10G. and hash_value = p_hash_value + &COMM_IF_LT_10G. and child_number = p_child_number + &COMM_IF_LT_10G. order by name) + &COMM_IF_LT_10G. loop + &COMM_IF_LT_10G. if not m_optim_env_sys_params.exists(r.name) or m_optim_env_sys_params(r.name) != r.value then + &COMM_IF_LT_10G. mcf_add_line_char (r.name, r.value, null); + &COMM_IF_LT_10G. l_num_params_found := l_num_params_found + 1; + &COMM_IF_LT_10G. end if; + &COMM_IF_LT_10G. end loop; + + &COMM_IF_LT_10G. if l_num_params_found > 0 then + &COMM_IF_LT_10G. print ('WARNING: '||l_num_params_found || ' params in gv$sql_optimizer_env are not the same as instance ones:'); + &COMM_IF_LT_10G. mcf_prepare_output (p_num_columns => least (l_num_params_found, 3)); + &COMM_IF_LT_10G. loop + &COMM_IF_LT_10G. l_line := mcf_next_output_line; + &COMM_IF_LT_10G. exit when l_line is null; + &COMM_IF_LT_10G. print (l_line); + &COMM_IF_LT_10G. end loop; + &COMM_IF_LT_10G. else + &COMM_IF_LT_10G. print ('all params in gv$sql_optimizer_env are the same as instance ones.'); + &COMM_IF_LT_10G. end if; +end optim_env_print_sql_pars; + +procedure optim_env_add_sys_stats_to_mcf (p_name varchar2, p_insert_general boolean default false) +is + l_status VARCHAR2(100 char); + l_dstart date; + l_dstop date; + l_value number; + SYS_STAT_UNABLE_GET exception; + pragma exception_init (SYS_STAT_UNABLE_GET, -20003); + SYS_STAT_NOT_EXISTS exception; + pragma exception_init (SYS_STAT_NOT_EXISTS, -20004); +begin + + dbms_stats.get_system_stats ( + status => l_status, + dstart => l_dstart, + dstop => l_dstop, + pname => p_name, + pvalue => l_value + ); + + if p_insert_general then + mcf_add_line_char ('status', lower(l_status), null); + mcf_add_line_char ('gathering start', to_char (l_dstart, 'yyyy-mm-dd/hh24:mi:ss'), null); + mcf_add_line_char ('gathering stop', to_char (l_dstop, 'yyyy-mm-dd/hh24:mi:ss'), null); + end if; + + if l_value is not null then + mcf_add_line (lower(p_name), l_value); + else + mcf_add_line_char (lower(p_name), 'null', null); + end if; +exception + when SYS_STAT_UNABLE_GET then + mcf_add_line_char (lower(p_name), 'no value found', null); + when SYS_STAT_NOT_EXISTS then + mcf_add_line_char (lower(p_name), 'not existent', null); +end optim_env_add_sys_stats_to_mcf; + +procedure optim_env_print_sys_stats +is + l_line varchar2(500 char); +begin + mcf_reset (p_default_execs => to_number(null), -- ignored + p_stat_default_decimals => 0, -- ignored + p_stex_default_decimals => to_number(null) -- suppress disaply if stat/exec + ); + mcf_add_line_char ('system statistic', 'value', null); + + optim_env_add_sys_stats_to_mcf ('CPUSPEED', true); + &COMM_IF_LT_10G. optim_env_add_sys_stats_to_mcf ('CPUSPEEDNW'); + optim_env_add_sys_stats_to_mcf ('SREADTIM'); + optim_env_add_sys_stats_to_mcf ('MREADTIM'); + optim_env_add_sys_stats_to_mcf ('MBRC'); + &COMM_IF_LT_10G. optim_env_add_sys_stats_to_mcf ('IOSEEKTIM'); + &COMM_IF_LT_10G. optim_env_add_sys_stats_to_mcf ('IOTFRSPEED'); + optim_env_add_sys_stats_to_mcf ('MAXTHR'); + optim_env_add_sys_stats_to_mcf ('SLAVETHR'); + + print ('optimizer system statistics:'); + mcf_prepare_output (p_num_columns => 3); + loop + l_line := mcf_next_output_line; + exit when l_line is null; + print (l_line); + end loop; +end optim_env_print_sys_stats; + \ No newline at end of file diff --git a/Alberto/xplan_optim_env_vars.sql b/Alberto/xplan_optim_env_vars.sql new file mode 100644 index 0000000..a9c334f --- /dev/null +++ b/Alberto/xplan_optim_env_vars.sql @@ -0,0 +1,7 @@ +-------------------------------------------------------------------------------- +-- Author: Alberto Dell'Era +-- Copyright: (c) 2008, 2009 Alberto Dell'Era http://www.adellera.it +-------------------------------------------------------------------------------- + +type optim_env_sys_params_t is table of varchar2(40) index by varchar2(40); +m_optim_env_sys_params optim_env_sys_params_t; \ No newline at end of file diff --git a/Alberto/xplan_print_plan.sql b/Alberto/xplan_print_plan.sql new file mode 100644 index 0000000..ed8b447 --- /dev/null +++ b/Alberto/xplan_print_plan.sql @@ -0,0 +1,605 @@ +-------------------------------------------------------------------------------- +-- Author: Alberto Dell'Era +-- Copyright: (c) 2008, 2009, 2010, 2012, 2013 Alberto Dell'Era http://www.adellera.it +-------------------------------------------------------------------------------- + +procedure extract_tag_value( p_xml clob, p_tag_name varchar2, p_tag_text out varchar2) +is + l_start int; + l_end int; + l_start_marker varchar2(30) := '<' || p_tag_name; + l_end_marker varchar2(30) := '' ; + l_next_chars varchar2(2 char); +begin + l_start := dbms_lob.instr (p_xml, l_start_marker, 1); + if l_start = 0 or l_start is null then + return; + end if; + l_start := l_start + length(l_start_marker); + + l_next_chars := dbms_lob.substr (p_xml, 2, l_start); + if l_next_chars is null or l_next_chars = '/>' then + return; + end if; + l_start := l_start + 1; + + l_end := dbms_lob.instr (p_xml, l_end_marker, l_start); + if l_end = 0 or l_end is null then + print ('error: end marker not found for tag '||p_tag_name); + return; + end if; + + if l_end - l_start > 32767 then + print ('error: tag too long for tag '||p_tag_name); + return; + end if; + + p_tag_text := dbms_lob.substr (p_xml, l_end - l_start, l_start); +end extract_tag_value; + +function extract_tag( + p_xml varchar2, + p_tag_name varchar2, + p_occurrence int, + p_attributes out varchar2, + p_value out varchar2) +return boolean +is + l_start_section varchar2(30) := '<' || p_tag_name || ' '; + l_end_tag varchar2(30) := ''; + l_start int; + l_end_start_tag int; + l_end int; +begin + l_start := instr (p_xml, l_start_section, 1, p_occurrence); + if l_start = 0 or l_start is null then + return false; + end if; + l_start := l_start + length(l_start_section); + + l_end_start_tag := instr (p_xml, '>', l_start); + if l_end_start_tag = 0 or l_end_start_tag is null then + print ('xml error: xml misformat for tag ' || p_tag_name); + return false; + end if; + + if substr(p_xml, l_end_start_tag-1, 1) = '/' then + -- + p_attributes := substr (p_xml, l_start, (l_end_start_tag-1) - l_start ); + p_value := null; + else + -- value + p_attributes := substr (p_xml, l_start, l_end_start_tag - l_start ); + + l_end := instr (p_xml, l_end_tag, l_end_start_tag+1); + if l_end = 0 or l_end is null then + print ('xml error: xml misformat 2 for tag ' || p_tag_name); + return false; + end if; + + p_value := substr (p_xml, l_end_start_tag+1, l_end - l_end_start_tag - 1); + end if; + + return true; +end extract_tag; + +function get_attribute( p_attributes_str varchar2, p_name varchar2 ) +return varchar2 +is + l_pos int; l_start int; l_end int; +begin + l_pos := instr (p_attributes_str, p_name||'="'); + if l_pos = 0 then return null; end if; + l_start := instr (p_attributes_str, '"', l_pos); + if l_start = 0 then return '??'; end if; + l_start := l_start + 1; + l_end := instr (p_attributes_str, '"', l_start); + if l_end = 0 then return '???'; end if; + return substr (p_attributes_str, l_start, l_end - l_start); +end get_attribute; + +procedure print_peeked_binds(p_other_xml clob) +is + l_peeked_binds_values long; + l_peeked_binds_types long; + l_peeked_str long; + l_bind_num int; + l_nam varchar2(30 char); + l_dty int; + l_frm int; + l_mxl int; + l_value_hex long; + l_value_raw long raw; + l_value long; + l_type varchar2(100); + l_value_varchar2 varchar2(32767); + l_value_nvarchar2 nvarchar2(32767); + l_value_number number; + l_value_date date; + l_value_timestamp timestamp; + &COMM_IF_LT_10G. l_value_binary_float binary_float; + &COMM_IF_LT_10G. l_value_binary_double binary_double; + l_value_rowid rowid; + l_bind_attributes long; + l_bind_found boolean; +begin + if p_other_xml is null then + return; + end if; + + extract_tag_value ( p_other_xml, 'peeked_binds', l_peeked_str); + if l_peeked_str is null then + return; + end if; + + if 1=0 then + print ('peeked binds : original peeked bind xml section:"'||l_peeked_str||'"'); + --return; + end if; + + -- format: 58 + -- or (for nulls) + -- max is the MaXLength in bytes + l_bind_num := 1; + l_peeked_binds_values := 'peeked binds values:'; + l_peeked_binds_types := 'peeked binds types :'; + loop + l_bind_found := extract_tag( l_peeked_str, 'bind', l_bind_num, l_bind_attributes, l_value_hex ); + --print('peeked binds : attrs=['||l_bind_attributes||'] val=['||l_value_hex||']'); + exit when not l_bind_found; + + begin + l_value_raw := hextoraw (l_value_hex); + exception + when others then + raise_application_error (-20089, 'l_value_hex="'||l_value_hex||'" '||sqlerrm); + end; + + l_nam := get_attribute (l_bind_attributes, 'nam'); + l_mxl := to_number (get_attribute (l_bind_attributes, 'mxl')); + l_dty := to_number (get_attribute (l_bind_attributes, 'dty')); + l_frm := trim(get_attribute (l_bind_attributes, 'frm')); + -- For dty codes, see "Call Interface Programmer's Guide", "Datatypes" + -- Also, "select text from dba_views where view_name = 'USER_TAB_COLS'" gives + -- a decode function to interpret them. charsetform is the "frm" in the xml string. + -- Generally frm=2 means NLS charset. + if l_dty = 1 and l_frm = '1' then -- varchar2 + dbms_stats.convert_raw_value (l_value_raw, l_value_varchar2); + l_value := ''''||l_value_varchar2||''''; + l_type := 'varchar2('||l_mxl||')'; + elsif l_dty = 1 and l_frm = '2' then -- nvarchar2 + dbms_stats.convert_raw_value_nvarchar (l_value_raw, l_value_nvarchar2); + l_value := ''''||l_value_nvarchar2||''''; + l_type := 'nvarchar2('||l_mxl||')'; + elsif l_dty = 2 then -- number + dbms_stats.convert_raw_value (l_value_raw, l_value_number); + l_value := nvl (to_char(l_value_number), 'null'); + l_type := 'number('||l_mxl||')'; + elsif l_dty = 12 then -- date + dbms_stats.convert_raw_value (l_value_raw, l_value_date); + l_value := nvl (to_char (l_value_date, 'yyyy/mm/dd hh24:mi:ss'), 'null'); + l_type := 'date'; + elsif l_dty = 23 then -- raw + l_value := nvl (to_char(l_value_hex), 'null'); + l_type := 'raw('||l_mxl||')'; + elsif l_dty = 69 then -- rowid (not fully tested) + dbms_stats.convert_raw_value_rowid (l_value_raw, l_value_rowid); + l_value := nvl (rowidtochar (l_value_rowid), 'null'); + l_type := 'rowid'; + elsif l_dty = 96 and l_frm = '1' then -- char + dbms_stats.convert_raw_value (l_value_raw, l_value_varchar2); + l_value := ''''||l_value_varchar2||''''; + l_type := 'char('||l_mxl||')'; + elsif l_dty = 96 and l_frm = '2' then -- nchar + dbms_stats.convert_raw_value_nvarchar (l_value_raw, l_value_nvarchar2); + l_value := ''''||l_value_nvarchar2||''''; + l_type := 'nchar('||l_mxl||')'; + &COMM_IF_LT_10G. elsif l_dty = 100 then -- binary_float + &COMM_IF_LT_10G. dbms_stats.convert_raw_value (l_value_raw, l_value_binary_float); + &COMM_IF_LT_10G. l_value := to_char (l_value_binary_float); + &COMM_IF_LT_10G. l_type := 'binary_float'; + &COMM_IF_LT_10G. elsif l_dty = 101 then -- binary_double + &COMM_IF_LT_10G. dbms_stats.convert_raw_value (l_value_raw, l_value_binary_double); + &COMM_IF_LT_10G. l_value := to_char (l_value_binary_double); + &COMM_IF_LT_10G. l_type := 'binary_double'; + elsif l_dty = 180 then -- timestamp + l_value := '(hex)'||l_value_hex; -- found no way to convert in 10.2 + l_type := 'timestamp'; + elsif l_dty = 181 then -- timestamp with time zone + l_value := '(hex)'||l_value_hex; -- found no way to convert in 10.2 + l_type := 'timestamp with time zone'; + elsif l_dty = 182 then -- interval year to month + l_value := '(hex)'||l_value_hex; -- found no way to convert in 10.2 + l_type := 'interval year to month'; + elsif l_dty = 183 then -- interval day to second + l_value := '(hex)'||l_value_hex; -- found no way to convert in 10.2 + l_type := 'interval day to second'; + elsif l_dty = 231 then -- timestamp with local time zone + l_value := '(hex)'||l_value_hex; -- found no way to convert in 10.2 + l_type := 'timestamp with local time zone'; + else + l_value := '(hex)'||l_value_hex; + l_type := '[dty='||l_dty||' frm='||l_frm||' mxl='||l_mxl||']'; + end if; + l_peeked_binds_values := l_peeked_binds_values || ' ' || l_nam || ' = ' || l_value|| ','; + l_peeked_binds_types := l_peeked_binds_types || ' ' || l_nam || ' = ' || l_type || ','; + l_bind_num := l_bind_num + 1; + end loop; + + l_peeked_binds_values := rtrim (l_peeked_binds_values, ','); + l_peeked_binds_types := rtrim (l_peeked_binds_types , ','); + + print (l_peeked_binds_values); + print (l_peeked_binds_types); + +end print_peeked_binds; + +procedure print_notes(p_other_xml clob) +is + l_xml long; + l_info_num int; + l_info_found boolean; + l_notes long; + l_info_attributes varchar2(200); + l_info_value varchar2(1000); + l_info_type varchar2(200); +begin + if p_other_xml is null then + return; + end if; + + if dbms_lob.getlength( p_other_xml) > 32767 then + print('print_notes: warning: cannot look for notes, other_xml too long'); + return; + end if; + + l_xml := dbms_lob.substr (p_other_xml, 32767, 1); + + l_info_num := 1; + loop + l_info_found := extract_tag( l_xml, 'info', l_info_num, l_info_attributes, l_info_value ); + --print('print_notes : attrs=['||l_info_attributes||'] val=['||l_info_value||']'); + exit when not l_info_found; + + l_info_type := get_attribute( l_info_attributes, 'type' ); + if l_info_type not in ( 'plan_hash', 'db_version', 'parse_schema', 'plan_hash_2' ) then + l_notes := l_notes || l_info_type || '=' || l_info_value || ' '; + end if; + + l_info_num := l_info_num + 1; + end loop; + + if l_notes is not null then + print('notes : ' || l_notes ); + end if; +end print_notes; + +function adapt_projection(p_txt varchar2) +return varchar2 +is + l_buf varchar2(4000) := replace( replace(p_txt, '"', ''), ' ', ''); + l_open int := 1; + l_clos int; +begin + loop + l_open := instr(l_buf, '[', l_open); + exit when l_open = 0 or l_open is null; + l_clos := instr(l_buf, ']', l_open+1); + exit when l_clos = 0 or l_clos is null; + l_buf := substr(l_buf, 1, l_open-1) || substr(l_buf, l_clos+1); + end loop; + return substr(l_buf, 1, 1000); +end adapt_projection; + +function adapt_predicate(p_txt varchar2) +return varchar2 +is + l_buf varchar2(4000) := replace(p_txt, '"', ''); +begin + return l_buf; +end adapt_predicate; + +procedure print_plan ( + p_inst_id sys.gv_$sql.inst_id%type, + p_address sys.gv_$sql.address%type, + p_hash_value sys.gv_$sql.hash_value%type, + p_child_number sys.gv_$sql.child_number%type, + p_executions int, + p_first_load_time date, + p_last_load_time date, + p_last_active_time date default null, -- null if not 10gR2+ + p_sql_plan_baseline varchar2 default null -- null if not 11g+ +) +is + type access_predicates_t is table of sys.gv_$sql_plan.access_predicates%type index by binary_integer; + type filter_predicates_t is table of sys.gv_$sql_plan.filter_predicates%type index by binary_integer; + type others_t is table of sys.gv_$sql_plan.other %type index by binary_integer; + type base_table_object_ids_t is table of varchar2(1) index by varchar2(30); + l_access_predicates access_predicates_t; + l_filter_predicates filter_predicates_t; + l_others others_t; + l_base_table_object_ids base_table_object_ids_t; + l_base_object_id_char varchar2(30); + l_plan scf_state_t; + l_plan2 scf_state_t; + l_plan3 scf_state_t; + l_col_tag varchar2(10 char); + l_execs int; + l_other_tag sys.gv_$sql_plan.other_tag%type; + l_id_min int := 1e6; + l_id_max int := -1; + l_id_string varchar2(10 char); + l_tmp varchar2(1000 char); + &COMM_IF_LT_10G. l_sql_id sys.gv_$sql.sql_id%type; + l_cursor sys_refcursor; + l_dbms_xplan_tag varchar2(10 char); + l_dbms_xplan_format varchar2(50 char); +begin + if '&PLAN_LAST_OR_NULL.' = 'LAST_' then + l_col_tag := 'last'; + l_execs := 1; + l_dbms_xplan_tag := ' LAST'; + elsif '&PLAN_AVG_PER_EXEC.' = 'Y' then + l_col_tag := '/exec'; + l_execs := p_executions; + else + l_col_tag := 'raw'; + l_execs := 1; -- a trick, of course + end if; + + if l_execs <= 0 then + l_execs := null; + end if; + + for s in (select /*+ xplan_exec_marker */ -- 10.2.0.3 columns + -- p.address, + -- p.hash_value, +&COMM_IF_LT_10G. p.sql_id, +&COMM_IF_LT_10G. p.plan_hash_value, +&COMM_IF_LT_10GR2. p.child_address, + p.child_number, + -- p.timestamp, + p.operation, + p.options, + p.object_node, + p.object#, + p.object_owner, + p.object_name, +&COMM_IF_LT_10G. p.object_alias, +&COMM_IF_LT_10G. p.object_type, + p.optimizer, + p.id, + p.parent_id, + p.depth, + p.position, + p.search_columns, + p.cost, + p.cardinality, + p.bytes, + p.other_tag, + p.partition_start, + p.partition_stop, + p.partition_id, + p.other, + p.distribution, + p.cpu_cost, + p.io_cost, + p.temp_space, +&COMM_IF_NO_PREDS. p.access_predicates, +&COMM_IF_NO_PREDS. p.filter_predicates, +&COMM_IF_LT_10G. p.projection, + --time +&COMM_IF_LT_10G. p.qblock_name, +&COMM_IF_LT_10G. p.remarks, +&COMM_IF_LT_10GR2. p.other_xml, + s.executions, + s.&PLAN_LAST_OR_NULL.starts as starts, + s.&PLAN_LAST_OR_NULL.output_rows as output_rows, + s.&PLAN_LAST_OR_NULL.cr_buffer_gets as cr_buffer_gets, + s.&PLAN_LAST_OR_NULL.cu_buffer_gets as cu_buffer_gets, + s.&PLAN_LAST_OR_NULL.disk_reads as disk_reads, + s.&PLAN_LAST_OR_NULL.disk_writes as disk_writes, + s.&PLAN_LAST_OR_NULL.elapsed_time as elapsed_time, + s.policy, + s.estimated_optimal_size, + s.estimated_onepass_size, + s.last_memory_used, + s.last_execution, + s.last_degree, + s.total_executions, + s.optimal_executions, + s.onepass_executions, + s.multipasses_executions, + s.active_time, + s.max_tempseg_size, + s.last_tempseg_size + from sys.gv_$sql_plan p, sys.gv_$sql_plan_statistics_all s + where p.inst_id = p_inst_id + and s.inst_id(+) = p_inst_id + and p.address = p_address + and p.hash_value = p_hash_value + and p.child_number = p_child_number + and s.address(+) = p_address + and s.hash_value(+) = p_hash_value + and s.child_number(+) = p_child_number + and p.id = s.id(+) + order by p.id) + loop + if s.id < l_id_min then l_id_min := s.id; end if; + if s.id > l_id_max then l_id_max := s.id; end if; + &COMM_IF_LT_10G. l_sql_id := s.sql_id; + &COMM_IF_LT_10G. if s.id = 1 then + &COMM_IF_LT_10GR2. print_peeked_binds (s.other_xml); + &COMM_IF_LT_10GR2. print_notes (s.other_xml); + &COMM_IF_LT_10G. if p_sql_plan_baseline is not null then print('sql plan baseline : '||p_sql_plan_baseline); end if; + &COMM_IF_LT_10G. end if; + l_base_object_id_char := to_char(get_cache_base_table_object_id (s.object#)); + if l_base_object_id_char is not null then + l_base_table_object_ids (l_base_object_id_char) := 'X'; + if :OPT_TABINFOS = 'BOTTOM' then + m_all_referenced_object_ids(l_base_object_id_char) := 'X'; + end if; + end if; + scf_add_elem (l_plan, 'CR+CU', (s.cr_buffer_gets + s.cu_buffer_gets) / l_execs, p_sep_mid => l_col_tag); + &COMM_IF_NO_SELF scf_add_self (l_plan, 'CR+CU+', p_self_src => 'CR+CU'); + scf_add_elem (l_plan, 'Ela', s.elapsed_time / l_execs, p_sep_mid => l_col_tag, p_sep_bot=>'usec'); + &COMM_IF_NO_SELF scf_add_self (l_plan, 'Ela+', p_self_src => 'Ela'); + scf_add_elem (l_plan, 'Starts', s.starts / l_execs, p_sep_mid => l_col_tag); + scf_add_elem (l_plan, 'Id' , s.id , p_is_auxil => 'Y', p_self_is_id => 'Y'); + scf_add_elem (l_plan, 'pId', s.parent_id, p_is_auxil => 'Y', p_self_is_pid => 'Y', p_is_hidden => 'Y'); + /* scf_add_elem (l_plan, 'pId', s.parent_id); -- TEMP!! + scf_add_elem (l_plan, 'remarks', s.remarks); -- TEMP!! + scf_add_elem (l_plan, 'depth', s.depth); -- TEMP!! + scf_add_elem (l_plan, 'position', s.position); -- TEMP!! + scf_add_elem (l_plan, 'qblock', s.qblock_name); -- TEMP!! + scf_add_elem (l_plan, 'optim', s.optimizer); -- TEMP!! + scf_add_elem (l_plan, 'object#', s.object#); -- TEMP!!*/ + scf_add_elem (l_plan, 'Operation', lpad (' ', s.depth) || s.operation||' '||s.options ); + scf_add_elem (l_plan, 'Name', s.object_name); + scf_add_elem (l_plan, 'Table', get_cache_obj_name (get_cache_base_table_object_id (s.object#))); + scf_add_elem (l_plan, 'TQ', s.object_node); + scf_add_elem (l_plan, 'Erows', s.cardinality); + scf_add_elem (l_plan, 'Arows', s.output_rows / l_execs, p_sep_mid => l_col_tag); + scf_add_elem (l_plan, 'Cost', s.cost); + scf_add_elem (l_plan, 'IoCost', s.io_cost); + scf_add_elem (l_plan, 'Psta', replace (s.partition_start, 'ROW LOCATION', 'ROWID') ); + scf_add_elem (l_plan, 'Psto', replace (s.partition_stop , 'ROW LOCATION', 'ROWID') ); + scf_add_elem (l_plan, 'IdP', s.partition_id); + l_other_tag := s.other_tag; + l_other_tag := replace (l_other_tag, 'SERIAL_FROM_REMOTE' , 'S->R'); + l_other_tag := replace (l_other_tag, 'PARALLEL_FROM_SERIAL' , 'S->P'); + l_other_tag := replace (l_other_tag, 'PARALLEL_TO_SERIAL' , 'P->S'); + l_other_tag := replace (l_other_tag, 'PARALLEL_TO_PARALLEL' , 'P->P'); + l_other_tag := replace (l_other_tag, 'PARALLEL_COMBINED_WITH_PARENT', 'PCWP'); + l_other_tag := replace (l_other_tag, 'PARALLEL_COMBINED_WITH_CHILD' , 'PCWC'); + scf_add_elem (l_plan, 'OT', l_other_tag); + scf_add_elem (l_plan, 'Distr', replace (replace (s.distribution, ' (RANDOM)', '(RAND)'),' (ORDER)', '(ORDER)')); + --scf_add_elem (l_plan, 'obj alias', s.object_alias); + --scf_add_elem (l_plan, 'qb_name', s.qblock_name); + &COMM_IF_NO_PREDS. if s.access_predicates is not null then l_access_predicates(s.id) := adapt_predicate(s.access_predicates); end if; + &COMM_IF_NO_PREDS. if s.filter_predicates is not null then l_filter_predicates(s.id) := adapt_predicate(s.filter_predicates); end if; + if s.other is not null then l_others(s.id) := s.other; end if; + + scf_add_elem (l_plan2, 'Id' , s.id , p_is_auxil => 'Y', p_self_is_id => 'Y'); + scf_add_elem (l_plan2, 'pId', s.parent_id, p_is_auxil => 'Y', p_self_is_pid => 'Y', p_is_hidden => 'Y'); + scf_add_elem (l_plan2, 'Starts', s.starts / l_execs, p_sep_mid => l_col_tag); + scf_add_elem (l_plan2, 'CR', s.cr_buffer_gets / l_execs, p_sep_mid => l_col_tag); + &COMM_IF_NO_SELF scf_add_self (l_plan2, 'CR+', p_self_src => 'CR'); + scf_add_elem (l_plan2, 'CU', s.cu_buffer_gets / l_execs, p_sep_mid => l_col_tag); + &COMM_IF_NO_SELF scf_add_self (l_plan2, 'CU+', p_self_src => 'CU'); + scf_add_elem (l_plan2, 'diskR', s.disk_reads / l_execs, p_sep_mid => l_col_tag); + &COMM_IF_NO_SELF scf_add_self (l_plan2, 'diskR+', p_self_src => 'diskR'); + scf_add_elem (l_plan2, 'diskW', s.disk_writes / l_execs, p_sep_mid => l_col_tag); + &COMM_IF_NO_SELF scf_add_self (l_plan2, 'diskW+', p_self_src => 'diskW'); + scf_add_elem (l_plan2, 'E0ram', s.estimated_optimal_size, p_sep_bot=>'KB'); + scf_add_elem (l_plan2, 'E1ram', s.estimated_optimal_size, p_sep_bot=>'KB'); + scf_add_elem (l_plan2, 'Aram', s.last_memory_used, p_sep_mid => 'last', p_sep_bot=>'KB'); + scf_add_elem (l_plan2, 'Policy', s.policy); + scf_add_elem (l_plan2, 'A01M', s.last_execution, p_sep_mid => 'last'); + l_tmp := null; + if s.optimal_executions > 0 or s.onepass_executions > 0 or s.multipasses_executions > 0 then + l_tmp := s.optimal_executions||'/'||s.onepass_executions||'/'||s.multipasses_executions; + end if; + scf_add_elem (l_plan2, '0/1/M', l_tmp, p_sep_bot=>'#'); + + scf_add_elem (l_plan2, 'ActTim', s.active_time*10, p_sep_mid => 'avg', p_sep_bot=>'msec'); + scf_add_elem (l_plan2, 'ETmpSpc', s.temp_space/1024, p_sep_bot=>'KB'); + scf_add_elem (l_plan2, 'ATmpSpcM', s. max_tempseg_size/1024, p_sep_mid => 'max' , p_sep_bot=>'KB'); + scf_add_elem (l_plan2, 'ATmpSpcL', s.last_tempseg_size/1024, p_sep_mid => 'last', p_sep_bot=>'KB'); + &COMM_IF_LT_10G. if :OPT_PLAN_DETAILS = 'Y' then + &COMM_IF_LT_10G. scf_add_elem (l_plan3, 'Id', s.id, p_is_auxil => 'Y'); + &COMM_IF_LT_10G. scf_add_elem (l_plan3, 'Qb_name', s.qblock_name); + &COMM_IF_LT_10G. scf_add_elem (l_plan3, 'ObjAlias', s.object_alias); + &COMM_IF_LT_10G. scf_add_elem (l_plan3, 'ObjType', s.object_type); + &COMM_IF_LT_10G. scf_add_elem (l_plan3, 'Obj', get_cache_obj_name(s.object#)); + &COMM_IF_LT_10G. scf_add_elem (l_plan3, 'BaseObj', get_cache_obj_name(get_cache_base_table_object_id (s.object#))); + --&COMM_IF_LT_10G. scf_add_elem (l_plan3, 'Obj#', s.object#); + --&COMM_IF_LT_10G. scf_add_elem (l_plan3, 'BaseObj#', get_cache_base_table_object_id (s.object#)); + &COMM_IF_LT_10G. scf_add_elem (l_plan3, 'Projection', adapt_projection(s.projection)); + &COMM_IF_LT_10G. scf_add_elem (l_plan3, 'Remarks', s.remarks); + &COMM_IF_LT_10G. end if; + end loop; + scf_print_output (l_plan, 'no plan found.', 'only aux plan infos found.'); + + -- filter and access predicates + for id in l_id_min .. l_id_max loop + l_id_string := '.'|| to_char (id, '990'); + if l_access_predicates.exists(id) then + print (l_id_string||' - access[ '||l_access_predicates(id)||' ]'); + l_id_string := rpad ('.', length (l_id_string)); + end if; + if l_filter_predicates.exists(id) then + print (l_id_string||' - filter[ '||l_filter_predicates(id)||' ]'); + l_id_string := rpad ('.', length (l_id_string)); + end if; + end loop; + + -- VPD policies + for po in ( select object_owner, object_name, predicate, policy_function_owner, policy + from sys.gv_$vpd_policy + where inst_id = p_inst_id + and sql_hash = p_hash_value +&COMM_IF_LT_10G. and sql_id = l_sql_id + and child_number = p_child_number + order by object_owner, object_name) + loop + print('. --- - VPD POLICY on '||po.object_owner||'.'||po.object_name||' : ['||po.predicate||'] applied by function '||po.policy_function_owner||'.'||po.policy); + end loop; + + -- PX Slave SQL + if l_others.count > 0 then + print ('---- PX Slave SQL:'); + for id in l_id_min .. l_id_max loop + l_id_string := '.'|| to_char (id, '990'); + if l_others.exists(id) then + print (l_id_string||' - ['||l_others(id)||']'); + l_id_string := rpad ('.', length (l_id_string)); + end if; + end loop; + end if; + + &COMM_IF_LT_10G. ash_print_stmt_profile ( + &COMM_IF_LT_10G. p_inst_id => p_inst_id , p_sql_id => l_sql_id, + &COMM_IF_LT_10G. p_child_number => p_child_number , + &COMM_IF_LT_10G. p_first_load_time => p_first_load_time, p_last_load_time => p_last_load_time, p_last_active_time => p_last_active_time); + + scf_print_output (l_plan2, 'no plan details found.', 'only aux plan details found.', + p_note => 'note: stats Aram, A01M, 0/1/M, ActTim do not seem to be always accurate.' ); + + scf_print_output (l_plan3, '', ''); + + -- output from dbms_xplan.display_cursor + &COMM_IF_NO_DBMS_XPLAN. if l_sql_id is not null then + &COMM_IF_NO_DBMS_XPLAN. l_dbms_xplan_format := 'ADVANCED'||l_dbms_xplan_tag; + &COMM_IF_NO_DBMS_XPLAN. print ('===== dbms_xplan.display_cursor ('||l_dbms_xplan_format||'):'); + &COMM_IF_NO_DBMS_XPLAN. open l_cursor for + &COMM_IF_NO_DBMS_XPLAN. select /*+ xplan_exec_marker */ plan_table_output + &COMM_IF_NO_DBMS_XPLAN. from table (dbms_xplan.display_cursor (l_sql_id, p_child_number, l_dbms_xplan_format)); + &COMM_IF_NO_DBMS_XPLAN. loop + &COMM_IF_NO_DBMS_XPLAN. fetch l_cursor into l_tmp; + &COMM_IF_NO_DBMS_XPLAN. if l_cursor%notfound then + &COMM_IF_NO_DBMS_XPLAN. close l_cursor; + &COMM_IF_NO_DBMS_XPLAN. exit; + &COMM_IF_NO_DBMS_XPLAN. end if; + &COMM_IF_NO_DBMS_XPLAN. print (l_tmp); + &COMM_IF_NO_DBMS_XPLAN. end loop; + &COMM_IF_NO_DBMS_XPLAN. end if; + + -- print sql-level optimizer env + optim_env_print_sql_pars (p_address => p_address, p_hash_value => p_hash_value, p_child_number => p_child_number); + + -- table infos from data dictionary + if :OPT_TABINFOS = 'Y' then + declare + l_curr_id varchar2(20); + begin + l_curr_id := l_base_table_object_ids.first; + loop + exit when l_curr_id is null; + print_cache_table_infos (l_curr_id); + l_curr_id := l_base_table_object_ids.next (l_curr_id); + end loop; + end; + end if; + +end print_plan; \ No newline at end of file diff --git a/Alberto/xplan_scf_body.sql b/Alberto/xplan_scf_body.sql new file mode 100644 index 0000000..6af66cf --- /dev/null +++ b/Alberto/xplan_scf_body.sql @@ -0,0 +1,405 @@ +-------------------------------------------------------------------------------- +-- Author: Alberto Dell'Era +-- Copyright: (c) 2008-2012 Alberto Dell'Era http://www.adellera.it +-------------------------------------------------------------------------------- + +procedure scf_init_state_for ( + p_state in out nocopy scf_state_t, + p_colname varchar2, + p_is_auxil varchar2, + p_is_hidden varchar2, + p_sep_top varchar2, + p_sep_mid varchar2, + p_sep_bot varchar2, + p_is_number varchar2, + p_self_src varchar2, + p_self_is_id varchar2, + p_self_is_pid varchar2 +) +is +begin + if not p_state.col_name_to_pos.exists (p_colname) then + declare + l_col_state scf_col_state_t; + l_col_pos int; + begin + if p_is_auxil not in ('Y', 'N') or p_is_auxil is null then + raise_application_error (-20001, ' illegal p_is_auxil='||p_is_auxil); + end if; + if p_is_hidden not in ('Y', 'N') or p_is_hidden is null then + raise_application_error (-20002, ' illegal p_is_hidden='||p_is_hidden); + end if; + if p_self_is_id not in ('Y', 'N') or p_self_is_id is null then + raise_application_error (-20003, ' illegal p_self_is_id='||p_self_is_id); + end if; + if p_self_is_pid not in ('Y', 'N') or p_self_is_pid is null then + raise_application_error (-20004, ' illegal p_self_is_pid='||p_self_is_pid); + end if; + l_col_pos := p_state.numcols; + p_state.col_name_to_pos (p_colname) := l_col_pos; + l_col_state.is_auxil := p_is_auxil; + l_col_state.is_hidden := p_is_hidden; + l_col_state.sep_top := p_sep_top; + l_col_state.colname := p_colname; + l_col_state.sep_mid := p_sep_mid; + l_col_state.sep_bot := p_sep_bot; + l_col_state.is_number := p_is_number; + l_col_state.self_src := p_self_src; + p_state.cols(l_col_pos) := l_col_state; + if p_self_is_id = 'Y' then + p_state.self_col_pos_id := l_col_pos; + end if; + if p_self_is_pid = 'Y' then + p_state.self_col_pos_pid := l_col_pos; + end if; + p_state.numcols := p_state.numcols + 1; + end; + end if; +end scf_init_state_for; + +-- overloaded on "p_rowval" +procedure scf_add_elem ( + p_state in out nocopy scf_state_t, + p_colname varchar2, + p_rowval varchar2, + p_is_auxil varchar2 default 'N', + p_is_hidden varchar2 default 'N', + p_sep_top varchar2 default null, + p_sep_mid varchar2 default null, + p_sep_bot varchar2 default null +) +is + l_col_pos int; +begin + scf_init_state_for (p_state, p_colname, p_is_auxil, p_is_hidden, p_sep_top, p_sep_mid, p_sep_bot, 'N', null, 'N' /* string cannot be id */, 'N' ); + l_col_pos := p_state.col_name_to_pos (p_colname); + p_state.cols(l_col_pos).rows_v( p_state.cols(l_col_pos).rows_v.count ) := rtrim (p_rowval); +end scf_add_elem; + +procedure scf_add_elem ( + p_state in out nocopy scf_state_t, + p_colname varchar2, + p_rowval number, + p_is_auxil varchar2 default 'N', + p_is_hidden varchar2 default 'N', + p_sep_top varchar2 default null, + p_sep_mid varchar2 default null, + p_sep_bot varchar2 default null, + p_self_is_id varchar2 default 'N', + p_self_is_pid varchar2 default 'N' +) +is + l_col_pos int; +begin + scf_init_state_for (p_state, p_colname, p_is_auxil, p_is_hidden, p_sep_top, p_sep_mid, p_sep_bot, 'Y', null, p_self_is_id, p_self_is_pid); + l_col_pos := p_state.col_name_to_pos (p_colname); + p_state.cols(l_col_pos).rows_n( p_state.cols(l_col_pos).rows_n.count ) := p_rowval; +end scf_add_elem; + +procedure scf_add_self ( + p_state in out nocopy scf_state_t, + p_colname varchar2, + p_self_src varchar2 default null +) +is + l_col_pos int; + l_col_state_src scf_col_state_t; +begin + -- copy info from src column + l_col_state_src := p_state.cols ( p_state.col_name_to_pos (p_self_src) ); + scf_init_state_for (p_state, p_colname, 'Y', 'N', l_col_state_src.sep_top, l_col_state_src.sep_mid, l_col_state_src.sep_bot, 'Y', p_self_src, 'N', 'N'); + -- set row to null + l_col_pos := p_state.col_name_to_pos (p_colname); + p_state.cols(l_col_pos).rows_n( p_state.cols(l_col_pos).rows_n.count ) := to_number(null); +end scf_add_self; + +procedure scf_prepare_output (p_state in out nocopy scf_state_t) +is + l_num_rows int; + l_number_fmt varchar2(40 char) := 'FM9,999,999,999,999,999,999,999,990'; +begin + p_state.numcols_not_empty := 0; + p_state.num_notaux_cols_not_empty := 0; + + if p_state.numcols = 0 then + return; + end if; + + -- adapt number format + if :OPT_NUMBER_COMMAS = 'N' then + l_number_fmt := replace(l_number_fmt, ',', ''); + end if; + + -- set l_num_rows + if p_state.cols(0).is_number = 'Y' then + l_num_rows := p_state.cols(0).rows_n.count; + else + l_num_rows := p_state.cols(0).rows_v.count; + end if; + + -- sanity check: check that all cols have the same number of rows + declare + l_num_rows_curr int; + begin + for c in 1 .. p_state.cols.count-1 loop + if p_state.cols(c).is_number = 'Y' then + l_num_rows_curr := p_state.cols(c).rows_n.count; + else + l_num_rows_curr := p_state.cols(c).rows_v.count; + end if; + if l_num_rows_curr != l_num_rows then + raise_application_error (-20001, 'num rows of first column "'||p_state.cols(0).colname + ||'" and column "'||p_state.cols(c).colname||'" differ.'); + end if; + end loop; + end; + + -- calc self columns + for c in 0 .. p_state.cols.count-1 loop + if p_state.cols(c).self_src is not null then + declare + l_pos_src int := p_state.col_name_to_pos (p_state.cols(c).self_src); + l_pid number; + l_p_row number; + l_is_empty varchar2(1) := 'Y'; + begin + -- build self global structures if not built yet + if p_state.self_id_to_row.count = 0 then + for r in 0 .. l_num_rows-1 loop + p_state.self_id_to_row( p_state.cols(p_state.self_col_pos_id).rows_n(r) ) := r; + p_state.self_pid_is_leaf(r) := 'Y'; + end loop; + for r in 0 .. l_num_rows-1 loop + l_pid := p_state.cols(p_state.self_col_pos_pid).rows_n(r); + if l_pid is not null then + p_state.self_pid_is_leaf( p_state.self_id_to_row( l_pid ) ) := 'N'; + end if; + end loop; + end if; + + -- copy source value, check if col is completely empty + for r in 0 .. l_num_rows-1 loop + p_state.cols(c).rows_n(r) := p_state.cols(l_pos_src).rows_n(r); + if l_is_empty = 'Y' and p_state.cols(c).rows_n(r) != 0 then + l_is_empty := 'N'; + end if; + end loop; + + if l_is_empty = 'N' then + -- subtract value from parent + for r in 0 .. l_num_rows-1 loop + l_pid := p_state.cols(p_state.self_col_pos_pid).rows_n(r); + if l_pid is not null then + l_p_row := p_state.self_id_to_row( l_pid ); + p_state.cols(c).rows_n(l_p_row) := p_state.cols(c).rows_n(l_p_row) + - p_state.cols(l_pos_src).rows_n( r ); + end if; + end loop; + else + -- set all rows to null + for r in 0 .. l_num_rows-1 loop + p_state.cols(c).rows_n(r) := to_number(null); + end loop; + end if; + end; + end if; + end loop; + + -- format number; remove useless decimal parts + for c in 0 .. p_state.cols.count-1 loop + if p_state.cols(c).is_number = 'Y' then + declare + l_fmt varchar2(40 char) := l_number_fmt; + l_var varchar2(40 char); + begin + -- add leading sign if self column + if p_state.cols(c).self_src is not null then + l_fmt := 'S' || l_fmt; + end if; + + -- change format if number has a decimal part + for r in 0 .. l_num_rows-1 loop + if p_state.cols(c).rows_n(r) != trunc( p_state.cols(c).rows_n(r) ) + then + l_fmt := l_fmt || '.0'; + exit; + end if; + end loop; + + for r in 0 .. l_num_rows-1 loop + l_var := to_char( round(p_state.cols(c).rows_n(r), 1) , l_fmt) ; + -- special display for self column + if p_state.cols(c).self_src is not null then + if p_state.self_pid_is_leaf(r) = 'Y' then + l_var := replace( l_var, '+', null ); + else + if l_var = '+0' then + l_var := '='; + end if; + end if; + end if; + p_state.cols(c).rows_v(r) := l_var; + end loop; + end; + end if; + end loop; + + + for c in 0 .. p_state.cols.count-1 loop + declare + l_curr_max_length int := 0; + begin + -- calc max row length (set to zero for hidden columns) + if p_state.cols(c).is_hidden = 'Y' then + l_curr_max_length := 0; + else + for r in 0 .. l_num_rows-1 loop + declare + l_curr_row_lenght int := nvl(length (p_state.cols(c).rows_v(r)), 0); + begin + if l_curr_row_lenght > l_curr_max_length then + l_curr_max_length := l_curr_row_lenght; + end if; + end; + end loop; + end if; + -- set all column rows to '' if no info is contained + if l_curr_max_length = 0 then + --print ('col #'||c||' is empty'); + p_state.cols(c).sep_top := ''; + p_state.cols(c).colname := ''; + p_state.cols(c).sep_mid := ''; + p_state.cols(c).sep_bot := ''; + else + p_state.numcols_not_empty := p_state.numcols_not_empty + 1; + -- this is calc in order to ignore auxiliary columns (such as 'Id') + if p_state.cols(c).is_auxil = 'N' then + p_state.num_notaux_cols_not_empty := p_state.num_notaux_cols_not_empty + 1; + end if; + end if; + -- calc max row length, separators and colname included + l_curr_max_length := greatest ( + nvl (length (p_state.cols(c).sep_top), 0), + nvl (length (p_state.cols(c).colname), 0), + nvl (length (p_state.cols(c).sep_mid), 0), + nvl (length (p_state.cols(c).sep_bot), 0), + l_curr_max_length + ); + + --print ('col #'||c||' max length='||l_curr_max_length); + -- set separators, colname and rows to same (max) length + p_state.cols(c).sep_top := rpad ( nvl(p_state.cols(c).sep_top, '-'), l_curr_max_length, '-'); + p_state.cols(c).colname := rpad ( nvl(p_state.cols(c).colname, ' '), l_curr_max_length, ' '); + p_state.cols(c).sep_mid := rpad ( nvl(p_state.cols(c).sep_mid, '-'), l_curr_max_length, '-'); + p_state.cols(c).sep_bot := rpad ( nvl(p_state.cols(c).sep_bot, '-'), l_curr_max_length, '-'); + for r in 0 .. l_num_rows-1 loop + declare + l_curr_row_lenght int := length (p_state.cols(c).rows_v(r)); + begin + if p_state.cols(c).is_number = 'Y' then + p_state.cols(c).rows_v(r) := lpad ( nvl(p_state.cols(c).rows_v(r), ' '), l_curr_max_length, ' '); + else + p_state.cols(c).rows_v(r) := rpad ( nvl(p_state.cols(c).rows_v(r), ' '), l_curr_max_length, ' '); + end if; + --print ('"'||p_state.cols(c).rows_v(r)||'"'); + end; + end loop; + end; + end loop; + +end scf_prepare_output; + +procedure scf_print_output ( + p_state in out nocopy scf_state_t, + p_no_info_msg varchar2, + p_no_not_aux_info_msg varchar2, + p_note varchar2 default null) +is + l_line varchar2(2000 char); +begin + scf_prepare_output (p_state); + + if p_state.numcols_not_empty = 0 then + print (p_no_info_msg); + return; + end if; + + if p_state.num_notaux_cols_not_empty = 0 then + print (p_no_not_aux_info_msg); + return; + end if; + + -- print top separator + l_line := '-'; + for c in 0 .. p_state.cols.count-1 loop + if p_state.cols(c).sep_top is not null then + l_line := l_line || p_state.cols(c).sep_top || '-'; + end if; + end loop; + print (l_line); + + -- print colnames + l_line := '|'; + for c in 0 .. p_state.cols.count-1 loop + if p_state.cols(c).colname is not null then + l_line := l_line || p_state.cols(c).colname || '|'; + end if; + end loop; + print (l_line); + + -- print middle separator + l_line := '-'; + for c in 0 .. p_state.cols.count-1 loop + if p_state.cols(c).sep_mid is not null then + l_line := l_line || p_state.cols(c).sep_mid || '-'; + end if; + end loop; + print (l_line); + + -- print rows + for r in 0 .. p_state.cols(0).rows_v.count-1 loop + l_line := '|'; + for c in 0 .. p_state.cols.count-1 loop + if p_state.cols(c).rows_v(r) is not null then + l_line := l_line || p_state.cols(c).rows_v(r) || '|'; + end if; + end loop; + print (l_line); + end loop; + + -- print bottom separator + l_line := '-'; + for c in 0 .. p_state.cols.count-1 loop + if p_state.cols(c).sep_bot is not null then + l_line := l_line || p_state.cols(c).sep_bot || '-'; + end if; + end loop; + print (l_line); + + if trim(p_note) is not null then + print (p_note); + end if; + +end scf_print_output; + +procedure scf_reset (p_state out scf_state_t) +is + l_state scf_state_t; +begin + p_state := l_state; +end scf_reset; + +procedure scf_test +is + l_plan scf_state_t; +begin + scf_add_elem (l_plan, 'id', 1, 'top', 'middle', 'bottom'); + scf_add_elem (l_plan, 'Operation', 'TABLE ACCESS BY INDEX ROWID','','middle_op'); + scf_add_elem (l_plan, 'id', 2.11); + scf_add_elem (l_plan, 'Operation', 'INDEX RANGE SCAN'); + scf_add_elem (l_plan, 'id', to_number(null)); + scf_add_elem (l_plan, 'Operation', ''); + + scf_print_output (l_plan, 'no plan found.', 'only aux plan infos found.'); +end scf_test; + diff --git a/Alberto/xplan_scf_vars.sql b/Alberto/xplan_scf_vars.sql new file mode 100644 index 0000000..9e076fe --- /dev/null +++ b/Alberto/xplan_scf_vars.sql @@ -0,0 +1,37 @@ +-------------------------------------------------------------------------------- +-- Author: Alberto Dell'Era +-- Copyright: (c) 2008, 2009, 2012 Alberto Dell'Era http://www.adellera.it +-------------------------------------------------------------------------------- + +type scf_array_of_varchar2_t is table of varchar2(1000 char) index by binary_integer; +type scf_array_of_number_t is table of number index by binary_integer; +type scf_hash_of_varchar2_to_num_t is table of number index by varchar2(30); + +type scf_col_state_t is record ( + sep_top varchar2(1000 char), -- separator: top + colname varchar2(1000 char), -- column name + is_auxil varchar2(1 char), -- Y=is auxiliary (print nothing if all non-auxiliary are empty) + is_hidden varchar2(1 char), -- Y=is hidden + sep_mid varchar2(1000 char), -- separator: middle + sep_bot varchar2(1000 char), -- separator: bottom + is_number varchar2(1 char), -- Y=is number + self_src varchar2(1000 char), -- null if not self column; otherwise name of source column + rows_v scf_array_of_varchar2_t, -- row values - varchar2 + rows_n scf_array_of_number_t -- row values - number +); + +type scf_array_of_col_state_t is table of scf_col_state_t index by binary_integer; + +type scf_state_t is record ( + numcols int := 0, + numcols_not_empty int := null, + num_notaux_cols_not_empty int := null, + col_name_to_pos scf_hash_of_varchar2_to_num_t, + cols scf_array_of_col_state_t, + self_col_pos_id int := null, + self_col_pos_pid int := null, + self_id_to_row scf_array_of_number_t, + self_pid_is_leaf scf_array_of_varchar2_t +); + + diff --git a/Alberto/xplan_showcase.sql b/Alberto/xplan_showcase.sql new file mode 100644 index 0000000..c89b932 --- /dev/null +++ b/Alberto/xplan_showcase.sql @@ -0,0 +1,80 @@ +-------------------------------------------------------------------------------- +-- Author: Alberto Dell'Era +-- Copyright: (c) 2008, 2009 Alberto Dell'Era http://www.adellera.it +-------------------------------------------------------------------------------- + +set termout on echo on + +drop table child purge; +drop table t purge; +drop table parent purge; + +-- table parent +create table parent (rr varchar2(1) primary key); +insert into parent(rr) values ('x'); + +-- table t +create table t (x, padding, rr, constraint t_pk primary key (x,padding)) +organization index +overflow +partition by range (x, padding) +--subpartition by hash (padding, x) subpartitions 2 +( + partition p1 values less than (100,'A'), + partition p2 values less than (200,'B'), + partition pother values less than (maxvalue,maxvalue) +) +as +select rownum x, rpad(rownum, 300,'x') padding, rpad('x',1) rr from dual connect by level <= 1000; + +create or replace view v as +select x, padding, rr + from t + where x > 0; + +create or replace function plsql_func (p varchar2) +return varchar2 +is +begin + return p; +end plsql_func; +/ +disassociate statistics from functions plsql_func; +associate statistics with functions plsql_func default selectivity 0.001, default cost (100,10,1); + +alter table t add constraint t_uq_1 unique (padding); +alter table t add constraint t_uq_2 unique (padding,x); +alter table t add constraint t_parent_fk foreign key (rr) references parent(rr); + +create index t_idx on t(padding, x) local; +create index t_fbi on t(x, upper(x), padding) local; +create index t_fbi2 on t(x, case when x = 0 then 'pippo' when x = 1 then 'uuiio' when x = 3 then 'uuciio' when x = 4 then 'uuieio' else 'pppppp' end ); + +exec dbms_stats.gather_table_stats (user,'t',cascade=>true, method_opt=>'for all columns size 254', estimate_percent=>null, granularity=>'ALL'); + +-- table child +create table child (padding varchar2(3 char), constraint child_t_fk foreign key (padding) references t(padding)); + +alter session set statistics_level=all; +alter system flush shared_pool; +alter system flush buffer_cache; + +--define SQL_TEST="select /*+ parallel(t,2) parallel_index(t,2) xplan_test_marker */ x,max(padding) from t where abs(x) = 2 and upper(x) = 2 and lower(x) = 2 and x*5=43 and x*4=43 and x*3=43 and x*2 = 43 group by x order by x" +define SQL_TEST="select /*+ index(t,t_fbi) ordered use_nl(v) xplan_test_marker */ t.rr, plsql_func(max(t.x)) from t, v where upper(t.x) >= '0' and t.x > l_y and v.rr ='x' group by t.rr order by t.rr" + +alter session set workarea_size_policy=manual; +alter session set hash_area_size=2000000; +alter session set sort_area_size=2000000; + +alter session set events '10046 trace name context forever, level 12'; + +declare l_x number := 0; l_y number := 0; +begin /* xplan_exec_marker sga_xplan_exec */ for r in (&SQL_TEST.) loop + null; + end loop; +end; +/ + +alter session set events '10046 trace name context off'; + +@xplan "%xplan_test_marker%" "plan_stats= last,access_predicates=Y,lines=150,module=,action=,dbms_xplan=n,plan_details=y,plan_env=y,tabinfos=y" diff --git a/Alberto/xplan_tabinfos_body.sql b/Alberto/xplan_tabinfos_body.sql new file mode 100644 index 0000000..33dcad9 --- /dev/null +++ b/Alberto/xplan_tabinfos_body.sql @@ -0,0 +1,714 @@ +-------------------------------------------------------------------------------- +-- Author: Alberto Dell'Era +-- Copyright: (c) 2008, 2009, 2013 Alberto Dell'Era http://www.adellera.it +-------------------------------------------------------------------------------- + +/* +type ref_object_t is record ( + object_id int, + object_type varchar2(30 char), + object_owner varchar2(30 char), + object_name varchar2(30 char), + base_table_object_id int, + base_table_owner varchar2(30 char), + base_table_name varchar2(30 char) +); */ + +function calc_base_table_object_id (p_object_id int) +return int +is +begin + -- N.B. Even for partitioned tables accessed with FROM T PARTITION(P), + -- gv$sql_plan.object# is always the object_id of the table, not the partition. + -- Same for partitioned indexes. + for o in (select /*+ xplan_exec_marker */ owner, object_name, object_type + from sys.all_objects + where object_id = p_object_id) + loop + if o.object_type = 'TABLE' then + return p_object_id; + elsif o.object_type in ('SEQUENCE', 'VIEW') then + return null; + elsif o.object_type in ('INDEX') then + for o2 in (select /*+ xplan_exec_marker */ table_owner, table_name + from sys.all_indexes + where owner = o.owner + and index_name = o.object_name) + loop + for o3 in (select /*+ xplan_exec_marker */ object_id + from sys.all_objects + where object_type = 'TABLE' + and owner = o2.table_owner + and object_name = o2.table_name) + loop + return o3.object_id; + end loop; + end loop; + end if; + end loop; + + return null; +end calc_base_table_object_id; + +function get_cache_base_table_object_id (p_object_id int) +return int +is +begin + if p_object_id is null then + return null; + end if; + if not m_cache_base_table_object_id.exists(to_char(p_object_id)) then + m_cache_base_table_object_id(to_char(p_object_id)) := calc_base_table_object_id (to_char(p_object_id)); + end if; + return to_number(m_cache_base_table_object_id (to_char(p_object_id))); +end get_cache_base_table_object_id; + +procedure cache_obj_infos (p_object_id int) +is +begin + if not m_cache_obj_infos.exists (to_char(p_object_id)) then + declare + l_obj_infos obj_infos_t; + begin + l_obj_infos.object_type := 'obj#'||p_object_id; + l_obj_infos.owner := 'obj#'||p_object_id; + l_obj_infos.object_name := 'obj#'||p_object_id; + for r in (select /*+ xplan_exec_marker */ owner, object_name, object_type + from sys.all_objects + where object_id = p_object_id) + loop + --if r.object_type <> 'TABLE' then + -- raise_application_error (-20001, 'object_id="'||p_object_id||'" is of type "'||r.object_type||'", not TABLE.'); + --end if; + l_obj_infos.object_type := r.object_type; + l_obj_infos.owner := r.owner; + l_obj_infos.object_name := r.object_name; + end loop; + m_cache_obj_infos(to_char(p_object_id)) := l_obj_infos; + end; + end if; +end cache_obj_infos; + +function get_cache_obj_name (p_object_id int) +return varchar2 +is +begin + if p_object_id is null then + return null; + end if; + cache_obj_infos (p_object_id); + return m_cache_obj_infos(to_char(p_object_id)).object_name; +end get_cache_obj_name; + +function get_cache_obj_owner (p_object_id int) +return varchar2 +is +begin + if p_object_id is null then + return null; + end if; + cache_obj_infos (p_object_id); + return m_cache_obj_infos(to_char(p_object_id)).owner; +end get_cache_obj_owner; + +function get_virtual_col_expr ( + p_table_owner varchar2, + p_table_name varchar2, + p_virt_col_name varchar2 +) +return varchar2 +is + l_ret long; +begin + -- try FBI expression + for i in (select /*+ xplan_exec_marker */ index_owner, index_name, column_position + from sys.all_ind_columns + where table_owner = p_table_owner and table_name = p_table_name + and column_name = p_virt_col_name) + loop + for e in (select /*+ xplan_exec_marker */ column_expression + from sys.all_ind_expressions + where table_owner = p_table_owner and table_name = p_table_name + and index_owner = i.index_owner and index_name = i.index_name + and column_position = i.column_position) + loop + if l_ret != e.column_expression then + return 'INTERNAL ERROR conflicting virtual col defs found for'||p_virt_col_name; + end if; + if l_ret is null then + l_ret := e.column_expression; + end if; + end loop; + end loop; + l_ret := 'I:' || l_ret; + + -- try multi-column expression + &COMM_IF_LT_11G if l_ret is null then + &COMM_IF_LT_11G. for e in (select /*+ xplan_exec_marker */ extension + &COMM_IF_LT_11G. from sys.all_stat_extensions + &COMM_IF_LT_11G. where owner = p_table_owner and table_name = p_table_name + &COMM_IF_LT_11G. and extension_name = p_virt_col_name) + &COMM_IF_LT_11G. loop + &COMM_IF_LT_11G. l_ret := 'E:'|| e.extension; + &COMM_IF_LT_11G. end loop; + &COMM_IF_LT_11G. end if; + return l_ret; +end get_virtual_col_expr; + +function get_part_key_list ( + p_owner varchar2, + p_name varchar2, + p_object_type varchar2 +) +return varchar2 +is + l_ret varchar2(500 char); +begin + for r in (select /*+ xplan_exec_marker */ column_name + from sys.all_part_key_columns + where owner = p_owner + and name = p_name + and object_type = p_object_type + order by column_position) + loop + l_ret := l_ret || r.column_name || ', '; + end loop; + return rtrim (l_ret, ', '); +end get_part_key_list; + +function get_subpart_key_list ( + p_owner varchar2, + p_name varchar2, + p_object_type varchar2 +) +return varchar2 +is + l_ret varchar2(500 char); +begin + for r in (select /*+ xplan_exec_marker */ column_name + from sys.all_subpart_key_columns + where owner = p_owner + and name = p_name + and object_type = p_object_type + order by column_position) + loop + l_ret := l_ret || r.column_name || ', '; + end loop; + return rtrim (l_ret, ', '); +end get_subpart_key_list; + +procedure print_table_infos (p_object_id int) +is + type t_prog_number is table of binary_integer index by varchar2(61 char); + l_index_number t_prog_number; + l_cons_u_number t_prog_number; + l_cons_r_number t_prog_number; + l_cons_r2_number t_prog_number; + type t_virt_expressions is table of varchar2(2000 char) index by varchar2(30 char); + l_virt_expressions t_virt_expressions; + l_table_owner varchar2(30) := get_cache_obj_owner (p_object_id); + l_table_name varchar2(30) := get_cache_obj_name (p_object_id); + l_scf scf_state_t; + l_iot_type sys.all_tables.iot_type%type; + l_partitioned sys.all_tables.partitioned%type; + l_temporary sys.all_tables.temporary%type; + l_duration sys.all_tables.duration%type; + l_tmp long; + l_tmp2 varchar2(1 char); + l_data_mod varchar2(100 char); + l_num_rows number; + l_columns_names_inited boolean; +begin + -- label each index with a progressive number + for i in (select /*+ xplan_exec_marker */ + owner index_owner, index_name + from sys.all_indexes + where table_owner = l_table_owner and table_name = l_table_name + order by index_name, owner -- keep this row aligned with rows labeled as "block b001" + ) + loop + l_index_number(i.index_owner||'.'||i.index_name) := l_index_number.count; + end loop; + -- label each unique/reference constraint with a progressive number + -- UQ and from-this-table-to-others FK + for co in (select /*+ xplan_exec_marker */ constraint_name, constraint_type + from sys.all_constraints + where owner = l_table_owner and table_name = l_table_name + and constraint_type in ('U','R') + order by decode (constraint_type,'P',1,'U',2,'R',3), constraint_name -- keep this row aligned with rows labeled as "block b003" + ) + loop + if co.constraint_type = 'U' then + l_cons_u_number (co.constraint_name) := l_cons_u_number.count; + elsif co.constraint_type = 'R' then + l_cons_r_number (co.constraint_name) := l_cons_r_number.count; + end if; + end loop; + + --------------- table --------------- + print ('############################################# table '||l_table_owner||'.'||l_table_name||' ###'); + + begin + select iot_type, partitioned, temporary, duration, num_rows + into l_iot_type, l_partitioned, l_temporary, l_duration, l_num_rows + from sys.all_tables + where owner = l_table_owner and table_name = l_table_name; + exception + when no_data_found then + print (l_table_owner||'.'||l_table_name||' not found in all_tables.'); + return; + end; + + if l_temporary = 'Y' then + print ('GLOBAL TEMPORARY TABLE on commit '|| case when l_duration = 'SYS$SESSION' then 'PRESERVE' else 'delete' end ||' rows'); + end if; + + if l_partitioned='YES' then + for r in (select /*+ xplan_exec_marker */ partitioning_type, subpartitioning_type + from sys.all_part_tables + where owner = l_table_owner and table_name = l_table_name) + loop + print ('PARTITIONED BY '||r.partitioning_type||' ( '||get_part_key_list(l_table_owner,l_table_name,'TABLE')||' ) '); + if r.subpartitioning_type<>'NONE' then + print ( 'SUBPARTITIONED BY '||r.subpartitioning_type||' ( '||get_subpart_key_list(l_table_owner,l_table_name,'TABLE')||' ) '); + end if; + end loop; + end if; + print (l_iot_type); + + -- dbms_metadata.get_ddl for table + &COMM_IF_NO_DBMS_METADATA. print('---- output of dbms_metadata.get_ddl ----'); + &COMM_IF_NO_DBMS_METADATA. print_clob( dbms_metadata.get_ddl( 'TABLE', l_table_name, l_table_owner) ); + + -- columns + scf_reset (l_scf); + l_virt_expressions.delete; + for c in (select /*+ xplan_exec_marker */ column_id, internal_column_id, column_name, nullable, + data_type, data_length, data_precision, data_scale, + char_used, char_length, hidden_column, virtual_column + from sys.all_tab_cols + where owner = l_table_owner and table_name = l_table_name + order by column_id, internal_column_id -- keep this row aligned with rows labeled as "block b002" + ) + loop + l_data_mod := ''; + if c.data_type in ('NUMBER') then + if c.data_precision is not null or c.data_scale is not null then + l_data_mod := ' ('||nvl(c.data_precision,38)||','||c.data_scale||')'; + end if; + elsif c.data_type in ('FLOAT') then + l_data_mod := ' ('||c.data_precision||')'; + -- VARCHAR2, NVARCHAR2, CHAR, NCHAR are the only types that can have CHAR length semantics + elsif c.data_type in ('VARCHAR2', 'VARCHAR', 'NVARCHAR2', 'NVARCHAR', 'CHAR', 'NCHAR') then + if c.char_used = 'C' then + l_data_mod := ' ('||c.char_length||' char)'; + else + l_data_mod := ' ('||c.data_length||' byte)'; + end if; + elsif c.data_type in ('RAW') then + l_data_mod := ' ('||c.data_length||')'; + end if; + scf_add_elem (l_scf, 'Id' , c.column_id); + scf_add_elem (l_scf, 'IId' , c.internal_column_id); + scf_add_elem (l_scf, 'V' , case when c.virtual_column = 'NO' then 'N' else 'Y' end); + scf_add_elem (l_scf, 'ColName', c.column_name); + scf_add_elem (l_scf, 'Type' , c.data_type||l_data_mod); + scf_add_elem (l_scf, 'Null' , case when c.nullable = 'N' then 'NOT' else 'yes' end); + if c.virtual_column ='YES' then + l_tmp := get_virtual_col_expr (l_table_owner, l_table_name, c.column_name); + l_virt_expressions (c.column_name) := l_tmp; + else + l_tmp := null; + end if; + scf_add_elem (l_scf, 'Expression', substr (l_tmp, 1, 10), p_sep_mid => 'trunc' ); + end loop; + -- add to each indexed column a pointer to indexing index (via index#) + for i in (select /*+ xplan_exec_marker */ + owner index_owner, index_name, uniqueness + from sys.all_indexes + where table_owner = l_table_owner and table_name = l_table_name + order by index_name, owner -- keep this row aligned with rows labeled as "block b001" + ) + loop + l_tmp := to_char(l_index_number(i.index_owner||'.'||i.index_name)); + for r in (select /*+ xplan_exec_marker */ ic.column_position + from sys.all_tab_cols c, sys.all_ind_columns ic + where c.owner = l_table_owner and c.table_name = l_table_name + and c.column_name = ic.column_name(+) + and ic.table_owner(+) = l_table_owner and ic.table_name(+) = l_table_name + and ic.index_owner(+) = i.index_owner and ic.index_name(+) = i.index_name + order by c.column_id, c.internal_column_id -- keep this row aligned with rows labeled as "block b002" + ) + loop + scf_add_elem (l_scf, l_tmp, r.column_position, p_sep_mid => case when i.uniqueness='UNIQUE' then 'U' end); + end loop; + end loop; + + -- al new + scf_print_output (l_scf, 'INTERNAL ERROR : no columns infos found', 'INTERNAL ERROR : no columns infos found(aux)'); + scf_reset (l_scf); + + l_columns_names_inited := false; + + -- add to each constrained column a label marking it as constrained + -- 1) UQ and from-this-table-to-others FK + for co in (select /*+ xplan_exec_marker */ constraint_name, constraint_type + from sys.all_constraints + where owner = l_table_owner and table_name = l_table_name + and constraint_type in ('P','U','R') + order by decode (constraint_type,'P',1,'U',2,'R',3), constraint_name -- keep this row aligned with rows labeled as "block b003" + ) + loop + if co.constraint_type = 'P' then + l_tmp := 'P'; + elsif co.constraint_type = 'U' then + l_tmp := 'U'||to_char(l_cons_u_number (co.constraint_name)); + elsif co.constraint_type = 'R' then + l_tmp := 'R'||to_char(l_cons_r_number (co.constraint_name)); + end if; + -- mark every PK/FK constraint with at least a FK from another table to the current one + l_tmp2 := ''; + if co.constraint_type in ('P','U') then + for r in (select constraint_name + from sys.all_constraints + where constraint_type = 'R' + and r_owner = l_table_owner and r_constraint_name = co.constraint_name + and rownum = 1 + ) + loop + -- dbms_output.put_line ('on '||co.constraint_name||' fk from '||r.constraint_name); + l_tmp2 := 'R'; + end loop; + end if; + for c in (select /*+ xplan_exec_marker */ c.column_id, c.internal_column_id, c.virtual_column, c.column_name, cc.position + from sys.all_tab_cols c, sys.all_cons_columns cc + where c.owner = l_table_owner and c.table_name = l_table_name + and c.column_name = cc.column_name(+) + and cc.owner(+) = l_table_owner and cc.table_name(+) = l_table_name + and cc.constraint_name(+) = co.constraint_name + order by c.column_id, c.internal_column_id -- keep this row aligned with rows labeled as "block b002" + ) + loop + if not l_columns_names_inited then + scf_add_elem (l_scf, 'Id' , c.column_id); + scf_add_elem (l_scf, 'IId' , c.internal_column_id); + scf_add_elem (l_scf, 'V' , case when c.virtual_column = 'NO' then 'N' else 'Y' end); + scf_add_elem (l_scf, 'ColName', c.column_name); + end if; + scf_add_elem (l_scf, l_tmp, case when c.position is null then null else l_tmp2||c.position end); + end loop; + l_columns_names_inited := true; + end loop; + + if l_columns_names_inited then + scf_print_output (l_scf, 'INTERNAL ERROR : no columns infos found', 'INTERNAL ERROR : no columns infos found(cons)'); + end if; + + -- virtual column expressions + if l_virt_expressions.count > 0 then + scf_reset (l_scf); + declare + l_colname varchar2(30); + begin + l_colname := l_virt_expressions.first; + loop + exit when l_colname is null; + scf_add_elem (l_scf, 'ColName', l_colname); + scf_add_elem (l_scf, 'Expression (full)', l_virt_expressions(l_colname) ); + l_colname := l_virt_expressions.next (l_colname); + end loop; + end; + scf_print_output (l_scf, 'INTERNAL ERROR: no virt expression found', 'INTERNAL ERROR: no virt expression found(aux)'); + end if; + + scf_reset (l_scf); + + for r in (select /*+ xplan_exec_marker */ + '1' typ, cast(null as number) partition_position, null as partition_name, cast(null as number) subpartition_position, null as subpartition_name, + num_rows, blocks, empty_blocks, avg_row_len, sample_size, last_analyzed, degree + from sys.all_tables + where owner = l_table_owner and table_name = l_table_name + union all + select '2' typ, partition_position, partition_name, null as subpartition_position, null as subpartition_name, + num_rows, blocks, empty_blocks, avg_row_len, sample_size, last_analyzed, null as degree + from sys.all_tab_partitions + where table_owner = l_table_owner and table_name = l_table_name + and :OPT_PARTINFOS = 'Y' + union all + select '3' typ, p.partition_position, s.partition_name, s.subpartition_position, s.subpartition_name, + s.num_rows, s.blocks, s.empty_blocks, s.avg_row_len, s.sample_size, s.last_analyzed, null as degree + from sys.all_tab_subpartitions s, sys.all_tab_partitions p + where s.table_owner = l_table_owner and s.table_name = l_table_name + and p.table_owner = l_table_owner and p.table_name = l_table_name + and s.partition_name = p.partition_name + and :OPT_PARTINFOS = 'Y' + order by typ, partition_position, subpartition_position + ) + loop + scf_add_elem (l_scf, 'Pid' , r.partition_position); + scf_add_elem (l_scf, 'Partition' , r.partition_name); + scf_add_elem (l_scf, 'SPid' , r.subpartition_position); + scf_add_elem (l_scf, 'SubPart' , r.subpartition_name); + scf_add_elem (l_scf, 'num_rows' , r.num_rows); + scf_add_elem (l_scf, 'blocks' , r.blocks); + scf_add_elem (l_scf, 'empty_blocks' , r.empty_blocks); + scf_add_elem (l_scf, 'avg_row_len' , r.avg_row_len); + scf_add_elem (l_scf, 'sample_size' , r.sample_size); + scf_add_elem (l_scf, 'last_analyzed', nvl(d2s (r.last_analyzed),'* null *')); + scf_add_elem (l_scf, 'parallel' , r.degree); + end loop; + scf_print_output (l_scf, 'INTERNAL ERROR : no table infos found', 'INTERNAL ERROR : no table infos found(aux)'); + if :OPT_PARTINFOS='N' and l_partitioned='YES' then + print ( 'WARNING: (sub)partitions infos not printed.'); + end if; + + -- column statistics + scf_reset (l_scf); + for r in (select /*+ xplan_exec_marker */ + '1' typ, column_id, internal_column_id, column_name, cast(null as number) partition_position, null as partition_name, cast(null as number) subpartition_position, null as subpartition_name, + num_distinct, density, num_nulls, num_buckets, avg_col_len, sample_size, last_analyzed + &COMM_IF_LT_10G. , histogram + from sys.all_tab_cols + where owner = l_table_owner and table_name = l_table_name + union all + select '2' typ, c.column_id, c.internal_column_id, c.column_name, p.partition_position, pcs.partition_name, null as subpartition_position, null as subpartition_name, + pcs.num_distinct, pcs.density, pcs.num_nulls, pcs.num_buckets, pcs.avg_col_len, pcs.sample_size, pcs.last_analyzed + &COMM_IF_LT_10G. , pcs.histogram + from sys.all_part_col_statistics pcs, sys.all_tab_cols c, sys.all_tab_partitions p + where pcs.owner = l_table_owner and pcs.table_name = l_table_name + and c.owner = l_table_owner and c.table_name = l_table_name + and p.table_owner = l_table_owner and p.table_name = l_table_name + and pcs.column_name = c.column_name + and pcs.partition_name = p.partition_name + and :OPT_PARTINFOS = 'Y' + union all + select '3' typ, c.column_id, c.internal_column_id, c.column_name, p.partition_position, p.partition_name, s.subpartition_position, s.subpartition_name, + scs.num_distinct, scs.density, scs.num_nulls, scs.num_buckets, scs.avg_col_len, scs.sample_size, scs.last_analyzed + &COMM_IF_LT_10G. , scs.histogram + from sys.all_subpart_col_statistics scs, sys.all_tab_cols c, sys.all_tab_subpartitions s, sys.all_tab_partitions p + where scs.owner = l_table_owner and scs.table_name = l_table_name + and c.owner = l_table_owner and c.table_name = l_table_name + and s.table_owner = l_table_owner and s.table_name = l_table_name + and p.table_owner = l_table_owner and p.table_name = l_table_name + and scs.column_name = c.column_name + and scs.subpartition_name = s.subpartition_name -- it seems that subpart names are unique across the whole table + and s.partition_name = p.partition_name + and :OPT_PARTINFOS = 'Y' + order by typ, column_id, internal_column_id, partition_position, subpartition_position + ) + loop + scf_add_elem (l_scf, 'ColName' , r.column_name); + scf_add_elem (l_scf, 'Partition' , r.partition_name); + scf_add_elem (l_scf, 'SubPart' , r.subpartition_name); + scf_add_elem (l_scf, 'ndv' , r.num_distinct); + scf_add_elem (l_scf, 'dens*#rows' , r.density * l_num_rows); + scf_add_elem (l_scf, 'num_nulls' , r.num_nulls); + scf_add_elem (l_scf, '#bkts' , r.num_buckets); + &COMM_IF_LT_10G. scf_add_elem (l_scf, 'hist', case r.histogram + &COMM_IF_LT_10G. when 'NONE' then null + &COMM_IF_LT_10G. when 'FREQUENCY' then 'FREQ' + &COMM_IF_LT_10G. when 'HEIGHT BALANCED' then 'HB' + &COMM_IF_LT_10G. else r.histogram + &COMM_IF_LT_10G. end); + scf_add_elem (l_scf, 'avg_col_len' , r.avg_col_len); + scf_add_elem (l_scf, 'sample_size' , r.sample_size); + scf_add_elem (l_scf, 'last_analyzed', nvl(d2s (r.last_analyzed),'* null *')); + end loop; + scf_print_output (l_scf, 'INTERNAL ERROR : no column statistics infos found', 'INTERNAL ERROR : no column statistics infos found(aux)'); + if :OPT_PARTINFOS='N' and l_partitioned='YES' then + print ( 'WARNING: (sub)partitions infos not printed.'); + end if; + + --------------- indexes --------------- + for i in (select /*+ xplan_exec_marker */ + owner index_owner, index_name, partitioned, uniqueness, index_type + from sys.all_indexes + where table_owner = l_table_owner and table_name = l_table_name + order by index_name, owner -- keep this row aligned with rows labeled as "block b001" + ) + loop + scf_reset (l_scf); + print ('### index #'||l_index_number(i.index_owner||'.'||i.index_name)||': '||i.index_owner||'.'||i.index_name); + l_tmp := null; + for c in (select column_name, descend + from sys.all_ind_columns + where table_owner = l_table_owner and table_name = l_table_name + and index_owner = i.index_owner and index_name = i.index_name + order by column_position) + loop + l_tmp := l_tmp || c.column_name || case when c.descend='DESC' then ' desc' end ||', '; + end loop; + print ('on '||l_table_owner||'.'||l_table_name||' ( '||rtrim(l_tmp,', ')||' )'); + + print (i.uniqueness||' '||replace(i.index_type,'NORMAL','B+TREE')); + + if i.partitioned='YES' then + for r in (select /*+ xplan_exec_marker */ partitioning_type, subpartitioning_type, locality + from sys.all_part_indexes + where owner = i.index_owner and index_name = i.index_name) + loop + print (r.locality||' PARTITIONED BY '||r.partitioning_type||' ( '||get_part_key_list(i.index_owner,i.index_name,'INDEX')||' ) '); + if r.subpartitioning_type<>'NONE' then + print ( 'SUBPARTITIONED BY '||r.subpartitioning_type||' ( '||get_subpart_key_list(i.index_owner,i.index_name,'INDEX')||' ) '); + end if; + end loop; + end if; + + -- dbms_metadata.get_ddl for index + &COMM_IF_NO_DBMS_METADATA. print('---- output of dbms_metadata.get_ddl ----'); + &COMM_IF_NO_DBMS_METADATA. print_clob( dbms_metadata.get_ddl( 'INDEX', i.index_name, i.index_owner) ); + + for r in (select /*+ xplan_exec_marker */ + '1' typ, cast(null as number) partition_position, null as partition_name, cast(null as number) subpartition_position, null as subpartition_name, + distinct_keys, num_rows, blevel, leaf_blocks, clustering_factor as cluf, sample_size, last_analyzed, degree + from sys.all_indexes + where owner = i.index_owner and index_name = i.index_name + union all + select '2' typ, partition_position, partition_name, null as subpartition_position, null as subpartition_name, + distinct_keys, num_rows, blevel, leaf_blocks, clustering_factor as cluf, sample_size, last_analyzed, null as degree + from sys.all_ind_partitions + where index_owner = i.index_owner and index_name = i.index_name + and :OPT_PARTINFOS = 'Y' + union all + select '3' typ, p.partition_position, s.partition_name, s.subpartition_position, s.subpartition_name, + s.distinct_keys, s.num_rows, s.blevel, s.leaf_blocks, s.clustering_factor as cluf, s.sample_size, s.last_analyzed, null as degree + from sys.all_ind_subpartitions s, sys.all_ind_partitions p + where s.index_owner = i.index_owner and s.index_name = i.index_name + and p.index_owner = i.index_owner and p.index_name = i.index_name + and s.partition_name = p.partition_name + and :OPT_PARTINFOS = 'Y' + order by typ, partition_position, subpartition_position) + loop + scf_add_elem (l_scf, 'Partition' , r.partition_name); + scf_add_elem (l_scf, 'SubPart' , r.subpartition_name); + scf_add_elem (l_scf, 'distinct_keys', r.distinct_keys); + scf_add_elem (l_scf, 'num_rows' , r.num_rows); + scf_add_elem (l_scf, 'blevel' , r.blevel); + scf_add_elem (l_scf, 'leaf_blocks' , r.leaf_blocks); + scf_add_elem (l_scf, 'cluf' , r.cluf); + scf_add_elem (l_scf, 'sample_size' , r.sample_size); + scf_add_elem (l_scf, 'last_analyzed', nvl(d2s (r.last_analyzed),'* null *')); + scf_add_elem (l_scf, 'parallel' , r.degree); + end loop; + scf_print_output (l_scf, 'INTERNAL ERROR : no index infos found', 'INTERNAL ERROR : no index infos found(aux)'); + if :OPT_PARTINFOS='N' and i.partitioned='YES' then + print ( 'WARNING: (sub)partitions infos not printed.'); + end if; + end loop; +end print_table_infos; + +--type cache_table_printed_infos_t is table of print_buffer_t index by varchar2(20); -- binary_integer is too small for object_id +--m_cache_table_printed_infos cache_table_printed_infos_t; +procedure cache_table_printed_infos (p_object_id int) +is + l_object_id_char varchar2(20) := to_char(p_object_id); +begin + if m_cache_table_printed_infos.exists (l_object_id_char) then + return; + end if; + + enable_print_buffer ('ENABLE'); + + print_table_infos (p_object_id); + + m_cache_table_printed_infos(l_object_id_char) := m_print_buffer; + + enable_print_buffer ('DISABLE'); +end cache_table_printed_infos; + +procedure print_cache_table_infos (p_object_id int) +is + l_object_id_char varchar2(20) := to_char(p_object_id); +begin + if p_object_id is null then + return; + end if; + cache_table_printed_infos (p_object_id); + for i in 0 .. m_cache_table_printed_infos(l_object_id_char).count-1 loop + print (m_cache_table_printed_infos(l_object_id_char)(i)); + end loop; +end print_cache_table_infos; + +-- following procedures are for gv$sql.program_id +procedure cache_program_info (p_program_id int) +is +begin + if m_cache_program_info.exists (p_program_id) then + return; + end if; + + m_cache_program_info(p_program_id) := '(not found)'||p_program_id; + for r in (select /*+ xplan_exec_marker */ owner, object_name, object_type + from sys.all_objects + where object_id = p_program_id) + loop + m_cache_program_info(p_program_id) := r.object_type ||' '||r.owner||'.'||r.object_name; + end loop; +end cache_program_info; + +function get_cache_program_info (p_program_id int) +return varchar2 +is +begin + if p_program_id is null then + return null; + end if; + cache_program_info (p_program_id); + return m_cache_program_info(p_program_id); +end get_cache_program_info; + +-- following procedures are for main xplan +procedure cache_username (p_user_id int) +is +begin + if m_cache_username.exists (p_user_id) then + return; + end if; + + m_cache_username(p_user_id) := '(not found)'||p_user_id; + for r in (select /*+ xplan_exec_marker */ username + from sys.all_users + where user_id = p_user_id) + loop + m_cache_username(p_user_id) := r.username; + end loop; +end cache_username; + +function get_cache_username (p_user_id int) +return varchar2 +is +begin + if p_user_id is null then + return null; + end if; + cache_username (p_user_id); + return m_cache_username (p_user_id); +end get_cache_username; + +procedure cache_user_id (p_username varchar2) +is +begin + if m_cache_user_id.exists (p_username) then + return; + end if; + + m_cache_user_id(p_username) := -1; + for r in (select /*+ xplan_exec_marker */ user_id + from sys.all_users + where username = p_username) + loop + m_cache_user_id(p_username) := r.user_id; + end loop; +end cache_user_id; + +function get_cache_user_id (p_username varchar2) +return varchar2 +is +begin + if p_username is null then + return null; + end if; + cache_user_id (p_username); + return m_cache_user_id (p_username); +end get_cache_user_id; + diff --git a/Alberto/xplan_tabinfos_vars.sql b/Alberto/xplan_tabinfos_vars.sql new file mode 100644 index 0000000..f724535 --- /dev/null +++ b/Alberto/xplan_tabinfos_vars.sql @@ -0,0 +1,38 @@ +-------------------------------------------------------------------------------- +-- Author: Alberto Dell'Era +-- Copyright: (c) 2008, 2009 Alberto Dell'Era http://www.adellera.it +-------------------------------------------------------------------------------- + +-- map from object id to base table object id +type cache_base_table_object_id_t is table of varchar2(20) index by varchar2(20); -- binary_integer is too small for object_id +m_cache_base_table_object_id cache_base_table_object_id_t; + +-- map from object id to basic obj infos +type obj_infos_t is record ( + object_type varchar2(19), + owner varchar2(30), + object_name varchar2(30) +); +type cache_obj_infos_t is table of obj_infos_t index by varchar2(20); -- binary_integer is too small for object_id +m_cache_obj_infos cache_obj_infos_t; + +-- map from table object id to list of lines to be printed +type cache_table_printed_infos_t is table of print_buffer_t index by varchar2(20); -- binary_integer is too small for object_id +m_cache_table_printed_infos cache_table_printed_infos_t; + +-- map from gv$sql.program_id to type/owner/objectname +type cache_program_info_t is table of varchar2(100) index by binary_integer; +m_cache_program_info cache_program_info_t; + +-- map from user_id to username +type cache_username_t is table of varchar2(30) index by binary_integer; +m_cache_username cache_username_t; + +-- map from username to user_id +type cache_user_id_t is table of varchar2(30) index by varchar2(30); +m_cache_user_id cache_user_id_t; + +-- list of all referenced table object ids +-- (05/02/2009, to support tabinfos='bottom') +type all_referenced_object_ids_t is table of varchar2(1) index by varchar2(30); +m_all_referenced_object_ids all_referenced_object_ids_t; diff --git a/Alberto/xplan_test.sql b/Alberto/xplan_test.sql new file mode 100644 index 0000000..58c5de9 --- /dev/null +++ b/Alberto/xplan_test.sql @@ -0,0 +1,93 @@ +-------------------------------------------------------------------------------- +-- Author: Alberto Dell'Era +-- Copyright: (c) 2008, 2009 Alberto Dell'Era http://www.adellera.it +-------------------------------------------------------------------------------- + +drop materialized view t_mv; +drop table t cascade constraint; +drop table parent cascade constraint; + +create table parent (rr varchar2(1) primary key); +insert into parent(rr) values ('x'); + +create table t (x, padding, rr, constraint t_pk primary key (x,padding)) +organization index +partition by range (x, padding) +--subpartition by hash (padding, x) subpartitions 2 +( + partition p1 values less than (100,'A'), + partition p2 values less than (200,'B'), + partition pother values less than (maxvalue,maxvalue) +) +as +select rownum x, rpad(rownum, 100,'x') padding, rpad('x',1) rr from dual connect by level <= 100; + +create or replace view v as +select x, padding, rr + from t + where x > 0; + +create or replace function plsql_func (p varchar2) +return varchar2 +is +begin + return p; +end plsql_func; +/ + +create or replace package plsql_pkg as +function f (p varchar2) return varchar2 ; +end plsql_pkg; +/ +create or replace package body plsql_pkg as +function f (p varchar2) return varchar2 is begin return p; end; +end plsql_pkg; +/ + +disassociate statistics from functions plsql_func; +associate statistics with functions plsql_func default selectivity 0.001, default cost (100,10,1); + +disassociate statistics from packages plsql_pkg; +associate statistics with packages plsql_pkg default selectivity 0.002, default cost (200,20,2); + +alter table t add constraint t_uq_1 unique (padding); +alter table t add constraint t_uq_2 unique (padding,x); +alter table t add constraint t_ref foreign key (rr) references parent(rr); + +create index t_idx on t(padding, x) local; +create index t_fbi on t(x, upper(x)) local; +create index t_fbi2 on t(x, case when x = 0 then 'pippo' when x = 1 then 'uuiio' when x = 3 then 'uuciio' when x = 4 then 'uuieio' else 'pppppp' end ); + +exec dbms_stats.gather_table_stats (user,'t',cascade=>true, method_opt=>'for all columns size 254', estimate_percent=>null, granularity=>'ALL'); + +create materialized view t_mv +build immediate +refresh complete on demand +enable query rewrite +as +select * from t + where upper(x) = '0'; + +create index t_mv_upper_x on t_mv (upper(x)); + +exec dbms_stats.gather_table_stats (user,'t_mv',cascade=>true, method_opt=>'for all columns size 254', estimate_percent=>null, granularity=>'ALL'); + + +alter session set statistics_level=all; +alter session set query_rewrite_enabled=true; +alter system flush shared_pool; + +--define SQL_TEST="select /*+ parallel(t,2) parallel_index(t,2) xplan_test_marker */ x,max(padding) from t where abs(x) = 2 and upper(x) = 2 and lower(x) = 2 and x*5=43 and x*4=43 and x*3=43 and x*2 = 43 group by x order by x" +define SQL_TEST="select /*+ index(t,t_fbi) xplan_test_marker */ t.padding,plsql_pkg.f(plsql_func(max(t.x))) from t, v where upper(t.x) = '0' and t.x > l_y group by t.padding order by t.padding" + +alter session set workarea_size_policy=manual; +alter session set hash_area_size=2000000; +alter session set sort_area_size=2000000; + +declare l_x number := 0; l_y number := 0; +begin /* xplan_exec_marker sga_xplan_exec */ for r in (&SQL_TEST.) loop null; end loop; end; +/ + +@xplan "%xplan_test_marker%" "plan_stats= last ,access_predicates=Y,lines=150,module=,action=,dbms_xplan=n,plan_details=n,plan_env=y,tabinfos=y" + +--exec sga_xplan.print ('select%xplan_test_marker%'); \ No newline at end of file diff --git a/Alberto/xplan_test_ass_stats.sql b/Alberto/xplan_test_ass_stats.sql new file mode 100644 index 0000000..9096fb4 --- /dev/null +++ b/Alberto/xplan_test_ass_stats.sql @@ -0,0 +1,132 @@ +-------------------------------------------------------------------------------- +-- Author: Alberto Dell'Era +-- Copyright: (c) 2008, 2009 Alberto Dell'Era http://www.adellera.it +-------------------------------------------------------------------------------- + +create or replace type tttt as object ( + dummy_attribute number, + static function f (p varchar2) return varchar2 +); +/ +show errors + +create or replace type body tttt as + static function f (p varchar2) + return varchar2 + is + begin + return p; + end f; +end; +/ +show errors + +disassociate statistics from types tttt; +associate statistics with types tttt default selectivity 0.003, default cost (300,30,3); + +-- following are dummified from http://www.oracle-developer.net/display.php?id=426# + +create or replace type stats_ot as object ( + + dummy_attribute number, + + static function odcigetinterfaces ( + p_interfaces out sys.odciobjectlist + ) return number, + + static function odcistatsselectivity ( + p_pred_info in sys.odcipredinfo, + p_selectivity out number, + p_args in sys.odciargdesclist, + p_start in varchar2, + p_stop in varchar2, + p_promo_category in varchar2, + p_env in sys.odcienv + ) return number, + + static function odcistatsfunctioncost ( + p_func_info in sys.odcifuncinfo, + p_cost out sys.odcicost, + p_args in sys.odciargdesclist, + p_promo_category in varchar2, + p_env in sys.odcienv + ) return number +); +/ +show errors + +create or replace type body stats_ot as + + static function odcigetinterfaces ( + p_interfaces out sys.odciobjectlist + ) return number is + begin + p_interfaces := sys.odciobjectlist( + SYS.ODCIObject ('SYS', 'ODCISTATS2') + ); + RETURN ODCIConst.success; + end odcigetinterfaces; + + static function odcistatsselectivity ( + p_pred_info in sys.odcipredinfo, + p_selectivity out number, + p_args in sys.odciargdesclist, + p_start in varchar2, + p_stop in varchar2, + p_promo_category in varchar2, + p_env in sys.odcienv + ) return number is + begin + p_selectivity := 0.1; + return odciconst.success; + end odcistatsselectivity; + + static function odcistatsfunctioncost ( + p_func_info in sys.odcifuncinfo, + p_cost out sys.odcicost, + p_args in sys.odciargdesclist, + p_promo_category in varchar2, + p_env in sys.odcienv + ) return number is + begin + p_cost := sys.odcicost(null, null, null, null); + p_cost.cpucost := 100; + p_cost.iocost := 10; + p_cost.networkcost := 0; + return odciconst.success; + end odcistatsfunctioncost; + +end; +/ +show errors + +create or replace function plsql_func (p varchar2) +return varchar2 +is +begin + return p; +end plsql_func; +/ + +disassociate statistics from functions plsql_func; +associate statistics with functions plsql_func using stats_ot; + +drop table t; +create table t (x varchar2(100)); +insert into t (x) values ('giulio cesare'); +insert into t (x) values ('marco antonio'); + +create index t_ind_ctx on t(x) indextype is ctxsys.context; + +select * from t where contains( x, 'giulio' ) > 0; + + +alter system flush shared_pool; + +define SQL_TEST="select /*+ xplan_test_marker */ tttt.f(x) from t where plsql_func('X') = 'X' and contains(x, 'giulio') > 0" + +declare l_x number := 0; l_y number := 0; +begin /* xplan_exec_marker sga_xplan_exec */ for r in (&SQL_TEST.) loop null; end loop; end; +/ + +@xplan "%xplan_test_marker%" "plan_stats= last ,access_predicates=Y,lines=150,module=,action=,dbms_xplan=n,plan_details=n,plan_env=y,tabinfos=y" diff --git a/Alberto/xplan_test_self.sql b/Alberto/xplan_test_self.sql new file mode 100644 index 0000000..1acd7e9 --- /dev/null +++ b/Alberto/xplan_test_self.sql @@ -0,0 +1,43 @@ +-------------------------------------------------------------------------------- +-- Author: Alberto Dell'Era +-- Copyright: (c) 2008-2012 Alberto Dell'Era http://www.adellera.it +-------------------------------------------------------------------------------- + +set echo on +set trimspool on + +/* +drop table t; + +create table t (x int, y int); +create index t_x_idx on t(x); +insert into t(x,y) select rownum, rownum from dual connect by level <= 10000; +commit; +exec dbms_stats.gather_table_stats(user, 'T', cascade=>true, method_opt=>'for all columns size 1', estimate_percent=>null); +*/ + +--alter system flush shared_pool; + +alter system flush buffer_cache; + +alter session set statistics_level=all; + +select /*+ index(t,t_x_idx) xplan_test_marker */ t.y, (select y from t t2 where t2.x = t.x) from t where x > 0; + +select /*+ leading(t2) use_nl(t1,t2) index(t2,t_x_idx) xplan_test_marker */ t1.*, t2.* + from t t1, t t2 + where t1.x = t2.x + and t1.y <= 1000; + +update /*+ xplan_test_marker */ t set x = x; +rollback; + +set autotrace traceonly statistics + +insert /*+ append xplan_test_marker */ into t select rownum-1, rownum-1 from dual connect by level <= 100000; +rollback; + +set autotrace off + +@xplan "%xplan_test_marker%" "ti=n,oi=n,plan_details=y" + diff --git a/Alberto/xplan_utilities_body.sql b/Alberto/xplan_utilities_body.sql new file mode 100644 index 0000000..d2bc8fa --- /dev/null +++ b/Alberto/xplan_utilities_body.sql @@ -0,0 +1,191 @@ +-------------------------------------------------------------------------------- +-- Author: Alberto Dell'Era +-- Copyright: (c) 2008, 2009 Alberto Dell'Era http://www.adellera.it +-------------------------------------------------------------------------------- + +----------------------------------------------------------- +-- enables or disables buffer redirection to internal buffer. +-- In both cases, clears the buffer. +procedure enable_print_buffer (p_enable_or_disable varchar2 default 'ENABLE') +is +begin + m_print_buffer.delete; + if p_enable_or_disable = 'ENABLE' then + m_print_buffer_enabled := true; + elsif p_enable_or_disable = 'DISABLE' then + m_print_buffer_enabled := false; + else + raise_application_error (-20001, 'enable_print_buffer: p_enable_or_disable is not ENABLE or DISABLE.'); + end if; +end enable_print_buffer; + +----------------------------------------------------------- +-- prints to dbms_output.put_line or to internal buffer +-- if requested +procedure print_or_buffer (p_line varchar2) +is +begin + if m_print_buffer_enabled then + m_print_buffer(m_print_buffer.count) := p_line; + else + dbms_output.put_line (p_line); + end if; +end print_or_buffer; + +----------------------------------------------------------- +-- transforms a statement into lines (with maxsize) +-- It's a pretty-printer as well. +procedure print_stmt_lines (p_text varchar2) +--create or replace procedure str2lines (p_text varchar2) +is + l_text long default rtrim(p_text); + l_text_length number default length(l_text); + l_pos int default 1; + l_chunk_size int default &LINE_SIZE.; + l_curr varchar2(400); + l_last int; +begin + &COMM_IF_GT_10G. if l_chunk_size > 255 then l_chunk_size := 255-5; end if; + + loop + l_curr := substr (l_text, l_pos, l_chunk_size); + exit when l_curr is null; + + -- chop at the FIRST newline, if any + l_last := instr (l_curr, chr(10)); + -- if not, chop at the last pos if shorter than chunksize + if l_last <= 0 and length(l_curr) < l_chunk_size then + l_last := l_chunk_size; + end if; + -- if not, chop at the LAST blank, if any + if l_last <= 0 then + l_last := instr (l_curr, ' ', -1); + end if; + -- if not, chop BEFORE an operator or separator + if l_last <= 0 then + l_last := -1 + greatest (instr (l_curr , '<=', -1), + instr (l_curr , '>=', -1), + instr (l_curr , '<>', -1), + instr (l_curr , '!=', -1), + instr (l_curr , ':=', -1), + instr (l_curr , '=' , -1), + instr (l_curr , '<' , -1), + instr (l_curr , '>' , -1), + instr (l_curr , ',' , -1), + instr (l_curr , ';' , -1), + instr (l_curr , '+' , -1), + instr (l_curr , '-' , -1), + instr (l_curr , '*' , -1), + instr (l_curr , '/' , -1), + instr (l_curr , '(' , -1), + instr (l_curr , '/*', -1) + ); + -- handle clash of '=' and '<=', '>=','!=' or ':='; of '*' and '/*' + if l_last > 2 and substr (l_curr, l_last, 2) in ('<=','>=','<>','!=','/*') then + l_last := l_last-1; + end if; + end if; + -- last resort: don't chop + if l_last <= 0 then + l_last := l_chunk_size; + end if; + + -- print (or buffer) line + print_or_buffer ( rtrim ( substr (l_curr, 1, l_last), chr(10) )); + + -- advance current position + l_pos := l_pos + l_last; + exit when l_pos > l_text_length; + end loop; + +end print_stmt_lines; + +----------------------------------------------------------- +-- print a line, breaking it if necessary +procedure print (p_text varchar2) +is +begin + print_stmt_lines (p_text); +end print; + +----------------------------------------------------------- +-- print a long (coming from a query) using print() +-- adapted from Tom's showlong: http://asktom.oracle.com/pls/asktom/f?p=100:11:0::::P11_QUESTION_ID:665224430110 +procedure print_long ( + p_query varchar2, + p_bind_1_name varchar2, + p_bind_1_value varchar2, + p_bind_2_name varchar2, + p_bind_2_value varchar2) +as + l_cursor integer default dbms_sql.open_cursor; + l_n number; + l_long_val varchar2(32000); + l_long_len number; + l_buflen number := 32000; + l_curpos number := 0; +begin + dbms_sql.parse( l_cursor, p_query, dbms_sql.native ); + dbms_sql.bind_variable( l_cursor, p_bind_1_name, p_bind_1_value ); + dbms_sql.bind_variable( l_cursor, p_bind_2_name, p_bind_2_value ); + + dbms_sql.define_column_long(l_cursor, 1); + l_n := dbms_sql.execute(l_cursor); + + if (dbms_sql.fetch_rows(l_cursor)>0) + then + loop + dbms_sql.column_value_long(l_cursor, 1, l_buflen, + l_curpos , l_long_val, + l_long_len ); + l_curpos := l_curpos + l_long_len; + print ( l_long_val ); + exit when l_long_len = 0; + end loop; + end if; + dbms_sql.close_cursor(l_cursor); +exception + when others then + if dbms_sql.is_open(l_cursor) then + dbms_sql.close_cursor(l_cursor); + end if; + raise; +end print_long; + +----------------------------------------------------------- +-- print a CLOB +procedure print_clob( p_clob clob) +is + l_buffer long; + l_amount binary_integer; + l_offset int; +begin + l_amount := 32767; + l_offset := 1; + loop + dbms_lob.read( p_clob, l_amount, l_offset, l_buffer ); + print( l_buffer ); + exit when l_amount < 32767; + l_offset := l_offset + l_amount; + end loop; +exception + when no_data_found then + null; +end print_clob; + +----------------------------------------------------------- +function d2s (p_date date) return varchar2 +is +begin + return to_char (p_date, 'yyyy/mm/dd hh24:mi:ss'); +end d2s; + +----------------------------------------------------------- +-- check whether the argument is an integer +function is_integer (p_s varchar2) +return boolean +is +begin + return trim ( translate (p_s, '0123456789', ' ') ) is null; +end is_integer; + diff --git a/Alberto/xplan_utilities_vars.sql b/Alberto/xplan_utilities_vars.sql new file mode 100644 index 0000000..b973eea --- /dev/null +++ b/Alberto/xplan_utilities_vars.sql @@ -0,0 +1,10 @@ +-------------------------------------------------------------------------------- +-- Author: Alberto Dell'Era +-- Copyright: (c) 2008, 2009 Alberto Dell'Era http://www.adellera.it +-------------------------------------------------------------------------------- + +type print_buffer_t is table of varchar2(512 char) index by binary_integer; +m_print_buffer print_buffer_t; + +m_print_buffer_enabled boolean default false; +