|
| 1 | +-- by Jeremy Schneider, Pythian |
| 2 | +clear breaks |
| 3 | +col sql_text format a40 |
| 4 | +col wait_class format a20 |
| 5 | +col event format a40 |
| 6 | +col top_obj_pct format a11 |
| 7 | +col top_object format a30 |
| 8 | +break on sql_id on sql_text skip 1 |
| 9 | + |
| 10 | +with master as ( |
| 11 | +select /*+ materialize */ hhh.sql_id, |
| 12 | + trunc(100*count(*)/hhh.total_sess) percentage, |
| 13 | + hhh.wait_class, |
| 14 | + hhh.event, |
| 15 | + hhh.top_obj, |
| 16 | + decode(hhh.top_obj,0,null,-1,null,trunc(100*hhh.total_top_obj/hhh.total_sess)) top_obj_pct, |
| 17 | + count(*) total_samples, |
| 18 | + hhh.topn |
| 19 | +from ( |
| 20 | + select hh.*, |
| 21 | + first_value(hh.current_obj#) over (partition by hh.sql_id, hh.event order by hh.total_obj desc nulls last) top_obj, |
| 22 | + first_value(hh.total_obj) over (partition by hh.sql_id, hh.event order by hh.total_obj desc nulls last) total_top_obj, |
| 23 | + dense_rank() over (partition by hh.sql_id order by hh.total_ev desc) topn_ev, |
| 24 | + dense_rank() over (order by total_sess desc) topn |
| 25 | + from ( |
| 26 | + select h.sql_id, h.wait_class, h.event, h.current_obj#, |
| 27 | + count(*) over (partition by h.sql_id) total_sess, |
| 28 | + count(*) over (partition by h.sql_id, h.event) total_ev, |
| 29 | + case when h.current_obj#>1 then count(*) over (partition by h.sql_id, h.current_obj#) else -1 end total_obj |
| 30 | + from dba_hist_active_sess_history h |
| 31 | + where h.instance_number=1 |
| 32 | + and h.session_state='WAITING' |
| 33 | + and h.sql_id is not null |
| 34 | + and h.sample_time between '&1' and '&2' |
| 35 | + ) hh |
| 36 | +) hhh |
| 37 | +where 1=1 |
| 38 | + and topn<=14 |
| 39 | +-- and topn_ev<=5 |
| 40 | +having 100*count(*)/hhh.total_sess>10 -- this wait event accounts for more than 10% of this SQL statement |
| 41 | +group by hhh.sql_id, hhh.wait_class, hhh.event, hhh.total_sess, hhh.top_obj, hhh.total_top_obj, hhh.topn_ev, hhh.topn |
| 42 | +) |
| 43 | +select m.sql_id, |
| 44 | + dbms_lob.substr(t.sql_text,40,1) sql_text, |
| 45 | + m.percentage, |
| 46 | + m.wait_class, |
| 47 | + m.event, |
| 48 | +-- m.top_obj, |
| 49 | + m.top_obj_pct, |
| 50 | + o.object_name top_object, |
| 51 | + o.object_type top_obj_type, |
| 52 | + m.total_samples |
| 53 | +from master m, dba_hist_sqltext t, dba_objects o |
| 54 | +where m.top_obj=o.object_id(+) and m.sql_id=t.sql_id |
| 55 | +order by m.topn, m.percentage desc |
| 56 | +/ |
| 57 | + |
0 commit comments