├── LICENSE ├── README.md ├── xplan.display.sql ├── xplan.display_awr.sql ├── xplan.display_cursor.sql └── xplan.package.sql /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2009-2020 Adrian Billington, www.oracle-developer.net 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | 2 | # XPLAN 3 | 4 | ## 1.0 Introduction 5 | This repository contains two versions of the XPLAN utility. XPLAN is a wrapper over DBMS_XPLAN functions that re-formats plan output to include parent operation ID and execution order columns. This makes plan interpretation easier for larger or more complex execution plans. 6 | 7 | ## 2.0 Versions 8 | There are two versions provided. 9 | 10 | ### 2.1 Installed Package (xplan.package.sql) 11 | This is a package of pipelined function wrappers over the DBMS_XPLAN reports (DISPLAY, DISPLAY_CURSOR, DISPLAY_AWR). It creates two types and the XPLAN package itself. See the description in the package header for more details and usage information. 12 | 13 | ### 2.2 Standalone Scripts (xplan.display.sql, xplan.display_cursor.sql, xplan.display_awr.sql) 14 | These are standalone SQL scripts (for SQL*Plus) that simulate the XPLAN functionality but without having to create any database objects. Because they are free-standing SQL scripts, they are more portable, can be added to your SQLPath for instant availability and can be used in more restrictive environments. See the description in the script headers for more details and usage information. Note that a Tuning and Diagnostics Pack licence is required for the `xplan.display_awr.sql` script as it accesses AWR data. 15 | 16 | ## 4.0 License 17 | This project uses the MIT License. 18 | See https://github.com/oracle-developer/xplan/blob/master/LICENSE 19 | 20 | Adrian Billington 21 | www.oracle-developer.net -------------------------------------------------------------------------------- /xplan.display.sql: -------------------------------------------------------------------------------- 1 | 2 | -- ---------------------------------------------------------------------------------------------- 3 | -- 4 | -- Utility: XPLAN 5 | -- 6 | -- Script: xplan.display.sql 7 | -- 8 | -- Version: 1.3 9 | -- 10 | -- Author: Adrian Billington 11 | -- www.oracle-developer.net 12 | -- (c) oracle-developer.net 13 | -- 14 | -- Description: A free-standing SQL wrapper over DBMS_XPLAN. Provides access to the 15 | -- DBMS_XPLAN.DISPLAY pipelined function for an explained SQL statement. 16 | -- 17 | -- The XPLAN utility has one purpose: to include the parent operation ID (PID) 18 | -- and an execution order column (OID) in the plan output. This makes plan 19 | -- interpretation easier for larger or more complex execution plans. Version 1.3 20 | -- has also added the object owner to the output for more clarity. 21 | -- 22 | -- See the following example for details. 23 | -- 24 | -- Example: DBMS_XPLAN output (format BASIC): 25 | -- ------------------------------------------------ 26 | -- | Id | Operation | Name | 27 | -- ------------------------------------------------ 28 | -- | 0 | SELECT STATEMENT | | 29 | -- | 1 | MERGE JOIN | | 30 | -- | 2 | TABLE ACCESS BY INDEX ROWID| DEPT | 31 | -- | 3 | INDEX FULL SCAN | PK_DEPT | 32 | -- | 4 | SORT JOIN | | 33 | -- | 5 | TABLE ACCESS FULL | EMP | 34 | -- ------------------------------------------------ 35 | -- 36 | -- Equivalent XPLAN output (format BASIC): 37 | -- ------------------------------------------------------------------ 38 | -- | Id | Pid | Ord | Operation | Name | 39 | -- ------------------------------------------------------------------ 40 | -- | 0 | | 6 | SELECT STATEMENT | | 41 | -- | 1 | 0 | 5 | MERGE JOIN | | 42 | -- | 2 | 1 | 2 | TABLE ACCESS BY INDEX ROWID| SCOTT.DEPT | 43 | -- | 3 | 2 | 1 | INDEX FULL SCAN | SCOTT.PK_DEPT | 44 | -- | 4 | 1 | 4 | SORT JOIN | | 45 | -- | 5 | 4 | 3 | TABLE ACCESS FULL | SCOTT.EMP | 46 | -- ------------------------------------------------------------------ 47 | -- 48 | -- Usage: @xplan.display.sql [plan_table] [statement_id] [plan_format] 49 | -- 50 | -- Parameters: 1) plan_table - OPTIONAL (defaults to PLAN_TABLE) 51 | -- 2) statement_id - OPTIONAL (defaults to NULL) 52 | -- 3) plan_format - OPTIONAL (defaults to TYPICAL) 53 | -- 54 | -- Examples: 1) Plan for last explained SQL statement 55 | -- ------------------------------------- 56 | -- @xplan.display.sql 57 | -- 58 | -- 2) Plan for a specific statement_id 59 | -- -------------------------------- 60 | -- @xplan.display.sql "" "my_statement_id" 61 | -- 62 | -- 3) Plan for last explained SQL statement using a non-standard plan table 63 | -- --------------------------------------------------------------------- 64 | -- @xplan.display.sql "my_plan_table" 65 | -- 66 | -- 4) Plan for last explained SQL statement with a non-default format 67 | -- --------------------------------------------------------------- 68 | -- @xplan.display.sql "" "" "basic +projection" 69 | -- 70 | -- 5) Plan for a specific statement_id and non-default format 71 | -- ------------------------------------------------------- 72 | -- @xplan.display.sql "" "my_statement_id" "advanced" 73 | -- 74 | -- 6) Plan for last explained SQL statement with a non-default plan table and non-default format 75 | -- ------------------------------------------------------------------------------------------ 76 | -- @xplan.display.sql "my_plan_table" "my_statement_id" "advanced" 77 | -- 78 | -- Versions: This utility will work for all versions of 10g and upwards. 79 | -- 80 | -- Required: 1) Access to a plan table that corresponds to the Oracle version being used. 81 | -- 82 | -- Notes: An XPLAN PL/SQL package is also available. This has wrappers for all of the 83 | -- DBMS_XPLAN pipelined functions, but requires the creation of objects. 84 | -- 85 | -- Credits: 1) James Padfield for the hierarchical query to order the plan operations. 86 | -- 87 | -- Disclaimer: http://www.oracle-developer.net/disclaimer.php 88 | -- 89 | -- ---------------------------------------------------------------------------------------------- 90 | 91 | set define on 92 | define v_xp_version = 1.3 93 | 94 | -- Initialise variables 1,2,3 in case they aren't supplied... 95 | -- ---------------------------------------------------------- 96 | set termout off 97 | column 1 new_value 1 98 | column 2 new_value 2 99 | column 3 new_value 3 100 | select null as "1" 101 | , null as "2" 102 | , null as "3" 103 | from dual 104 | where 1=2; 105 | 106 | -- Set the plan table... 107 | -- --------------------- 108 | column plan_table new_value v_xp_plan_table 109 | select nvl('&1', 'PLAN_TABLE') as plan_table 110 | from dual; 111 | 112 | -- Finally prepare the inputs to the main Xplan SQL... 113 | -- --------------------------------------------------- 114 | column plan_id new_value v_xp_plan_id 115 | column stmt_id new_value v_xp_stmt_id 116 | column format new_value v_xp_format 117 | select nvl(max(plan_id), -1) as plan_id 118 | , max(statement_id) keep (dense_rank first order by plan_id desc) as stmt_id 119 | , nvl(max('&3'), 'typical') as format 120 | from &v_xp_plan_table 121 | where id = 0 122 | and nvl(statement_id, '~') = coalesce('&2', statement_id, '~'); 123 | 124 | -- Main Xplan SQL... 125 | -- ----------------- 126 | set termout on lines 200 pages 1000 127 | col plan_table_output format a200 128 | 129 | with sql_plan_data as ( 130 | select id, parent_id, object_owner, object_name 131 | from &v_xp_plan_table 132 | where plan_id = &v_xp_plan_id 133 | order by id 134 | ) 135 | , hierarchy_data as ( 136 | select id, parent_id, object_owner, object_name 137 | from sql_plan_data 138 | start with id = 0 139 | connect by prior id = parent_id 140 | order siblings by id desc 141 | ) 142 | , ordered_hierarchy_data as ( 143 | select id 144 | , parent_id 145 | , object_owner 146 | , object_name 147 | , row_number() over (order by rownum desc) as order_id 148 | , max(id) over () as max_id 149 | from hierarchy_data 150 | ) 151 | , xplan_data as ( 152 | select /*+ ordered use_nl(o) */ 153 | x.plan_table_output 154 | , o.id 155 | , o.parent_id 156 | , o.order_id 157 | , o.max_id 158 | , o.object_owner 159 | , o.object_name 160 | , count(*) over () as row_count 161 | from table(dbms_xplan.display('&v_xp_plan_table','&v_xp_stmt_id','&v_xp_format')) x 162 | left outer join 163 | ordered_hierarchy_data o 164 | on (o.id = case 165 | when regexp_like(x.plan_table_output, '^\|[\* 0-9]+\|') 166 | then to_number(regexp_substr(x.plan_table_output, '[0-9]+')) 167 | end) 168 | ) 169 | select plan_table_output 170 | from xplan_data 171 | model 172 | dimension by (rownum as r) 173 | measures (plan_table_output, 174 | id, 175 | max_id as mid, 176 | parent_id as pid, 177 | order_id as oid, 178 | object_owner as owner, 179 | object_name as oname, 180 | nullif(object_owner || '.', '.') || object_name as ownname, 181 | max(length(object_owner || '.' || object_name)) over () as maxownnamelen, 182 | max(length(object_owner || '.' || object_name)) over () - max(length(object_name)) over () as ownnamepad, 183 | greatest(max(length(max_id)) over () + 3, 6) as csize, 184 | cast(null as varchar2(128)) as inject, 185 | row_count as rc) 186 | rules sequential order ( 187 | inject[r] = case 188 | when id[cv()+1] = 0 189 | or id[cv()+3] = 0 190 | or id[cv()-1] = mid[cv()-1] 191 | then rpad('-', csize[cv()]*2 + ownnamepad[cv()], '-') 192 | when id[cv()+2] = 0 193 | then '|' || lpad('Pid |', csize[cv()]) || lpad('Ord |', csize[cv()]) 194 | when id[cv()] is not null 195 | then '|' || lpad(pid[cv()] || ' |', csize[cv()]) || lpad(oid[cv()] || ' |', csize[cv()]) 196 | end, 197 | plan_table_output[r] = case 198 | when inject[cv()] like '---%' 199 | then inject[cv()] || plan_table_output[cv()] 200 | when inject[cv()] is not null 201 | then regexp_replace(plan_table_output[cv()], '\|', inject[cv()], 1, 2) 202 | else plan_table_output[cv()] 203 | end, 204 | plan_table_output[r] order by r = case 205 | when plan_table_output[cv()] like '|%' 206 | then case 207 | when id[cv()+2] = 0 208 | then regexp_replace(plan_table_output[cv()], '(\| Name[ ]+)', '\1' || rpad(' ', ownnamepad[cv()])) 209 | else case 210 | when oname[cv()] is not null 211 | then regexp_replace(plan_table_output[cv()], '[^\|]+', rpad(' ' || ownname[cv()], maxownnamelen[cv()] + 2), 1, 5) 212 | else regexp_replace(plan_table_output[cv()], '(\|.)', '\1' || rpad(' ', ownnamepad[cv()]), 1, 5) 213 | end 214 | end 215 | else plan_table_output[cv()] 216 | end || 217 | case 218 | when cv(r) = rc[cv()] 219 | then chr(10) || chr(10) || 220 | 'About' || chr(10) || 221 | '------' || chr(10) || 222 | ' - XPlan v&v_xp_version by Adrian Billington (http://www.oracle-developer.net)' 223 | end 224 | ) 225 | order by r; 226 | 227 | -- Teardown... 228 | -- ----------- 229 | undefine v_xp_plan_table 230 | undefine v_xp_plan_id 231 | undefine v_xp_stmt_id 232 | undefine v_xp_format 233 | undefine v_xp_version 234 | undefine 1 235 | undefine 2 236 | undefine 3 237 | -------------------------------------------------------------------------------- /xplan.display_awr.sql: -------------------------------------------------------------------------------- 1 | 2 | -- ---------------------------------------------------------------------------------------------- 3 | -- 4 | -- Utility: XPLAN 5 | -- 6 | -- Script: xplan.display_awr.sql 7 | -- 8 | -- Version: 1.3 9 | -- 10 | -- Author: Adrian Billington 11 | -- www.oracle-developer.net 12 | -- (c) oracle-developer.net 13 | -- 14 | -- Description: A free-standing SQL wrapper over DBMS_XPLAN. Provides access to the 15 | -- DBMS_XPLAN.DISPLAY_AWR pipelined function for a given SQL_ID and optional 16 | -- plan hash value. 17 | -- 18 | -- The XPLAN utility has one purpose: to include the parent operation ID (PID) 19 | -- and an execution order column (OID) in the plan output. This makes plan 20 | -- interpretation easier for larger or more complex execution plans. Version 1.3 21 | -- has also added the object owner to the output for more clarity. 22 | -- 23 | -- See the following example for details. 24 | -- 25 | -- Example: DBMS_XPLAN output (format BASIC): 26 | -- ------------------------------------------------ 27 | -- | Id | Operation | Name | 28 | -- ------------------------------------------------ 29 | -- | 0 | SELECT STATEMENT | | 30 | -- | 1 | MERGE JOIN | | 31 | -- | 2 | TABLE ACCESS BY INDEX ROWID| DEPT | 32 | -- | 3 | INDEX FULL SCAN | PK_DEPT | 33 | -- | 4 | SORT JOIN | | 34 | -- | 5 | TABLE ACCESS FULL | EMP | 35 | -- ------------------------------------------------ 36 | -- 37 | -- Equivalent XPLAN output (format BASIC): 38 | -- ------------------------------------------------------------------ 39 | -- | Id | Pid | Ord | Operation | Name | 40 | -- ------------------------------------------------------------------ 41 | -- | 0 | | 6 | SELECT STATEMENT | | 42 | -- | 1 | 0 | 5 | MERGE JOIN | | 43 | -- | 2 | 1 | 2 | TABLE ACCESS BY INDEX ROWID| SCOTT.DEPT | 44 | -- | 3 | 2 | 1 | INDEX FULL SCAN | SCOTT.PK_DEPT | 45 | -- | 4 | 1 | 4 | SORT JOIN | | 46 | -- | 5 | 4 | 3 | TABLE ACCESS FULL | SCOTT.EMP | 47 | -- ------------------------------------------------------------------ 48 | -- 49 | -- Usage: @xplan.display_awr.sql [plan_hash_value] [plan_format] 50 | -- 51 | -- Parameters: 1) sql_id - MANDATORY 52 | -- 2) plan_hash_value - OPTIONAL (defaults to all available for the SQL ID) 53 | -- 3) plan_format - OPTIONAL (defaults to TYPICAL) 54 | -- 55 | -- Examples: 1) All AWR plans for a SQL_ID 56 | -- -------------------------- 57 | -- @xplan.display_awr.sql 9vfvgsk7mtkr4 58 | -- 59 | -- 2) All AWR plans for a SQL_ID with a non-default format 60 | -- ---------------------------------------------------- 61 | -- @xplan.display_awr.sql 9vfvgsk7mtkr4 "" "basic +projection" 62 | -- 63 | -- 3) AWR plan for a SQL_ID and specific PLAN_HASH_VALUE 64 | -- -------------------------------------------------- 65 | -- @xplan.display_awr.sql 9vfvgsk7mtkr4 63301235 66 | -- 67 | -- 4) AWR plan for a SQL_ID, specific PLAN_HASH_VALUE and non-default format 68 | -- ---------------------------------------------------------------------- 69 | -- @xplan.display_awr.sql 9vfvgsk7mtkr4 63301235 "advanced" 70 | -- 71 | -- Versions: This utility will work for all versions of 10g and upwards. 72 | -- 73 | -- Required: *** IMPORTANT: PLEASE READ *** 74 | -- 75 | -- 1) Oracle license implications 76 | -- --------------------------- 77 | -- The AWR functionality of XPLAN accesses a DBA_HIST% AWR view which means 78 | -- that it requires an Oracle Tuning and Diagnostic Pack license. Please 79 | -- ensure that you are licensed to use this feature: the author accepts 80 | -- no responsibility for any use of this functionality in an unlicensed database. 81 | -- 82 | -- 2) Access to the DBA_HIST_SQL_PLAN AWR view. 83 | -- 84 | -- Notes: An XPLAN PL/SQL package is also available. This has wrappers for all of the 85 | -- DBMS_XPLAN pipelined functions, but requires the creation of objects. 86 | -- 87 | -- Credits: 1) James Padfield for the hierarchical query to order the plan operations. 88 | -- 89 | -- Disclaimer: http://www.oracle-developer.net/disclaimer.php 90 | -- 91 | -- ---------------------------------------------------------------------------------------------- 92 | 93 | set define on 94 | define v_xa_version = 1.3 95 | 96 | -- Initialise variables 1,2,3 in case they aren't supplied... 97 | -- ---------------------------------------------------------- 98 | set termout off 99 | column 1 new_value 1 100 | column 2 new_value 2 101 | column 3 new_value 3 102 | select null as "1" 103 | , null as "2" 104 | , null as "3" 105 | from dual 106 | where 1=2; 107 | 108 | -- Define the parameters... 109 | -- ------------------------ 110 | column dbid new_value v_xa_dbid 111 | column sql_id new_value v_xa_sql_id 112 | column format new_value v_xa_format 113 | column plan_hash_value new_value v_xa_plan_hash_value 114 | select dbid 115 | , '&1' as sql_id 116 | , nvl('&2', 'NULL') as plan_hash_value 117 | , nvl('&3', 'TYPICAL') as format 118 | from gv$database 119 | where inst_id = sys_context('userenv','instance'); 120 | 121 | -- Main Xplan SQL... 122 | -- ----------------- 123 | set termout on lines 200 pages 1000 124 | col plan_table_output format a200 125 | 126 | prompt _ _____________________________________________________________________ 127 | prompt _ 128 | prompt _ XPlan v&v_xa_version by Adrian Billington (http://www.oracle-developer.net) 129 | prompt _ 130 | prompt _ 131 | prompt _ *** IMPORTANT: PLEASE READ *** 132 | prompt _ 133 | prompt _ A licence for the Oracle Tuning and Diagnostics Pack is needed to 134 | prompt _ use this utility. Continue at your own risk: the author accepts 135 | prompt _ no responsibility for any use of this functionality in an unlicensed 136 | prompt _ database. 137 | prompt _ 138 | prompt _ To cancel: press Ctrl-C 139 | prompt _ To continue: press Enter 140 | prompt _ _____________________________________________________________________ 141 | prompt 142 | pause 143 | 144 | with sql_plan_data as ( 145 | select id, parent_id, plan_hash_value, object_owner, object_name 146 | from dba_hist_sql_plan 147 | where sql_id = '&v_xa_sql_id' 148 | and plan_hash_value = nvl(&v_xa_plan_hash_value, plan_hash_value) 149 | and dbid = &v_xa_dbid 150 | ) 151 | , hierarchy_data as ( 152 | select id, parent_id, plan_hash_value, object_owner, object_name 153 | from sql_plan_data 154 | start with id = 0 155 | connect by prior id = parent_id 156 | and prior plan_hash_value = plan_hash_value 157 | order siblings by id desc 158 | ) 159 | , ordered_hierarchy_data as ( 160 | select id 161 | , parent_id 162 | , plan_hash_value 163 | , object_owner 164 | , object_name 165 | , row_number() over (partition by plan_hash_value order by rownum desc) as order_id 166 | , max(id) over (partition by plan_hash_value) as max_id 167 | from hierarchy_data 168 | ) 169 | , xplan_data as ( 170 | select /*+ ordered use_nl(o) */ 171 | x.plan_table_output 172 | , o.id 173 | , o.parent_id 174 | , o.order_id 175 | , o.max_id 176 | , o.object_owner 177 | , o.object_name 178 | , p.plan_hash_value 179 | , count(*) over () as row_count 180 | from ( 181 | select distinct plan_hash_value 182 | from ordered_hierarchy_data 183 | ) p 184 | cross join 185 | table(dbms_xplan.display_awr('&v_xa_sql_id',p.plan_hash_value,&v_xa_dbid,'&v_xa_format')) x 186 | left outer join 187 | ordered_hierarchy_data o 188 | on ( o.plan_hash_value = p.plan_hash_value 189 | and o.id = case 190 | when regexp_like(x.plan_table_output, '^\|[\* 0-9]+\|') 191 | then to_number(regexp_substr(x.plan_table_output, '[0-9]+')) 192 | end) 193 | ) 194 | select plan_table_output 195 | from xplan_data 196 | model 197 | dimension by (plan_hash_value as phv, rownum as r) 198 | measures (plan_table_output, 199 | id, 200 | max_id as mid, 201 | parent_id as pid, 202 | order_id as oid, 203 | object_owner as owner, 204 | object_name as oname, 205 | nullif(object_owner || '.', '.') || object_name as ownname, 206 | max(length(object_owner || '.' || object_name)) over () as maxownnamelen, 207 | max(length(object_owner || '.' || object_name)) over () - max(length(object_name)) over () as ownnamepad, 208 | greatest(max(length(max_id)) over () + 3, 6) as csize, 209 | cast(null as varchar2(128)) as inject, 210 | row_count as rc) 211 | rules sequential order ( 212 | inject[phv,r] = case 213 | when id[cv(),cv()+1] = 0 214 | or id[cv(),cv()+3] = 0 215 | or id[cv(),cv()-1] = mid[cv(),cv()-1] 216 | then rpad('-', csize[cv(),cv()]*2 + ownnamepad[cv(),cv()], '-') 217 | when id[cv(),cv()+2] = 0 218 | then '|' || lpad('Pid |', csize[cv(),cv()]) || lpad('Ord |', csize[cv(),cv()]) 219 | when id[cv(),cv()] is not null 220 | then '|' || lpad(pid[cv(),cv()] || ' |', csize[cv(),cv()]) || lpad(oid[cv(),cv()] || ' |', csize[cv(),cv()]) 221 | end, 222 | plan_table_output[phv,r] = case 223 | when inject[cv(),cv()] like '---%' 224 | then inject[cv(),cv()] || plan_table_output[cv(),cv()] 225 | when inject[cv(),cv()] is not null 226 | then regexp_replace(plan_table_output[cv(),cv()], '\|', inject[cv(),cv()], 1, 2) 227 | else plan_table_output[cv(),cv()] 228 | end, 229 | plan_table_output[phv,r] order by r = case 230 | when plan_table_output[cv(),cv()] like '|%' 231 | then case 232 | when id[cv(),cv()+2] = 0 233 | then regexp_replace(plan_table_output[cv(),cv()], '(\| Name[ ]+)', '\1' || rpad(' ', ownnamepad[cv(),cv()])) 234 | else case 235 | when oname[cv(),cv()] is not null 236 | then regexp_replace(plan_table_output[cv(),cv()], '[^\|]+', rpad(' ' || ownname[cv(),cv()], maxownnamelen[cv(),cv()] + 2), 1, 5) 237 | else regexp_replace(plan_table_output[cv(),cv()], '(\|.)', '\1' || rpad(' ', ownnamepad[cv(),cv()]), 1, 5) 238 | end 239 | end 240 | else plan_table_output[cv(),cv()] 241 | end || 242 | case 243 | when cv(r) = rc[cv(),cv()] 244 | then chr(10) || 245 | 'About' || chr(10) || 246 | '------' || chr(10) || 247 | ' - XPlan v&v_xa_version by Adrian Billington (http://www.oracle-developer.net)' 248 | end 249 | ) 250 | order by r; 251 | 252 | 253 | -- Teardown... 254 | -- ----------- 255 | undefine v_xa_sql_id 256 | undefine v_xa_plan_hash_value 257 | undefine v_xa_dbid 258 | undefine v_xa_format 259 | undefine v_xa_version 260 | undefine 1 261 | undefine 2 262 | undefine 3 263 | -------------------------------------------------------------------------------- /xplan.display_cursor.sql: -------------------------------------------------------------------------------- 1 | 2 | -- ---------------------------------------------------------------------------------------------- 3 | -- 4 | -- Utility: XPLAN 5 | -- 6 | -- Script: xplan.display_cursor.sql 7 | -- 8 | -- Version: 1.3 9 | -- 10 | -- Author: Adrian Billington 11 | -- www.oracle-developer.net 12 | -- (c) oracle-developer.net 13 | -- 14 | -- Description: A free-standing SQL wrapper over DBMS_XPLAN. Provides access to the 15 | -- DBMS_XPLAN.DISPLAY_CURSOR pipelined function for a given SQL_ID and CHILD_NO. 16 | -- 17 | -- The XPLAN utility has one purpose: to include the parent operation ID (PID) 18 | -- and an execution order column (OID) in the plan output. This makes plan 19 | -- interpretation easier for larger or more complex execution plans. Version 1.3 20 | -- has also added the object owner name to the output for more clarity. 21 | -- 22 | -- 23 | -- See the following example for details. 24 | -- 25 | -- Example: DBMS_XPLAN output (format BASIC): 26 | -- ------------------------------------------------ 27 | -- | Id | Operation | Name | 28 | -- ------------------------------------------------ 29 | -- | 0 | SELECT STATEMENT | | 30 | -- | 1 | MERGE JOIN | | 31 | -- | 2 | TABLE ACCESS BY INDEX ROWID| DEPT | 32 | -- | 3 | INDEX FULL SCAN | PK_DEPT | 33 | -- | 4 | SORT JOIN | | 34 | -- | 5 | TABLE ACCESS FULL | EMP | 35 | -- ------------------------------------------------ 36 | -- 37 | -- Equivalent XPLAN output (format BASIC): 38 | -- ------------------------------------------------------------------ 39 | -- | Id | Pid | Ord | Operation | Name | 40 | -- ------------------------------------------------------------------ 41 | -- | 0 | | 6 | SELECT STATEMENT | | 42 | -- | 1 | 0 | 5 | MERGE JOIN | | 43 | -- | 2 | 1 | 2 | TABLE ACCESS BY INDEX ROWID| SCOTT.DEPT | 44 | -- | 3 | 2 | 1 | INDEX FULL SCAN | SCOTT.PK_DEPT | 45 | -- | 4 | 1 | 4 | SORT JOIN | | 46 | -- | 5 | 4 | 3 | TABLE ACCESS FULL | SCOTT.EMP | 47 | -- ------------------------------------------------------------------ 48 | -- 49 | -- Usage: @xplan.display_cursor.sql [cursor_child_number] [format] 50 | -- 51 | -- Parameters: 1) sql_id - OPTIONAL (defaults to last executed SQL_ID) 52 | -- 2) sql_child_number - OPTIONAL (defaults to 0) 53 | -- 3) plan_format - OPTIONAL (defaults to TYPICAL) 54 | -- 55 | -- Examples: 1) Plan for last executed SQL (needs serveroutput off) 56 | -- --------------------------------------------------- 57 | -- @xplan.display_cursor.sql 58 | -- 59 | -- 2) Plan for a SQL_ID with default child number 60 | -- ------------------------------------------- 61 | -- @xplan.display_cursor.sql 9vfvgsk7mtkr4 62 | -- 63 | -- 3) Plan for a SQL_ID with specific child number 64 | -- -------------------------------------------- 65 | -- @xplan.display_cursor.sql 9vfvgsk7mtkr4 1 66 | -- 67 | -- 4) Plan for a SQL_ID with default child number and non-default format 68 | -- ------------------------------------------------------------------ 69 | -- @xplan.display_cursor.sql 9vfvgsk7mtkr4 "" "basic +projection" 70 | -- 71 | -- 5) Plan for a SQL_ID, specific child number and non-default format 72 | -- --------------------------------------------------------------- 73 | -- @xplan.display_cursor.sql 9vfvgsk7mtkr4 1 "advanced" 74 | -- 75 | -- Versions: This utility will work for all versions of 10g and upwards. 76 | -- 77 | -- Required: 1) Access to GV$SESSION, GV$SQL_PLAN 78 | -- 79 | -- Notes: An XPLAN PL/SQL package is also available. This has wrappers for all of the 80 | -- DBMS_XPLAN pipelined functions, but requires the creation of objects. 81 | -- 82 | -- Credits: 1) James Padfield for the hierarchical query to order the plan operations. 83 | -- 2) Paul Vale for the suggestion to turn XPLAN.DISPLAY_CURSOR into a standalone 84 | -- SQL script, including a prototype. 85 | -- 86 | -- Disclaimer: http://www.oracle-developer.net/disclaimer.php 87 | -- 88 | -- ---------------------------------------------------------------------------------------------- 89 | 90 | set define on 91 | define v_xc_version = 1.3 92 | 93 | -- Fetch the previous SQL details in case they're not supplied... 94 | -- -------------------------------------------------------------- 95 | set termout off 96 | column prev_sql_id new_value v_xc_prev_sql_id 97 | column prev_child_number new_value v_xc_prev_child_no 98 | select prev_sql_id 99 | , prev_child_number 100 | from gv$session 101 | where inst_id = sys_context('userenv','instance') 102 | and sid = sys_context('userenv','sid') 103 | and username is not null 104 | and prev_hash_value <> 0; 105 | 106 | -- Initialise variables 1,2,3 in case they aren't supplied... 107 | -- ---------------------------------------------------------- 108 | column 1 new_value 1 109 | column 2 new_value 2 110 | column 3 new_value 3 111 | select null as "1" 112 | , null as "2" 113 | , null as "3" 114 | from dual 115 | where 1=2; 116 | 117 | -- Finally prepare the inputs to the main Xplan SQL... 118 | -- --------------------------------------------------- 119 | column sql_id new_value v_xc_sql_id 120 | column child_no new_value v_xc_child_no 121 | column format new_value v_xc_format 122 | select nvl('&1', '&v_xc_prev_sql_id') as sql_id 123 | , to_number(nvl('&2', '&v_xc_prev_child_no')) as child_no 124 | , nvl('&3', 'typical') as format 125 | from dual; 126 | 127 | -- Main Xplan SQL... 128 | -- ----------------- 129 | set termout on lines 200 pages 1000 130 | col plan_table_output format a200 131 | 132 | with sql_plan_data as ( 133 | select id, parent_id, object_owner, object_name 134 | from gv$sql_plan 135 | where inst_id = sys_context('userenv','instance') 136 | and sql_id = '&v_xc_sql_id' 137 | and child_number = to_number('&v_xc_child_no') 138 | ) 139 | , hierarchy_data as ( 140 | select id, parent_id, object_owner, object_name 141 | from sql_plan_data 142 | start with id = 0 143 | connect by prior id = parent_id 144 | order siblings by id desc 145 | ) 146 | , ordered_hierarchy_data as ( 147 | select id 148 | , parent_id 149 | , object_owner 150 | , object_name 151 | , row_number() over (order by rownum desc) as order_id 152 | , max(id) over () as max_id 153 | from hierarchy_data 154 | ) 155 | , xplan_data as ( 156 | select /*+ ordered use_nl(o) */ 157 | x.plan_table_output 158 | , o.id 159 | , o.parent_id 160 | , o.order_id 161 | , o.max_id 162 | , o.object_owner 163 | , o.object_name 164 | , count(*) over () as row_count 165 | from table(dbms_xplan.display_cursor('&v_xc_sql_id',to_number('&v_xc_child_no'),'&v_xc_format')) x 166 | left outer join 167 | ordered_hierarchy_data o 168 | on (o.id = case 169 | when regexp_like(x.plan_table_output, '^\|[\* 0-9]+\|') 170 | then to_number(regexp_substr(x.plan_table_output, '[0-9]+')) 171 | end) 172 | ) 173 | select plan_table_output 174 | from xplan_data 175 | model 176 | dimension by (rownum as r) 177 | measures (plan_table_output, 178 | id, 179 | max_id as mid, 180 | parent_id as pid, 181 | order_id as oid, 182 | object_owner as owner, 183 | object_name as oname, 184 | nullif(object_owner || '.', '.') || object_name as ownname, 185 | max(length(object_owner || '.' || object_name)) over () as maxownnamelen, 186 | max(length(object_owner || '.' || object_name)) over () - max(length(object_name)) over () as ownnamepad, 187 | greatest(max(length(max_id)) over () + 3, 6) as csize, 188 | cast(null as varchar2(128)) as inject, 189 | row_count as rc) 190 | rules sequential order ( 191 | inject[r] = case 192 | when id[cv()+1] = 0 193 | or id[cv()+3] = 0 194 | or id[cv()-1] = mid[cv()-1] 195 | then rpad('-', csize[cv()]*2 + ownnamepad[cv()], '-') 196 | when id[cv()+2] = 0 197 | then '|' || lpad('Pid |', csize[cv()]) || lpad('Ord |', csize[cv()]) 198 | when id[cv()] is not null 199 | then '|' || lpad(pid[cv()] || ' |', csize[cv()]) || lpad(oid[cv()] || ' |', csize[cv()]) 200 | end, 201 | plan_table_output[r] = case 202 | when inject[cv()] like '---%' 203 | then inject[cv()] || plan_table_output[cv()] 204 | when inject[cv()] is not null 205 | then regexp_replace(plan_table_output[cv()], '\|', inject[cv()], 1, 2) 206 | else plan_table_output[cv()] 207 | end, 208 | plan_table_output[r] order by r = case 209 | when plan_table_output[cv()] like '|%' 210 | then case 211 | when id[cv()+2] = 0 212 | then regexp_replace(plan_table_output[cv()], '(\| Name[ ]+)', '\1' || rpad(' ', ownnamepad[cv()])) 213 | else case 214 | when oname[cv()] is not null 215 | then regexp_replace(plan_table_output[cv()], '[^\|]+', rpad(' ' || ownname[cv()], maxownnamelen[cv()] + 2), 1, 5) 216 | else regexp_replace(plan_table_output[cv()], '(\|.)', '\1' || rpad(' ', ownnamepad[cv()]), 1, 5) 217 | end 218 | end 219 | else plan_table_output[cv()] 220 | end || 221 | case 222 | when cv(r) = rc[cv()] 223 | then chr(10) || 224 | 'About' || chr(10) || 225 | '------' || chr(10) || 226 | ' - XPlan v&v_xc_version by Adrian Billington (http://www.oracle-developer.net)' 227 | end 228 | ) 229 | order by r; 230 | 231 | 232 | -- Teardown... 233 | -- ----------- 234 | undefine v_xc_sql_id 235 | undefine v_xc_child_no 236 | undefine v_xc_format 237 | undefine v_xc_prev_sql_id 238 | undefine v_xc_prev_child_no 239 | undefine v_xc_version 240 | undefine 1 241 | undefine 2 242 | undefine 3 243 | -------------------------------------------------------------------------------- /xplan.package.sql: -------------------------------------------------------------------------------- 1 | 2 | -- ---------------------------------------------------------------------------------------------- 3 | -- 4 | -- Script: xplan.package.sql 5 | -- 6 | -- Version: 1.2 7 | -- 8 | -- Author: Adrian Billington 9 | -- www.oracle-developer.net 10 | -- 11 | -- Description: Creates a package named XPLAN as a wrapper over DBMS_XPLAN. Provides access to 12 | -- the following DBMS_XPLAN pipelined functions: 13 | -- 14 | -- 1. DISPLAY; 15 | -- 2. DISPLAY_CURSOR; 16 | -- 3. DISPLAY_AWR (optional - see Notes section for licence implications). 17 | -- 18 | -- The XPLAN wrapper package has one purpose: to include the parent operation ID 19 | -- and "order" columns in the plan output. This makes plan interpretation easier 20 | -- for larger or more complex execution plans. See the following example for 21 | -- details. 22 | -- 23 | -- Example: DBMS_XPLAN output (format BASIC): 24 | -- ------------------------------------------------ 25 | -- | Id | Operation | Name | 26 | -- ------------------------------------------------ 27 | -- | 0 | SELECT STATEMENT | | 28 | -- | 1 | MERGE JOIN | | 29 | -- | 2 | TABLE ACCESS BY INDEX ROWID| DEPT | 30 | -- | 3 | INDEX FULL SCAN | PK_DEPT | 31 | -- | 4 | SORT JOIN | | 32 | -- | 5 | TABLE ACCESS FULL | EMP | 33 | -- ------------------------------------------------ 34 | -- 35 | -- Equivalent XPLAN output (format BASIC): 36 | -- -------------------------------------------------------------- 37 | -- | Id | PID | Order | Operation | Name | 38 | -- -------------------------------------------------------------- 39 | -- | 0 | | 6 | SELECT STATEMENT | | 40 | -- | 1 | 0 | 5 | MERGE JOIN | | 41 | -- | 2 | 1 | 2 | TABLE ACCESS BY INDEX ROWID| DEPT | 42 | -- | 3 | 2 | 1 | INDEX FULL SCAN | PK_DEPT | 43 | -- | 4 | 1 | 4 | SORT JOIN | | 44 | -- | 5 | 4 | 3 | TABLE ACCESS FULL | EMP | 45 | -- -------------------------------------------------------------- 46 | -- 47 | -- Usage: SELECT * FROM TABLE(XPLAN.DISPLAY(...)); 48 | -- SELECT * FROM TABLE(XPLAN.DISPLAY_CURSOR(...)); 49 | -- SELECT * FROM TABLE(XPLAN.DISPLAY_AWR(...)); 50 | -- 51 | -- Usage for XPLAN is the same as for DBMS_XPLAN. See the DBMS_XPLAN 52 | -- documentation for all options. 53 | -- 54 | -- Note that the only exception to this is that XPLAN.DISPLAY does not contain 55 | -- the FILTER_PREDS parameter available in 10.2+ versions of DBMS_XPLAN.DISPLAY 56 | -- (this parameter enables us to limit the data being returned from an Explain 57 | -- Plan but is of quite limited use). 58 | -- 59 | -- See the Notes section below for details on the licensing implications of 60 | -- using XPLAN.DISPLAY_AWR. 61 | -- 62 | -- Versions: This utility will work for all versions of 10g and upwards. 63 | -- 64 | -- Required: 1) PLAN_TABLE of at least 10.1 format 65 | -- 66 | -- 2) Either: 67 | -- SELECT ANY DICTIONARY 68 | -- Or: 69 | -- SELECT on V$DATABASE 70 | -- SELECT on V$SQL_PLAN 71 | -- SELECT on V$SESSION 72 | -- SELECT on V$MYSTAT 73 | -- SELECT on DBA_HIST_SQL_PLAN 74 | -- Or: 75 | -- SELECT_CATALOG_ROLE 76 | -- 77 | -- 3) CREATE TYPE, CREATE PROCEDURE 78 | -- 79 | -- Note that the SQL statements that access V$ views are all dynamic and the 80 | -- package uses invoker rights. This means that the package will compile in 81 | -- constrained developer environments where explicit privileges on V$ views 82 | -- are not granted and access to the views is only available via roles such as 83 | -- SELECT_CATALOG_ROLE. 84 | -- 85 | -- Notes: *** IMPORTANT: PLEASE READ *** 86 | -- 87 | -- 1) Oracle license implications 88 | -- --------------------------- 89 | -- The AWR functionality of XPLAN accesses a DBA_HIST% view which means 90 | -- that it requires an Oracle Diagnostic Pack license. The XPLAN.DISPLAY_AWR 91 | -- pipelined function is therefore disabled by default. It can be included 92 | -- by modifying two substitution variables at the start of the script. Please 93 | -- ensure that you are licensed to use this feature: the author accepts 94 | -- no responsibility for any use of this functionality in an unlicensed database. 95 | -- 96 | -- Installation: Installation requires SQL*Plus or any IDE that supports substitution 97 | -- variables and SQL*Plus SET commands. To install, simply run the script in 98 | -- the target schema. 99 | -- 100 | -- Creates: 1) XPLAN_OT object type 101 | -- 2) XPLAN_NTT collection type 102 | -- 3) XPLAN package 103 | -- 104 | -- Removal: 1) DROP PACKAGE xplan; 105 | -- 3) DROP TYPE xplan_ntt; 106 | -- 4) DROP TYPE xplan_ot; 107 | -- 108 | -- Credits: James Padfield for the hierarchical query to order the plan operations. 109 | -- 110 | -- Disclaimer: http://www.oracle-developer.net/disclaimer.php 111 | -- 112 | -- ---------------------------------------------------------------------------------------------- 113 | 114 | -- 115 | -- Define the "commenting-out" substitution variables for the AWR elements of this utility. The 116 | -- default is commented out. To include the AWR functionality, change the variables to " " (i.e. 117 | -- a single space). 118 | -- 119 | 120 | SET DEFINE ON 121 | DEFINE _awr_start = "/*" 122 | DEFINE _awr_end = "*/" 123 | 124 | -- 125 | -- Supporting types for the pipelined functions... 126 | -- 127 | 128 | CREATE OR REPLACE TYPE xplan_ot AS OBJECT 129 | ( plan_table_output VARCHAR2(300) ); 130 | / 131 | 132 | CREATE OR REPLACE TYPE xplan_ntt AS 133 | TABLE OF xplan_ot; 134 | / 135 | 136 | -- 137 | -- Xplan package... 138 | -- 139 | 140 | CREATE OR REPLACE PACKAGE xplan AUTHID CURRENT_USER AS 141 | 142 | FUNCTION display( p_table_name IN VARCHAR2 DEFAULT 'PLAN_TABLE', 143 | p_statement_id IN VARCHAR2 DEFAULT NULL, 144 | p_format IN VARCHAR2 DEFAULT 'TYPICAL' ) 145 | RETURN xplan_ntt PIPELINED; 146 | 147 | FUNCTION display_cursor( p_sql_id IN VARCHAR2 DEFAULT NULL, 148 | p_cursor_child_no IN INTEGER DEFAULT 0, 149 | p_format IN VARCHAR2 DEFAULT 'TYPICAL' ) 150 | RETURN xplan_ntt PIPELINED; 151 | 152 | &_awr_start 153 | FUNCTION display_awr( p_sql_id IN VARCHAR2, 154 | p_plan_hash_value IN INTEGER DEFAULT NULL, 155 | p_db_id IN INTEGER DEFAULT NULL, 156 | p_format IN VARCHAR2 DEFAULT 'TYPICAL' ) 157 | RETURN xplan_ntt PIPELINED; 158 | &_awr_end 159 | 160 | END xplan; 161 | / 162 | 163 | CREATE OR REPLACE PACKAGE BODY xplan AS 164 | 165 | TYPE ntt_map_binds IS TABLE OF VARCHAR2(100); 166 | 167 | TYPE rt_map IS RECORD 168 | ( ord PLS_INTEGER 169 | , pid PLS_INTEGER ); 170 | 171 | TYPE aat_map IS TABLE OF rt_map 172 | INDEX BY PLS_INTEGER; 173 | 174 | g_map aat_map; 175 | g_hdrs PLS_INTEGER; 176 | g_len PLS_INTEGER; 177 | g_pad VARCHAR2(300); 178 | 179 | ---------------------------------------------------------------------------- 180 | PROCEDURE reset_state IS 181 | BEGIN 182 | g_hdrs := 0; 183 | g_len := 0; 184 | g_pad := NULL; 185 | g_map.DELETE; 186 | END reset_state; 187 | 188 | ---------------------------------------------------------------------------- 189 | FUNCTION info RETURN xplan_ot IS 190 | BEGIN 191 | RETURN xplan_ot(CHR(10) || 192 | 'About' || CHR(10) || 193 | '-----' || CHR(10) || 194 | ' - XPlan v1.2 by Adrian Billington (http://www.oracle-developer.net)' ); 195 | END info; 196 | 197 | ---------------------------------------------------------------------------- 198 | PROCEDURE build_map( p_sql IN VARCHAR2, 199 | p_binds IN ntt_map_binds ) IS 200 | 201 | TYPE rt_id_data IS RECORD 202 | ( id PLS_INTEGER 203 | , pid PLS_INTEGER 204 | , ord PLS_INTEGER ); 205 | 206 | TYPE aat_id_data IS TABLE OF rt_id_data 207 | INDEX BY PLS_INTEGER; 208 | 209 | aa_ids aat_id_data; 210 | v_cursor SYS_REFCURSOR; 211 | v_sql VARCHAR2(32767); 212 | 213 | BEGIN 214 | 215 | -- Build SQL template... 216 | -- --------------------- 217 | v_sql := 'WITH sql_plan_data AS ( ' || 218 | p_sql || ' 219 | ) 220 | , hierarchical_sql_plan_data AS ( 221 | SELECT id 222 | , parent_id 223 | FROM sql_plan_data 224 | START WITH id = 0 225 | CONNECT BY PRIOR id = parent_id 226 | ORDER SIBLINGS BY id DESC 227 | ) 228 | SELECT id 229 | , parent_id 230 | , ROW_NUMBER() OVER (ORDER BY ROWNUM DESC) AS ord 231 | FROM hierarchical_sql_plan_data'; 232 | 233 | -- Binds will differ according to plan type... 234 | -- ------------------------------------------- 235 | CASE p_binds.COUNT 236 | WHEN 0 237 | THEN 238 | OPEN v_cursor FOR v_sql; 239 | WHEN 1 240 | THEN 241 | OPEN v_cursor FOR v_sql USING p_binds(1); 242 | WHEN 2 243 | THEN 244 | OPEN v_cursor FOR v_sql USING p_binds(1), 245 | TO_NUMBER(p_binds(2)); 246 | WHEN 3 247 | THEN 248 | OPEN v_cursor FOR v_sql USING p_binds(1), 249 | TO_NUMBER(p_binds(2)), 250 | TO_NUMBER(p_binds(3)); 251 | END CASE; 252 | 253 | -- Fetch the IDs and order data... 254 | -- ------------------------------- 255 | FETCH v_cursor BULK COLLECT INTO aa_ids; 256 | CLOSE v_cursor; 257 | 258 | -- Populate the map array... 259 | -- ------------------------- 260 | FOR i IN 1 .. aa_ids.COUNT LOOP 261 | g_map(aa_ids(i).id).ord := aa_ids(i).ord; 262 | g_map(aa_ids(i).id).pid := aa_ids(i).pid; 263 | END LOOP; 264 | 265 | -- Use the map to determine padding needed to slot in our columns... 266 | -- ----------------------------------------------------------------- 267 | IF g_map.COUNT > 0 THEN 268 | g_len := LEAST(LENGTH(g_map.LAST) + 13, 14); 269 | g_pad := LPAD('-', g_len, '-'); 270 | END IF; 271 | 272 | END build_map; 273 | 274 | ---------------------------------------------------------------------------- 275 | FUNCTION prepare_row( p_curr IN VARCHAR2, 276 | p_next IN VARCHAR2 ) RETURN xplan_ot IS 277 | 278 | v_id PLS_INTEGER; 279 | v_row VARCHAR2(4000); 280 | v_hdr VARCHAR2(64) := '%|%Id%|%Operation%|%'; 281 | 282 | BEGIN 283 | 284 | -- Intercept the plan section to include new columns for the 285 | -- the parent ID and operation order that we mapped earlier. 286 | -- The plan output itself will be bound by dashed lines. 287 | -- We need to add in additional dashes, column headings 288 | -- and column values... 289 | -- ------------------------------------------------------------- 290 | 291 | IF p_curr LIKE '---%' THEN 292 | 293 | IF p_next LIKE v_hdr THEN 294 | g_hdrs := 1; 295 | v_row := g_pad || p_curr; 296 | ELSIF g_hdrs BETWEEN 1 AND 3 THEN 297 | g_hdrs := g_hdrs + 1; 298 | v_row := g_pad || p_curr; 299 | ELSE 300 | v_row := p_curr; 301 | END IF; 302 | 303 | ELSIF p_curr LIKE v_hdr THEN 304 | 305 | v_row := REGEXP_REPLACE( 306 | p_curr, '\|', 307 | RPAD('|', GREATEST(g_len-12, 2)) || 'PID ' || 308 | RPAD('|', GREATEST(g_len-13, 2)) || 'Order |', 309 | 1, 2 310 | ); 311 | 312 | ELSIF REGEXP_LIKE(p_curr, '^\|[\* 0-9]+\|') THEN 313 | 314 | v_id := REGEXP_SUBSTR(p_curr, '[0-9]+'); 315 | v_row := REGEXP_REPLACE( 316 | p_curr, '\|', 317 | '|' || LPAD(NVL(TO_CHAR(g_map(v_id).pid),' '), GREATEST(g_len-12, 4)) 318 | || ' |' || LPAD(g_map(v_id).ord, GREATEST(g_len-13, 6)) || ' |', 319 | 1, 2 320 | ); 321 | ELSE 322 | v_row := p_curr; 323 | END IF; 324 | 325 | RETURN xplan_ot(v_row); 326 | 327 | END prepare_row; 328 | 329 | ---------------------------------------------------------------------------- 330 | FUNCTION display( p_table_name IN VARCHAR2 DEFAULT 'PLAN_TABLE', 331 | p_statement_id IN VARCHAR2 DEFAULT NULL, 332 | p_format IN VARCHAR2 DEFAULT 'TYPICAL' ) 333 | RETURN xplan_ntt PIPELINED IS 334 | 335 | v_plan_table VARCHAR2(128) := NVL(p_table_name, 'PLAN_TABLE'); 336 | v_sql VARCHAR2(512); 337 | v_binds ntt_map_binds := ntt_map_binds(); 338 | 339 | BEGIN 340 | 341 | reset_state(); 342 | 343 | -- Prepare the inputs for the parent ID and order map... 344 | -- ----------------------------------------------------- 345 | v_sql := 'SELECT id, parent_id 346 | FROM ' || v_plan_table || ' 347 | WHERE plan_id = (SELECT MAX(plan_id) 348 | FROM ' || v_plan_table || ' 349 | WHERE id = 0 %bind%) 350 | ORDER BY id'; 351 | 352 | IF p_statement_id IS NULL THEN 353 | v_sql := REPLACE(v_sql, '%bind%'); 354 | ELSE 355 | v_sql := REPLACE(v_sql, '%bind%', 'AND statement_id = :bv_statement_id'); 356 | v_binds := ntt_map_binds(p_statement_id); 357 | END IF; 358 | 359 | -- Build the map... 360 | -- -------------------------------------------------- 361 | build_map(v_sql, v_binds); 362 | 363 | -- Now we can call DBMS_XPLAN to output the plan... 364 | -- ------------------------------------------------ 365 | PIPE ROW (info); 366 | 367 | FOR r_plan IN ( SELECT plan_table_output AS p 368 | , LEAD(plan_table_output) OVER (ORDER BY ROWNUM) AS np 369 | FROM TABLE( 370 | DBMS_XPLAN.DISPLAY( 371 | v_plan_table, p_statement_id, p_format 372 | )) 373 | ORDER BY 374 | ROWNUM) 375 | LOOP 376 | IF g_map.COUNT > 0 THEN 377 | PIPE ROW (prepare_row(r_plan.p, r_plan.np)); 378 | ELSE 379 | PIPE ROW (xplan_ot(r_plan.p)); 380 | END IF; 381 | END LOOP; 382 | 383 | PIPE ROW (info); 384 | 385 | reset_state(); 386 | RETURN; 387 | 388 | END display; 389 | 390 | ---------------------------------------------------------------------------- 391 | FUNCTION display_cursor( p_sql_id IN VARCHAR2 DEFAULT NULL, 392 | p_cursor_child_no IN INTEGER DEFAULT 0, 393 | p_format IN VARCHAR2 DEFAULT 'TYPICAL' ) 394 | RETURN xplan_ntt PIPELINED IS 395 | 396 | v_sql_id VARCHAR2(30); 397 | v_child_no INTEGER; 398 | v_sql VARCHAR2(256); 399 | v_binds ntt_map_binds := ntt_map_binds(); 400 | 401 | BEGIN 402 | 403 | reset_state(); 404 | 405 | -- Set a SQL_ID if default parameters passed... 406 | -- -------------------------------------------- 407 | IF p_sql_id IS NULL THEN 408 | EXECUTE IMMEDIATE 'SELECT prev_sql_id, prev_child_number 409 | FROM v$session 410 | WHERE sid = (SELECT m.sid FROM v$mystat m WHERE ROWNUM = 1) 411 | AND username IS NOT NULL 412 | AND prev_hash_value <> 0' 413 | INTO v_sql_id, v_child_no; 414 | ELSE 415 | v_sql_id := p_sql_id; 416 | v_child_no := NVL(p_cursor_child_no,0); 417 | END IF; 418 | 419 | -- Prepare the inputs for the parent ID and order map... 420 | -- ----------------------------------------------------- 421 | v_sql := 'SELECT id, parent_id 422 | FROM v$sql_plan 423 | WHERE sql_id = :bv_sql_id 424 | AND child_number = :bv_child_no'; 425 | 426 | v_binds := ntt_map_binds(v_sql_id, v_child_no); 427 | 428 | -- Build the plan map from the SQL... 429 | -- ---------------------------------------- 430 | build_map(v_sql, v_binds); 431 | 432 | -- Now we can call DBMS_XPLAN to output the plan... 433 | -- ------------------------------------------------ 434 | FOR r_plan IN ( SELECT plan_table_output AS p 435 | , LEAD(plan_table_output) OVER (ORDER BY ROWNUM) AS np 436 | FROM TABLE( 437 | DBMS_XPLAN.DISPLAY_CURSOR( 438 | v_sql_id, v_child_no, p_format 439 | )) 440 | ORDER BY 441 | ROWNUM) 442 | LOOP 443 | IF g_map.COUNT > 0 THEN 444 | PIPE ROW (prepare_row(r_plan.p, r_plan.np)); 445 | ELSE 446 | PIPE ROW (xplan_ot(r_plan.p)); 447 | END IF; 448 | END LOOP; 449 | 450 | PIPE ROW (info); 451 | 452 | reset_state(); 453 | RETURN; 454 | 455 | END display_cursor; 456 | 457 | &_awr_start 458 | ---------------------------------------------------------------------------- 459 | FUNCTION display_awr( p_sql_id IN VARCHAR2, 460 | p_plan_hash_value IN INTEGER DEFAULT NULL, 461 | p_db_id IN INTEGER DEFAULT NULL, 462 | p_format IN VARCHAR2 DEFAULT 'TYPICAL' ) 463 | RETURN xplan_ntt PIPELINED IS 464 | 465 | TYPE rt_awr IS RECORD 466 | ( sql_id VARCHAR2(30) 467 | , plan_hash_value INTEGER 468 | , dbid INTEGER ); 469 | 470 | TYPE aat_awr IS TABLE OF rt_awr 471 | INDEX BY PLS_INTEGER; 472 | 473 | aa_awr aat_awr; 474 | v_sql VARCHAR2(256); 475 | v_binds ntt_map_binds := ntt_map_binds(); 476 | 477 | BEGIN 478 | 479 | reset_state(); 480 | 481 | -- Prepare the inputs for the parent ID and order map... 482 | -- ----------------------------------------------------- 483 | v_sql := 'SELECT id, parent_id 484 | FROM dba_hist_sql_plan 485 | WHERE sql_id = :bv_sql_id 486 | AND plan_hash_value = :bv_plan_hash_value 487 | AND dbid = :bv_dbid'; 488 | 489 | -- Determine all plans for the sql_id... 490 | -- ------------------------------------- 491 | EXECUTE IMMEDIATE 'SELECT DISTINCT 492 | sql_id 493 | , plan_hash_value 494 | , dbid 495 | FROM dba_hist_sql_plan 496 | WHERE sql_id = :bv_sql_id 497 | AND plan_hash_value = NVL(:bv_plan_hash_value, plan_hash_value) 498 | AND dbid = NVL(:bv_db_id, (SELECT dbid FROM v$database)) 499 | ORDER BY 500 | plan_hash_value' 501 | BULK COLLECT INTO aa_awr 502 | USING p_sql_id, p_plan_hash_value, p_db_id; 503 | 504 | FOR i IN 1 .. aa_awr.COUNT LOOP 505 | 506 | -- Prepare the binds and build the order map... 507 | -- -------------------------------------------- 508 | v_binds := ntt_map_binds(aa_awr(i).sql_id, 509 | aa_awr(i).plan_hash_value, 510 | aa_awr(i).dbid); 511 | 512 | -- Build the plan map from the SQL... 513 | -- ---------------------------------- 514 | build_map(v_sql, v_binds); 515 | 516 | -- Now we can call DBMS_XPLAN to output the plan... 517 | -- ------------------------------------------------ 518 | FOR r_plan IN ( SELECT plan_table_output AS p 519 | , LEAD(plan_table_output) OVER (ORDER BY ROWNUM) AS np 520 | FROM TABLE( 521 | DBMS_XPLAN.DISPLAY_AWR( 522 | aa_awr(i).sql_id, aa_awr(i).plan_hash_value, 523 | aa_awr(i).dbid, p_format 524 | )) 525 | ORDER BY 526 | ROWNUM) 527 | LOOP 528 | IF g_map.COUNT > 0 THEN 529 | PIPE ROW (prepare_row(r_plan.p, r_plan.np)); 530 | ELSE 531 | PIPE ROW (xplan_ot(r_plan.p)); 532 | END IF; 533 | END LOOP; 534 | 535 | END LOOP; 536 | 537 | PIPE ROW (info); 538 | 539 | reset_state(); 540 | RETURN; 541 | 542 | END display_awr; 543 | &_awr_end 544 | 545 | END xplan; 546 | / 547 | 548 | UNDEFINE _awr_start 549 | UNDEFINE _awr_end 550 | 551 | --------------------------------------------------------------------------------