|
| 1 | +-- Copyright 2018 Tanel Poder. All rights reserved. More info at http://tanelpoder.com |
| 2 | +-- Licensed under the Apache License, Version 2.0. See LICENSE.txt for terms & conditions. |
| 3 | + |
| 4 | +------------------------------------------------------------------------------------------------------------------------ |
| 5 | +-- |
| 6 | +-- File name: asqlmon.sql (v1.2) |
| 7 | +-- |
| 8 | +-- Purpose: Report SQL-monitoring-style drill-down into where in an execution plan the execution time is spent |
| 9 | +-- |
| 10 | +-- Author: Tanel Poder |
| 11 | +-- |
| 12 | +-- Copyright: (c) https://tanelpoder.com - All rights reserved. |
| 13 | +-- |
| 14 | +-- Disclaimer: This script is provided "as is", no warranties nor guarantees are |
| 15 | +-- made. Use at your own risk :) |
| 16 | +-- |
| 17 | +-- Usage: @asqlmon <sqlid> <child#> <from_time> <to_time> |
| 18 | +-- |
| 19 | +-- Notes: This script runs on Oracle 11g+ and you should have the |
| 20 | +-- Diagnostics pack license for using it as it queries |
| 21 | +-- some separately licensed views. |
| 22 | +-- |
| 23 | +------------------------------------------------------------------------------------------------------------------------ |
| 24 | +SET LINESIZE 999 PAGESIZE 5000 TRIMOUT ON TRIMSPOOL ON |
| 25 | + |
| 26 | +COL asqlmon_operation HEAD Plan_Operation FOR a72 |
| 27 | +COL asqlmon_predicates HEAD PREDICATES FOR a100 word_wrap |
| 28 | +COL obj_alias_qbc_name FOR a40 |
| 29 | +COL options FOR a30 |
| 30 | + |
| 31 | +COL asqlmon_plan_hash_value HEAD PLAN_HASH_VALUE PRINT |
| 32 | +COL asqlmon_sql_id HEAD SQL_ID NOPRINT |
| 33 | +COL asqlmon_sql_child HEAD "CHILD" PRINT |
| 34 | +COL asqlmon_sample_time HEAD SAMPLE_HOUR |
| 35 | +COL projection FOR A520 |
| 36 | + |
| 37 | +COL pct_child HEAD "Activity %" FOR A8 |
| 38 | +COL pct_child_vis HEAD "Visual" FOR A12 |
| 39 | + |
| 40 | +COL asqlmon_id HEAD "ID" FOR 9999 |
| 41 | +COL asqlmon_parent_id HEAD "PID" FOR 9999 |
| 42 | + |
| 43 | + |
| 44 | +BREAK ON asqlmon_sql_id SKIP 1 ON asqlmon_sql_child SKIP 1 ON asqlmon_plan_hash_value SKIP 1 ON asqlmon_sample_time SKIP 1 DUP ON asqlmon_operation |
| 45 | + |
| 46 | +PROMPT |
| 47 | +PROMPT -- ASQLMon v1.1 - by Tanel Poder ( https://tanelpoder.com ) - Display SQL execution plan line level activity breakdown from ASH |
| 48 | + |
| 49 | +WITH sample_times AS ( |
| 50 | + select * from dual |
| 51 | +), |
| 52 | +sq AS ( |
| 53 | +SELECT |
| 54 | + count(*) samples |
| 55 | + , ash.sql_id |
| 56 | + , ash.sql_child_number |
| 57 | + , ash.sql_plan_hash_value |
| 58 | + , ash.sql_full_plan_hash_value |
| 59 | + , NVL(ash.sql_plan_line_id,1) sql_plan_line_id -- this is because simple "planless" operations like single-row insert |
| 60 | + , ash.sql_plan_operation |
| 61 | + , ash.sql_plan_options |
| 62 | + , ash.session_state |
| 63 | + , ash.event |
| 64 | +-- , AVG(ash.p3) avg_p3 -- p3 is sometimes useful for listing block counts for IO wait events |
| 65 | +FROM |
| 66 | + v$active_session_history ash |
| 67 | +WHERE |
| 68 | + 1=1 |
| 69 | +AND ash.sql_id LIKE '&1' |
| 70 | +AND ash.sql_child_number LIKE '&2' |
| 71 | +AND ash.sample_time BETWEEN &3 AND &4 |
| 72 | +GROUP BY |
| 73 | + ash.sql_id |
| 74 | + , ash.sql_child_number |
| 75 | + , ash.sql_plan_hash_value |
| 76 | + , ash.sql_full_plan_hash_value |
| 77 | + , NVL(ash.sql_plan_line_id,1) |
| 78 | + , ash.sql_plan_operation |
| 79 | + , ash.sql_plan_options |
| 80 | + , ash.session_state |
| 81 | + , ash.event |
| 82 | +) |
| 83 | +SELECT |
| 84 | + plan.sql_id asqlmon_sql_id |
| 85 | + , plan.child_number asqlmon_sql_child |
| 86 | + , plan.full_plan_hash_value asqlmon_full_plan_hash_value |
| 87 | + , plan.plan_hash_value asqlmon_plan_hash_value |
| 88 | + , sq.samples seconds |
| 89 | + , LPAD(TO_CHAR(ROUND(RATIO_TO_REPORT(sq.samples) OVER (PARTITION BY sq.sql_id, sq.sql_plan_hash_value) * 100, 1), 999.9)||' %',8) pct_child |
| 90 | + , '|'||RPAD( NVL( LPAD('#', ROUND(RATIO_TO_REPORT(sq.samples) OVER (PARTITION BY sq.sql_id, sq.sql_plan_hash_value) * 10), '#'), ' '), 10,' ')||'|' pct_child_vis |
| 91 | +--, LPAD(plan.id,4)||CASE WHEN parent_id IS NULL THEN ' ' ELSE ' <- ' END||LPAD(plan.parent_id,4) asqlmon_plan_id |
| 92 | + , plan.id asqlmon_id |
| 93 | + , plan.parent_id asqlmon_parent_id |
| 94 | + , LPAD(' ', depth, ' ') || plan.operation ||' '|| plan.options || NVL2(plan.object_name, ' ['||plan.object_name ||']', null) asqlmon_operation |
| 95 | + , sq.session_state |
| 96 | + , sq.event |
| 97 | +-- , sq.avg_p3 |
| 98 | + , plan.object_alias || CASE WHEN plan.qblock_name IS NOT NULL THEN ' ['|| plan.qblock_name || ']' END obj_alias_qbc_name |
| 99 | +-- , CASE WHEN plan.access_predicates IS NOT NULL THEN '[A:] '|| SUBSTR(plan.access_predicates,1,1990) END || CASE WHEN plan.filter_predicates IS NOT NULL THEN ' [F:] ' || SUBSTR(plan.filter_predicates,1,1990) END asqlmon_predicates |
| 100 | +-- , plan.projection |
| 101 | +FROM |
| 102 | + v$sql_plan plan |
| 103 | + , sq |
| 104 | +WHERE |
| 105 | + 1=1 |
| 106 | +AND sq.sql_id(+) = plan.sql_id |
| 107 | +AND sq.sql_child_number(+) = plan.child_number |
| 108 | +AND sq.sql_plan_line_id(+) = plan.id |
| 109 | +AND sq.sql_full_plan_hash_value(+) = plan.full_plan_hash_value |
| 110 | +--AND sq.sql_plan_hash_value(+) = plan.plan_hash_value |
| 111 | +AND plan.sql_id LIKE '&1' |
| 112 | +AND plan.child_number LIKE '&2' |
| 113 | +ORDER BY |
| 114 | + plan.child_number |
| 115 | + , plan.plan_hash_value |
| 116 | + , plan.id |
| 117 | +/ |
0 commit comments