diff --git a/ashmasters/README.md b/ashmasters/README.md new file mode 100644 index 0000000..36c9f2c --- /dev/null +++ b/ashmasters/README.md @@ -0,0 +1,30 @@ + see http://ashmasters.com for information on + Oracle Active Session History (ASH) + +queries contained in repository + +* ash_bbw.sql - buffer busy wait analysis +* ash_graph_ash.sql - basic ASH load chart in ASCII art +* ash_graph_ash_histash.sql - ASH load chart from DBA_HIST_ACTIVE_SESS_HISTORY only +* ash_graph_histash_by_dbid.sql - ASH load chart from DBA_HIST_ACTIVE_SESS_HISTORY only, input DBID +* ash_graph_histash_by_dbid_program.sql - ASH load chart from DBA_HIST_ACTIVE_SESS_HISTORY only, input DBID and PROGRAM +* ash_graph_histash_by_dbid_sqlid.sql - ASH load chart from DBA_HIST_ACTIVE_SESS_HISTORY only, input DBID and a SQL_ID +* ash_io_sizes.sql - I/O sizes from ASH +* ash_sql_elapsed.sql - use ASH to find longest running SQL +* ash_sql_elapsed_hist.sql - use ASH to find longest running SQL, give histogram of execution times +* ash_sql_elapsed_hist_longestid.sql - use ASH to find longest running SQL, give histogram of execution times and execution id of longest running query +* ash_top_procedure.sql - top procedures and who they call +* ash_top_session.sql - top SESSION from ASH ordered by time broke into wait, I/O and CPU time +* ash_top_sql.sql - top SQL from ASH ordered by time broke into wait, I/O and CPU time +* latency_eventmetric.sql - wait event latency from V$EVENTMETRIC, ie last 60 seconds +* latency_system_event.sql - wait event latency from DBA_HIST_SYSTEM_EVENT +* latency_waitclassmetric.sql - User I/O latency from V$WAITCLASSMETRIC, ie over last 60 seconds + +* load_awr - physical and logical reads per sec from AWR with snapshot time +* top10_sql_with_events_from_AWR.sql - top 10 SQL queries with events per AWR snapshot +* topsql - top 10 sql per last N minutes from ASH +* aas_by_hour - display AAS (based on ASH) for number of days at specific time +* aas_15min - display AAS (based on AWR) for all AWR snapshots calculated per 15 min spilt with split between CPU and WAIT +* event_histograms_delta_from_AWR.sql - event histograms deltas between AWR snapshots + +* topaas - display OEM like graph based on sampling and v$session view - NO DIAGNOSTIC PACK required diff --git a/ashmasters/aas_15min.sql b/ashmasters/aas_15min.sql new file mode 100644 index 0000000..5a4ecd9 --- /dev/null +++ b/ashmasters/aas_15min.sql @@ -0,0 +1,7 @@ +select mtime, round(sum(c1),2) AAS_WAIT, round(sum(c2),2) AAS_CPU, round(sum(cnt),2) AAS from ( + select to_char(sample_time,'YYYY-MM-DD HH24') mtime, decode(session_state,'WAITING',count(*),0)/360 c1, decode(session_state,'ON CPU',count(*),0)/360 c2, count(*)/360 cnt + from dba_hist_active_sess_history + group by to_char(sample_time,'YYYY-MM-DD HH24'), session_state + ) + group by mtime + order by mtime; diff --git a/ashmasters/aas_by_hour.sql b/ashmasters/aas_by_hour.sql new file mode 100644 index 0000000..fa98cf1 --- /dev/null +++ b/ashmasters/aas_by_hour.sql @@ -0,0 +1,8 @@ +select mtime, to_char(sum(c1)/min(delta_time),'9999.99') AAS_WAIT, to_char(sum(c2)/min(delta_time),'9999.99') AAS_CPU, to_char(sum(cnt)/min(delta_time),'9999.99') AAS, min(delta_time*10) Sample_DTime from ( + select min(begin_interval_time) mtime, decode(session_state,'WAITING',count(*),0) c1, decode(session_state,'ON CPU',count(*),0) c2, count(*) cnt, (trunc(sysdate) + (max(sample_time)-min(sample_time)) - trunc(sysdate) )* 24 * 360 delta_time + from dba_hist_active_sess_history ash, dba_hist_snapshot s where s.snap_id = ash.snap_id and BEGIN_INTERVAL_TIME > sysdate - &days_before and to_char(BEGIN_INTERVAL_TIME,'HH24:MI') in ('&trunchhmm') + group by s.snap_id, session_state + ) + group by mtime + order by mtime +/ diff --git a/ashmasters/ash_bbw.sql b/ashmasters/ash_bbw.sql new file mode 100644 index 0000000..585c24d --- /dev/null +++ b/ashmasters/ash_bbw.sql @@ -0,0 +1,50 @@ + + +/* + when block type is not found in v$waitclass then it's undo/rbs segement + +OBJN OTYPE FILEN BLOCKN SQL_ID BLOCK_TYPE +------------------------- ----------- ------ ------------- ------------------ +53218 BBW_INDEX_VAL_I INDEX 1 64826 97dgthz60u28d data block 1 +53218 BBW_INDEX_VAL_I INDEX 1 64826 gypmcfzruu249 data block 1 +53218 BBW_INDEX_VAL_I INDEX 1 64826 2vd1w5kgnfa5n data block 1 +53218 BBW_INDEX_VAL_I INDEX 1 64826 3p3qncvp2juxs data block 1 +53218 BBW_INDEX_VAL_I INDEX 1 64826 6avm49ys4k7t6 data block 1 +53218 BBW_INDEX_VAL_I INDEX 1 64826 1hsb81ypyrfs5 data block 1 +53218 BBW_INDEX_VAL_I INDEX 1 64652 2vd1w5kgnfa5n data block 1 +53218 BBW_INDEX_VAL_I INDEX 1 64826 3p3qncvp2juxs data block 1 +53218 BBW_INDEX_VAL_I INDEX 1 64923 5wqps1quuxqr4 data block 1 +53218 BBW_INDEX_VAL_I INDEX 1 64826 6avm49ys4k7t6 data block 1 +-1 0 0 fm7zcsnd5fud6 39 +-1 0 0 3qrw5v6d6qj4a 39 +53218 BBW_INDEX_VAL_I INDEX 1 64825 2vd1w5kgnfa5n segment header 4 +53218 BBW_INDEX_VAL_I INDEX 1 64826 gypmcfzruu249 data block 1 +53218 BBW_INDEX_VAL_I INDEX 1 64826 5x0fksgfwkn6s data block 1 +53218 BBW_INDEX_VAL_I INDEX 1 64826 2vd1w5kgnfa5n data block 1 + +*/ + + +col block_type for a18 +col objn for a25 +col otype for a15 +select + --ash.p1, + --ash.p2, + --ash.p3, + CURRENT_OBJ#||' '||o.object_name objn, + o.object_type otype, + CURRENT_FILE# filen, + CURRENT_BLOCK# blockn, + ash.SQL_ID, + w.class ||' '||to_char(ash.p3) block_type +from v$active_session_history ash, + ( select rownum class#, class from v$waitstat ) w, + all_objects o +where event='buffer busy waits' + and w.class#(+)=ash.p3 + and o.object_id (+)= ash.CURRENT_OBJ# + --and w.class# > 18 +Order by sample_time +/ + diff --git a/ashmasters/ash_graph_ash.sql b/ashmasters/ash_graph_ash.sql new file mode 100644 index 0000000..8669b21 --- /dev/null +++ b/ashmasters/ash_graph_ash.sql @@ -0,0 +1,115 @@ + +/* + ASH graph from v$active_session_history no filter by DBID nor time + don't use dba_hist_active_sess_history , + + + Output looks like + + TO_CHAR( AAS PCT1 FIRST PCT2 SECOND GRAPH + -------- --- ---- --------------- ---- --------------- ------------------------------------------- + 15 15:00 7 46 db file sequent 19 CPU +++++++ooooooooooooo4ooooooooooo------ + 15 16:00 6 53 db file sequent 31 CPU +++++++++ooooooooooo4oooooooo--- + 15 17:00 7 48 db file sequent 41 CPU +++++++++++++++ooooo4oooooooooooooooo- + 15 18:00 5 55 CPU 37 db file sequent ++++++++++++++oooooo4oooooo- + 15 19:00 1 64 CPU 21 db file sequent ++o 4 + 15 20:00 1 63 CPU 19 read by other s ++++o- 4 + 15 21:00 2 31 db file sequent 24 CPU ++ooo---- 4 + 15 22:00 3 35 CPU 24 db file scatter +++++ooooooo--- 4 + 15 23:00 6 29 log file sync 25 db file sequent ++++ooooooooo-------4------------- + 16 00:00 7 52 db file sequent 27 CPU ++++++++++oooooooooo4ooooooooooooooo-- + 16 01:00 4 57 CPU 36 db file sequent +++++++++++oooooooo 4 + 16 02:00 6 38 db file sequent 21 CPU ++++++oooooooooooo--4--------- + 16 03:00 3 69 db file sequent 20 CPU +++ooooooooooo 4 + 16 04:00 0 45 db file sequent 28 CPU o 4 + 16 05:00 1 58 db file sequent 24 CPU +ooo 4 + 16 06:00 1 41 db file sequent 39 CPU +oo 4 + + + The "graph" on the right shows the load over time each line is an hour by default. + The "+" represent CPU, "o" represent I/O and "-" represent a wait. + The columns "FIRST" and "SECOND" represent the top two things happening on the database. + +*/ + + +Def v_secs=3600 -- bucket size +Def v_days=1 -- total time analyze +Def v_bars=5 -- size of one AAS in characters +Def v_graph=80 + +col aveact format 999.99 +col graph format a30 +col fpct format 9.99 +col spct format 9.99 +col tpct format 9.99 +col aas1 format 9.99 +col aas2 format 9.99 + + +select to_char(start_time,'DD HH24:MI:SS'), + samples, + --total, + --waits, + --cpu, + round(fpct * (total/&v_secs),2) aas1, + decode(fpct,null,null,first) first, + round(spct * (total/&v_secs),2) aas2, + decode(spct,null,null,second) second, + substr(substr(rpad('+',round((cpu*&v_bars)/&v_secs),'+') || + rpad('-',round((waits*&v_bars)/&v_secs),'-') || + rpad(' ',p.value * &v_bars,' '),0,(p.value * &v_bars)) || + p.value || + substr(rpad('+',round((cpu*&v_bars)/&v_secs),'+') || + rpad('-',round((waits*&v_bars)/&v_secs),'-') || + rpad(' ',p.value * &v_bars,' '),(p.value * &v_bars),10) ,0,30) + graph + -- spct, + -- decode(spct,null,null,second) second, + -- tpct, + -- decode(tpct,null,null,third) third +from ( +select start_time + , max(samples) samples + , sum(top.total) total + , round(max(decode(top.seq,1,pct,null)),2) fpct + , substr(max(decode(top.seq,1,decode(top.event,'ON CPU','CPU',event),null)),0,15) first + , round(max(decode(top.seq,2,pct,null)),2) spct + , substr(max(decode(top.seq,2,decode(top.event,'ON CPU','CPU',event),null)),0,15) second + , round(max(decode(top.seq,3,pct,null)),2) tpct + , substr(max(decode(top.seq,3,decode(top.event,'ON CPU','CPU',event),null)),0,10) third + , sum(waits) waits + , sum(cpu) cpu +from ( + select + to_date(tday||' '||tmod*&v_secs,'YYMMDD SSSSS') start_time + , event + , total + , row_number() over ( partition by id order by total desc ) seq + , ratio_to_report( sum(total)) over ( partition by id ) pct + , max(samples) samples + , sum(decode(event,'ON CPU',total,0)) cpu + , sum(decode(event,'ON CPU',0,total)) waits + from ( + select + to_char(sample_time,'YYMMDD') tday + , trunc(to_char(sample_time,'SSSSS')/&v_secs) tmod + , to_char(sample_time,'YYMMDD')||trunc(to_char(sample_time,'SSSSS')/&v_secs) id + , decode(ash.session_state,'ON CPU','ON CPU',ash.event) event + , sum(decode(session_state,'ON CPU',1,decode(session_type,'BACKGROUND',0,1))) total + , (max(sample_id)-min(sample_id)+1) samples + from + v$active_session_history ash + group by trunc(to_char(sample_time,'SSSSS')/&v_secs) + , to_char(sample_time,'YYMMDD') + , decode(ash.session_state,'ON CPU','ON CPU',ash.event) + ) chunks + group by id, tday, tmod, event, total +) top +group by start_time +) aveact, + v$parameter p +where p.name='cpu_count' +order by start_time +/ + diff --git a/ashmasters/ash_graph_ash_histash.sql b/ashmasters/ash_graph_ash_histash.sql new file mode 100644 index 0000000..fa4e475 --- /dev/null +++ b/ashmasters/ash_graph_ash_histash.sql @@ -0,0 +1,133 @@ + +/* + ASH graph from v$active_session_history and dba_hist_active_sess_history + no filter no DBID + time filter by # of days, input variable &v_days + + + Output looks like + + TO_CHAR( AAS PCT1 FIRST PCT2 SECOND GRAPH + -------- --- ---- --------------- ---- --------------- ------------------------------------------- + 15 15:00 7 46 db file sequent 19 CPU +++++++ooooooooooooo4ooooooooooo------ + 15 16:00 6 53 db file sequent 31 CPU +++++++++ooooooooooo4oooooooo--- + 15 17:00 7 48 db file sequent 41 CPU +++++++++++++++ooooo4oooooooooooooooo- + 15 18:00 5 55 CPU 37 db file sequent ++++++++++++++oooooo4oooooo- + 15 19:00 1 64 CPU 21 db file sequent ++o 4 + 15 20:00 1 63 CPU 19 read by other s ++++o- 4 + 15 21:00 2 31 db file sequent 24 CPU ++ooo---- 4 + 15 22:00 3 35 CPU 24 db file scatter +++++ooooooo--- 4 + 15 23:00 6 29 log file sync 25 db file sequent ++++ooooooooo-------4------------- + 16 00:00 7 52 db file sequent 27 CPU ++++++++++oooooooooo4ooooooooooooooo-- + 16 01:00 4 57 CPU 36 db file sequent +++++++++++oooooooo 4 + 16 02:00 6 38 db file sequent 21 CPU ++++++oooooooooooo--4--------- + 16 03:00 3 69 db file sequent 20 CPU +++ooooooooooo 4 + 16 04:00 0 45 db file sequent 28 CPU o 4 + 16 05:00 1 58 db file sequent 24 CPU +ooo 4 + 16 06:00 1 41 db file sequent 39 CPU +oo 4 + + + The "graph" on the right shows the load over time each line is an hour by default. + The "+" represent CPU, "o" represent I/O and "-" represent a wait. + The columns "FIRST" and "SECOND" represent the top two things happening on the database. + +*/ + +Def v_secs=3600 -- bucket size +Def v_days=1 -- total time analyze +Def v_bars=5 -- size of one AAS in characters +Def v_graph=80 + +col aveact format 999.99 +col graph format a30 +col fpct format 9.99 +col spct format 9.99 +col tpct format 9.99 +col aas1 format 9.99 +col aas2 format 9.99 + + +select to_char(start_time,'DD HH24:MI:SS'), + samples, + --total, + --waits, + --cpu, + round(fpct * (total/&v_secs),2) aas1, + decode(fpct,null,null,first) first, + round(spct * (total/&v_secs),2) aas2, + decode(spct,null,null,second) second, + substr(substr(rpad('+',round((cpu*&v_bars)/&v_secs),'+') || + rpad('-',round((waits*&v_bars)/&v_secs),'-') || + rpad(' ',p.value * &v_bars,' '),0,(p.value * &v_bars)) || + p.value || + substr(rpad('+',round((cpu*&v_bars)/&v_secs),'+') || + rpad('-',round((waits*&v_bars)/&v_secs),'-') || + rpad(' ',p.value * &v_bars,' '),(p.value * &v_bars),10) ,0,30) + graph + -- spct, + -- decode(spct,null,null,second) second, + -- tpct, + -- decode(tpct,null,null,third) third +from ( +select start_time + , max(samples) samples + , sum(top.total) total + , round(max(decode(top.seq,1,pct,null)),2) fpct + , substr(max(decode(top.seq,1,decode(top.event,'ON CPU','CPU',event),null)),0,15) first + , round(max(decode(top.seq,2,pct,null)),2) spct + , substr(max(decode(top.seq,2,decode(top.event,'ON CPU','CPU',event),null)),0,15) second + , round(max(decode(top.seq,3,pct,null)),2) tpct + , substr(max(decode(top.seq,3,decode(top.event,'ON CPU','CPU',event),null)),0,10) third + , sum(waits) waits + , sum(cpu) cpu +from ( + select + to_date(tday||' '||tmod*&v_secs,'YYMMDD SSSSS') start_time + , event + , total + , row_number() over ( partition by id order by total desc ) seq + , ratio_to_report( sum(total)) over ( partition by id ) pct + , max(samples) samples + , sum(decode(event,'ON CPU',total,0)) cpu + , sum(decode(event,'ON CPU',0,total)) waits + from ( + select + to_char(sample_time,'YYMMDD') tday + , trunc(to_char(sample_time,'SSSSS')/&v_secs) tmod + , to_char(sample_time,'YYMMDD')||trunc(to_char(sample_time,'SSSSS')/&v_secs) id + , decode(ash.session_state,'ON CPU','ON CPU',ash.event) event + , sum(decode(session_state,'ON CPU',1,decode(session_type,'BACKGROUND',0,1))) total + , (max(sample_id)-min(sample_id)+1) samples + from + v$active_session_history ash + where + sample_time > sysdate - &v_days + group by trunc(to_char(sample_time,'SSSSS')/&v_secs) + , to_char(sample_time,'YYMMDD') + , decode(ash.session_state,'ON CPU','ON CPU',ash.event) +union all + select + to_char(sample_time,'YYMMDD') tday + , trunc(to_char(sample_time,'SSSSS')/&v_secs) tmod + , to_char(sample_time,'YYMMDD')||trunc(to_char(sample_time,'SSSSS')/&v_secs) id + , decode(ash.session_state,'ON CPU','ON CPU',ash.event) event + , sum(decode(session_state,'ON CPU',10,decode(session_type,'BACKGROUND',0,10))) total + , (max(sample_id)-min(sample_id)+1) samples + from + dba_hist_active_sess_history ash + where + sample_time > sysdate - &v_days + and sample_time < ( select min(sample_time) from v$active_session_history) + group by trunc(to_char(sample_time,'SSSSS')/&v_secs) + , to_char(sample_time,'YYMMDD') + , decode(ash.session_state,'ON CPU','ON CPU',ash.event) + ) chunks + group by id, tday, tmod, event, total +) top +group by start_time +) aveact, + v$parameter p +where p.name='cpu_count' +order by start_time +/ + diff --git a/ashmasters/ash_graph_histash_by_dbid.sql b/ashmasters/ash_graph_histash_by_dbid.sql new file mode 100644 index 0000000..e333774 --- /dev/null +++ b/ashmasters/ash_graph_histash_by_dbid.sql @@ -0,0 +1,153 @@ + +/* + ASH graph from dba_hist_active_sess_history no v$active_session_history + input DBID + time filter by # of days, input variable &v_days + + ATTENTION: number of CPU cores is hard coded to 4. + future enhancement is to get CPU_COUNT by DBID instead + + Output looks like + + TO_CHAR( AAS PCT1 FIRST PCT2 SECOND GRAPH + -------- --- ---- --------------- ---- --------------- ------------------------------------------- + 15 15:00 7 46 db file sequent 19 CPU +++++++ooooooooooooo4ooooooooooo------ + 15 16:00 6 53 db file sequent 31 CPU +++++++++ooooooooooo4oooooooo--- + 15 17:00 7 48 db file sequent 41 CPU +++++++++++++++ooooo4oooooooooooooooo- + 15 18:00 5 55 CPU 37 db file sequent ++++++++++++++oooooo4oooooo- + 15 19:00 1 64 CPU 21 db file sequent ++o 4 + 15 20:00 1 63 CPU 19 read by other s ++++o- 4 + 15 21:00 2 31 db file sequent 24 CPU ++ooo---- 4 + 15 22:00 3 35 CPU 24 db file scatter +++++ooooooo--- 4 + 15 23:00 6 29 log file sync 25 db file sequent ++++ooooooooo-------4------------- + 16 00:00 7 52 db file sequent 27 CPU ++++++++++oooooooooo4ooooooooooooooo-- + 16 01:00 4 57 CPU 36 db file sequent +++++++++++oooooooo 4 + 16 02:00 6 38 db file sequent 21 CPU ++++++oooooooooooo--4--------- + 16 03:00 3 69 db file sequent 20 CPU +++ooooooooooo 4 + 16 04:00 0 45 db file sequent 28 CPU o 4 + 16 05:00 1 58 db file sequent 24 CPU +ooo 4 + 16 06:00 1 41 db file sequent 39 CPU +oo 4 + + + The "graph" on the right shows the load over time each line is an hour by default. + The "+" represent CPU, "o" represent I/O and "-" represent a wait. + The columns "FIRST" and "SECOND" represent the top two things happening on the database. + +*/ + + +Def v_secs=3600 -- bucket size +Def v_days=1 -- total time analyze +Def v_bars=5 -- size of one AAS in characters +Def v_graph=80 + +col aveact format 999.99 +col graph format a80 +col fpct format 9.99 +col spct format 9.99 +col tpct format 9.99 +col aas1 format 9.99 +col aas2 format 9.99 +col pct1 format 999 +col pct2 format 999 +col first format a15 +col second format a15 + +Def p_value=4 + + +select to_char(start_time,'DD HH24:MI'), + --samples, + --total, + --waits, + --cpu, + round((total/&v_secs)) aas, + --round(fpct * (total/&v_secs),2) aas1, + fpct*100 pct1, + decode(fpct,null,null,first) first, + --round(spct * (total/&v_secs),2) aas2, + spct*100 pct2, + decode(spct,null,null,second) second, + -- substr, ie trunc, the whole graph to make sure it doesn't overflow + substr( + -- substr, ie trunc, the graph below the # of CPU cores line + -- draw the whole graph and trunc at # of cores line + substr( + rpad('+',round((cpu*&v_bars)/&v_secs),'+') || + rpad('o',round((io*&v_bars)/&v_secs),'o') || + rpad('-',round((waits*&v_bars)/&v_secs),'-') || + rpad(' ',&p_value * &v_bars,' '),0,(&p_value * &v_bars)) || + &p_value || + -- draw the whole graph, then cut off the amount we drew before the # of cores + substr( + rpad('+',round((cpu*&v_bars)/&v_secs),'+') || + rpad('o',round((io*&v_bars)/&v_secs),'o') || + rpad('-',round((waits*&v_bars)/&v_secs),'-') || + rpad(' ',&p_value * &v_bars,' '),(&p_value * &v_bars),( &v_graph-&v_bars*&p_value) ) + ,0,&v_graph) + graph + -- spct, + -- decode(spct,null,null,second) second, + -- tpct, + -- decode(tpct,null,null,third) third +from ( +select start_time + , max(samples) samples + , sum(top.total) total + , round(max(decode(top.seq,1,pct,null)),2) fpct + , substr(max(decode(top.seq,1,decode(top.event,'ON CPU','CPU',event),null)),0,15) first + , round(max(decode(top.seq,2,pct,null)),2) spct + , substr(max(decode(top.seq,2,decode(top.event,'ON CPU','CPU',event),null)),0,15) second + , round(max(decode(top.seq,3,pct,null)),2) tpct + , substr(max(decode(top.seq,3,decode(top.event,'ON CPU','CPU',event),null)),0,10) third + , sum(waits) waits + , sum(io) io + , sum(cpu) cpu +from ( + select + to_date(tday||' '||tmod*&v_secs,'YYMMDD SSSSS') start_time + , event + , total + , row_number() over ( partition by id order by total desc ) seq + , ratio_to_report( sum(total)) over ( partition by id ) pct + , max(samples) samples + , sum(decode(event,'ON CPU',total,0)) cpu + , sum(decode(event,'ON CPU',0, + 'db file sequential read',0, + 'db file scattered read',0, + 'db file parallel read',0, + 'direct path read',0, + 'direct path read temp',0, + 'direct path write',0, + 'direct path write temp',0, total)) waits + , sum(decode(event,'db file sequential read',total, + 'db file scattered read',total, + 'db file parallel read',total, + 'direct path read',total, + 'direct path read temp',total, + 'direct path write',total, + 'direct path write temp',total, 0)) io + from ( + select + to_char(sample_time,'YYMMDD') tday + , trunc(to_char(sample_time,'SSSSS')/&v_secs) tmod + , to_char(sample_time,'YYMMDD')||trunc(to_char(sample_time,'SSSSS')/&v_secs) id + , decode(ash.session_state,'ON CPU','ON CPU',ash.event) event + , sum(decode(session_state,'ON CPU',10,decode(session_type,'BACKGROUND',0,10))) total + , (max(sample_id)-min(sample_id)+1) samples + from + dba_hist_active_sess_history ash + where + -- sample_time > sysdate - &v_days + -- and sample_time < ( select min(sample_time) from v$active_session_history) + dbid=&DBID + group by trunc(to_char(sample_time,'SSSSS')/&v_secs) + , to_char(sample_time,'YYMMDD') + , decode(ash.session_state,'ON CPU','ON CPU',ash.event) + ) chunks + group by id, tday, tmod, event, total +) top +group by start_time +) aveact +order by start_time +/ diff --git a/ashmasters/ash_graph_histash_by_dbid_program.sql b/ashmasters/ash_graph_histash_by_dbid_program.sql new file mode 100644 index 0000000..1cfaaca --- /dev/null +++ b/ashmasters/ash_graph_histash_by_dbid_program.sql @@ -0,0 +1,152 @@ + +/* + ASH graph from dba_hist_active_sess_history no v$active_session_history + input DBID and PROGRAM + time filter by # of days, input variable &v_days + + + Output looks like + + TO_CHAR( AAS PCT1 FIRST PCT2 SECOND GRAPH + -------- --- ---- --------------- ---- --------------- ------------------------------------------- + 15 15:00 7 46 db file sequent 19 CPU +++++++ooooooooooooo4ooooooooooo------ + 15 16:00 6 53 db file sequent 31 CPU +++++++++ooooooooooo4oooooooo--- + 15 17:00 7 48 db file sequent 41 CPU +++++++++++++++ooooo4oooooooooooooooo- + 15 18:00 5 55 CPU 37 db file sequent ++++++++++++++oooooo4oooooo- + 15 19:00 1 64 CPU 21 db file sequent ++o 4 + 15 20:00 1 63 CPU 19 read by other s ++++o- 4 + 15 21:00 2 31 db file sequent 24 CPU ++ooo---- 4 + 15 22:00 3 35 CPU 24 db file scatter +++++ooooooo--- 4 + 15 23:00 6 29 log file sync 25 db file sequent ++++ooooooooo-------4------------- + 16 00:00 7 52 db file sequent 27 CPU ++++++++++oooooooooo4ooooooooooooooo-- + 16 01:00 4 57 CPU 36 db file sequent +++++++++++oooooooo 4 + 16 02:00 6 38 db file sequent 21 CPU ++++++oooooooooooo--4--------- + 16 03:00 3 69 db file sequent 20 CPU +++ooooooooooo 4 + 16 04:00 0 45 db file sequent 28 CPU o 4 + 16 05:00 1 58 db file sequent 24 CPU +ooo 4 + 16 06:00 1 41 db file sequent 39 CPU +oo 4 + + + The "graph" on the right shows the load over time each line is an hour by default. + The "+" represent CPU, "o" represent I/O and "-" represent a wait. + The columns "FIRST" and "SECOND" represent the top two things happening on the database. + +*/ + +Def v_secs=3600 -- bucket size +Def v_days=1 -- total time analyze +Def v_bars=5 -- size of one AAS in characters +Def v_graph=80 + +col aveact format 999.99 +col graph format a80 +col fpct format 9.99 +col spct format 9.99 +col tpct format 9.99 +col aas format 999.99 +col aas1 format 9.99 +col aas2 format 9.99 +col pct1 format 999 +col pct2 format 999 +col first format a15 +col second format a15 + +Def p_value=4 + +select to_char(start_time,'DD HH24:MI'), + --samples, + --total, + --waits, + --cpu, + (total/&v_secs) aas, + --round(fpct * (total/&v_secs),2) aas1, + fpct*100 pct1, + decode(fpct,null,null,first) first, + --round(spct * (total/&v_secs),2) aas2, + spct*100 pct2, + decode(spct,null,null,second) second, + -- substr, ie trunc, the whole graph to make sure it doesn't overflow + substr( + -- substr, ie trunc, the graph below the # of CPU cores line + -- draw the whole graph and trunc at # of cores line + substr( + rpad('+',round((cpu*&v_bars)/&v_secs),'+') || + rpad('o',round((io*&v_bars)/&v_secs),'o') || + rpad('-',round((waits*&v_bars)/&v_secs),'-') || + rpad(' ',&p_value * &v_bars,' '),0,(&p_value * &v_bars)) || + &p_value || + -- draw the whole graph, then cut off the amount we drew before the # of cores + substr( + rpad('+',round((cpu*&v_bars)/&v_secs),'+') || + rpad('o',round((io*&v_bars)/&v_secs),'o') || + rpad('-',round((waits*&v_bars)/&v_secs),'-') || + rpad(' ',&p_value * &v_bars,' '),(&p_value * &v_bars),( &v_graph-&v_bars*&p_value) ) + ,0,&v_graph) + graph + -- spct, + -- decode(spct,null,null,second) second, + -- tpct, + -- decode(tpct,null,null,third) third +from ( +select start_time + , max(samples) samples + , sum(top.total) total + , round(max(decode(top.seq,1,pct,null)),2) fpct + , substr(max(decode(top.seq,1,decode(top.event,'ON CPU','CPU',event),null)),0,15) first + , round(max(decode(top.seq,2,pct,null)),2) spct + , substr(max(decode(top.seq,2,decode(top.event,'ON CPU','CPU',event),null)),0,15) second + , round(max(decode(top.seq,3,pct,null)),2) tpct + , substr(max(decode(top.seq,3,decode(top.event,'ON CPU','CPU',event),null)),0,10) third + , sum(waits) waits + , sum(io) io + , sum(cpu) cpu +from ( + select + to_date(tday||' '||tmod*&v_secs,'YYMMDD SSSSS') start_time + , event + , total + , row_number() over ( partition by id order by total desc ) seq + , ratio_to_report( sum(total)) over ( partition by id ) pct + , max(samples) samples + , sum(decode(event,'ON CPU',total,0)) cpu + , sum(decode(event,'ON CPU',0, + 'db file sequential read',0, + 'db file scattered read',0, + 'db file parallel read',0, + 'direct path read',0, + 'direct path read temp',0, + 'direct path write',0, + 'direct path write temp',0, total)) waits + , sum(decode(event,'db file sequential read',total, + 'db file scattered read',total, + 'db file parallel read',total, + 'direct path read',total, + 'direct path read temp',total, + 'direct path write',total, + 'direct path write temp',total, 0)) io + from ( + select + to_char(sample_time,'YYMMDD') tday + , trunc(to_char(sample_time,'SSSSS')/&v_secs) tmod + , to_char(sample_time,'YYMMDD')||trunc(to_char(sample_time,'SSSSS')/&v_secs) id + , decode(ash.session_state,'ON CPU','ON CPU',ash.event) event + , sum(decode(session_state,'ON CPU',10,decode(session_type,'BACKGROUND',0,10))) total + , (max(sample_id)-min(sample_id)+1) samples + from + dba_hist_active_sess_history ash + where + -- sample_time > sysdate - &v_days + -- and sample_time < ( select min(sample_time) from v$active_session_history) + dbid=&DBID + and program like '&PROGRAM%' + group by trunc(to_char(sample_time,'SSSSS')/&v_secs) + , to_char(sample_time,'YYMMDD') + , decode(ash.session_state,'ON CPU','ON CPU',ash.event) + ) chunks + group by id, tday, tmod, event, total +) top +group by start_time +) aveact +order by start_time +/ + diff --git a/ashmasters/ash_graph_histash_by_dbid_sqlid.sql b/ashmasters/ash_graph_histash_by_dbid_sqlid.sql new file mode 100644 index 0000000..9dfb222 --- /dev/null +++ b/ashmasters/ash_graph_histash_by_dbid_sqlid.sql @@ -0,0 +1,154 @@ + +/* + ASH graph from dba_hist_active_sess_history no v$active_session_history + input DBID and SQL_ID + time filter by # of days, input variable &v_days + + + Output looks like + + TO_CHAR( AAS PCT1 FIRST PCT2 SECOND GRAPH + -------- --- ---- --------------- ---- --------------- ------------------------------------------- + 15 15:00 7 46 db file sequent 19 CPU +++++++ooooooooooooo4ooooooooooo------ + 15 16:00 6 53 db file sequent 31 CPU +++++++++ooooooooooo4oooooooo--- + 15 17:00 7 48 db file sequent 41 CPU +++++++++++++++ooooo4oooooooooooooooo- + 15 18:00 5 55 CPU 37 db file sequent ++++++++++++++oooooo4oooooo- + 15 19:00 1 64 CPU 21 db file sequent ++o 4 + 15 20:00 1 63 CPU 19 read by other s ++++o- 4 + 15 21:00 2 31 db file sequent 24 CPU ++ooo---- 4 + 15 22:00 3 35 CPU 24 db file scatter +++++ooooooo--- 4 + 15 23:00 6 29 log file sync 25 db file sequent ++++ooooooooo-------4------------- + 16 00:00 7 52 db file sequent 27 CPU ++++++++++oooooooooo4ooooooooooooooo-- + 16 01:00 4 57 CPU 36 db file sequent +++++++++++oooooooo 4 + 16 02:00 6 38 db file sequent 21 CPU ++++++oooooooooooo--4--------- + 16 03:00 3 69 db file sequent 20 CPU +++ooooooooooo 4 + 16 04:00 0 45 db file sequent 28 CPU o 4 + 16 05:00 1 58 db file sequent 24 CPU +ooo 4 + 16 06:00 1 41 db file sequent 39 CPU +oo 4 + + + The "graph" on the right shows the load over time each line is an hour by default. + The "+" represent CPU, "o" represent I/O and "-" represent a wait. + The columns "FIRST" and "SECOND" represent the top two things happening on the database. + +*/ + + + +Def v_secs=3600 -- bucket size +Def v_days=1 -- total time analyze +Def v_bars=5 -- size of one AAS in characters +Def v_graph=80 + +col aveact format 999.99 +col graph format a80 +col fpct format 9.99 +col spct format 9.99 +col tpct format 9.99 +col aas format 999.99 +col aas1 format 9.99 +col aas2 format 9.99 +col pct1 format 999 +col pct2 format 999 +col first format a15 +col second format a15 + +Def p_value=4 + +select to_char(start_time,'DD HH24:MI'), + --samples, + --total, + --waits, + --cpu, + (total/&v_secs) aas, + --round(fpct * (total/&v_secs),2) aas1, + fpct*100 pct1, + decode(fpct,null,null,first) first, + --round(spct * (total/&v_secs),2) aas2, + spct*100 pct2, + decode(spct,null,null,second) second, + -- substr, ie trunc, the whole graph to make sure it doesn't overflow + substr( + -- substr, ie trunc, the graph below the # of CPU cores line + -- draw the whole graph and trunc at # of cores line + substr( + rpad('+',round((cpu*&v_bars)/&v_secs),'+') || + rpad('o',round((io*&v_bars)/&v_secs),'o') || + rpad('-',round((waits*&v_bars)/&v_secs),'-') || + rpad(' ',&p_value * &v_bars,' '),0,(&p_value * &v_bars)) || + &p_value || + -- draw the whole graph, then cut off the amount we drew before the # of cores + substr( + rpad('+',round((cpu*&v_bars)/&v_secs),'+') || + rpad('o',round((io*&v_bars)/&v_secs),'o') || + rpad('-',round((waits*&v_bars)/&v_secs),'-') || + rpad(' ',&p_value * &v_bars,' '),(&p_value * &v_bars),( &v_graph-&v_bars*&p_value) ) + ,0,&v_graph) + graph + -- spct, + -- decode(spct,null,null,second) second, + -- tpct, + -- decode(tpct,null,null,third) third +from ( +select start_time + , max(samples) samples + , sum(top.total) total + , round(max(decode(top.seq,1,pct,null)),2) fpct + , substr(max(decode(top.seq,1,decode(top.event,'ON CPU','CPU',event),null)),0,15) first + , round(max(decode(top.seq,2,pct,null)),2) spct + , substr(max(decode(top.seq,2,decode(top.event,'ON CPU','CPU',event),null)),0,15) second + , round(max(decode(top.seq,3,pct,null)),2) tpct + , substr(max(decode(top.seq,3,decode(top.event,'ON CPU','CPU',event),null)),0,10) third + , sum(waits) waits + , sum(io) io + , sum(cpu) cpu +from ( + select + to_date(tday||' '||tmod*&v_secs,'YYMMDD SSSSS') start_time + , event + , total + , row_number() over ( partition by id order by total desc ) seq + , ratio_to_report( sum(total)) over ( partition by id ) pct + , max(samples) samples + , sum(decode(event,'ON CPU',total,0)) cpu + , sum(decode(event,'ON CPU',0, + 'db file sequential read',0, + 'db file scattered read',0, + 'db file parallel read',0, + 'direct path read',0, + 'direct path read temp',0, + 'direct path write',0, + 'direct path write temp',0, total)) waits + , sum(decode(event,'db file sequential read',total, + 'db file scattered read',total, + 'db file parallel read',total, + 'direct path read',total, + 'direct path read temp',total, + 'direct path write',total, + 'direct path write temp',total, 0)) io + from ( + select + to_char(sample_time,'YYMMDD') tday + , trunc(to_char(sample_time,'SSSSS')/&v_secs) tmod + , to_char(sample_time,'YYMMDD')||trunc(to_char(sample_time,'SSSSS')/&v_secs) id + , decode(ash.session_state,'ON CPU','ON CPU',ash.event) event + , sum(decode(session_state,'ON CPU',10,decode(session_type,'BACKGROUND',0,10))) total + , (max(sample_id)-min(sample_id)+1) samples + from + dba_hist_active_sess_history ash + where + -- sample_time > sysdate - &v_days + -- and sample_time < ( select min(sample_time) from v$active_session_history) + dbid=&DBID + and sql_id='&SQL_ID' + group by trunc(to_char(sample_time,'SSSSS')/&v_secs) + , to_char(sample_time,'YYMMDD') + , decode(ash.session_state,'ON CPU','ON CPU',ash.event) + ) chunks + group by id, tday, tmod, event, total +) top +group by start_time +) aveact +order by start_time +/ + diff --git a/ashmasters/ash_io_sizes.sql b/ashmasters/ash_io_sizes.sql new file mode 100644 index 0000000..58e073c --- /dev/null +++ b/ashmasters/ash_io_sizes.sql @@ -0,0 +1,33 @@ + + +/* + + get I/O sizes from dba_hist_active_sess_history + + output looks like + + EVENT MN AV MX CNT + ------------------------- ---------- ---------- ---------- ---------- + db file scattered read 2 16 16 892 + db file sequential read 1 1 1 105 + direct path read 1 1 1 1 + direct path write 1 1 1 2 + direct path write temp 4 29 31 17 + + see: https://sites.google.com/site/oraclemonitor/dba_hist_active_sess_history + +*/ +col event for a25 +select event,round(min(p3)) mn, +round(avg(p3)) av, +round(max(p3)) mx, +count(*) cnt +from dba_hist_active_sess_history +--from v$active_session_history +where (event like 'db file%' or event like 'direct %') +and event not like '%parallel%' +and dbid=&DBID +group by event +order by event +/ + diff --git a/ashmasters/ash_io_top_obj.sql b/ashmasters/ash_io_top_obj.sql new file mode 100644 index 0000000..bfb1884 --- /dev/null +++ b/ashmasters/ash_io_top_obj.sql @@ -0,0 +1,20 @@ + +col objn for a28 + + +select + count(*) cnt, + CURRENT_OBJ#||' '||o.object_name objn, + o.object_type otype +from v$active_session_history ash, + all_objects o +where ( event like 'db file s%' or event like 'direct%' ) + and o.object_id (+)= ash.CURRENT_OBJ# + and sample_time > sysdate - &1/(60*24) + and session_state='WAITING' +group by + CURRENT_OBJ#, o.object_name , + o.object_type +Order by count(*) +/ + diff --git a/ashmasters/ash_sql_elapsed.sql b/ashmasters/ash_sql_elapsed.sql new file mode 100644 index 0000000..d2cb50f --- /dev/null +++ b/ashmasters/ash_sql_elapsed.sql @@ -0,0 +1,54 @@ +/* + +Output looks like + +SQL_ID COUNT(*) MX AV MIN +------------- ---------- ------- --------- ---------- +0fvrpk7476b7y 26 3068 133.1 0 +1pjp66rxcj6tg 15 3106 767.7 57 +8r5wuxk1dprhr 39 3510 841.0 24 +0w5uu5kngyyty 21 3652 442.3 0 +0hbv80w9ypy0n 161 4089 1183.9 0 +71fwb4n6a92fv 49 4481 676.9 30 +0bujgc94rg3fj 604 4929 24.7 0 +64dqhdkkw63fd 1083 7147 7.2 0 +990m08w8xav7s 591 7681 51.8 0 +2n5369dsuvn5a 16 10472 5726.8 303 +2spgk3k0f7quz 251 29607 546.1 0 +36pd759xym9tc 12 37934 23861.9 1391 +497wh6n7hu14f 49 69438 5498.2 0 + +*/ + +col mx for 999999 +col mn for 999999 +col av for 999999.9 + +select + sql_id, + count(*), + max(tm) mx, + avg(tm) av, + min(tm) min +from ( + select + sql_id, + sql_exec_id, + max(tm) tm + from ( select + sql_id, + sql_exec_id, + ((cast(sample_time as date)) - + (cast(sql_exec_start as date))) * (3600*24) tm + from + dba_hist_active_sess_history + where sql_exec_id is not null + ) + group by sql_id,sql_exec_id + ) +group by sql_id +having count(*) > 10 +order by mx,av +/ + + diff --git a/ashmasters/ash_sql_elapsed_hist.sql b/ashmasters/ash_sql_elapsed_hist.sql new file mode 100644 index 0000000..33677b2 --- /dev/null +++ b/ashmasters/ash_sql_elapsed_hist.sql @@ -0,0 +1,64 @@ + +/* +OUTPUT looks like + +SQL_ID CT MX MN AV 1 2 3 4 5 +------------- ---------- ---------- ---------- -------- ------ ------ ----- ----- ----- +5k7vccwjr5ahd 2653 1963 0 33.4 2623 15 8 4 3 +ds8cz0fb8w147 161 2531 13 273.8 136 18 5 1 1 +bzyny95313u12 114 2599 0 46.5 113 0 0 0 1 +0hbv80w9ypy0n 161 4089 0 1183.9 27 116 9 6 3 +71fwb4n6a92fv 49 4481 30 676.9 38 6 2 2 1 +0bujgc94rg3fj 604 4929 0 24.7 601 1 1 0 1 +64dqhdkkw63fd 1083 7147 0 7.2 1082 0 0 0 1 +990m08w8xav7s 591 7681 0 51.8 587 0 0 2 2 +2spgk3k0f7quz 251 29607 0 546.1 247 2 0 0 2 +497wh6n7hu14f 49 69438 0 5498.2 44 1 0 1 3 + +*/ + +col 1 for 99999 +col 2 for 99999 +col 3 for 9999 +col 4 for 9999 +col 5 for 9999 +col av for 99999.9 +with pivot_data as ( +select + sql_id, + ct, + mxdelta mx, + mndelta mn, + avdelta av, + width_bucket(delta,0,mxdelta+.1,5) as bucket +from ( +select + sql_id, + delta, + count(*) OVER (PARTITION BY sql_id) ct, + max(delta) OVER (PARTITION BY sql_id) mxdelta, + min(delta) OVER (PARTITION BY sql_id) mndelta, + avg(delta) OVER (PARTITION BY sql_id) avdelta +from ( + select + sql_id, + sql_exec_id, + max(delta) delta + from ( select + sql_id, + sql_exec_id, + ((cast(sample_time as date)) - + (cast(sql_exec_start as date))) * (3600*24) delta + from + dba_hist_active_sess_history + where sql_exec_id is not null + ) + group by sql_id,sql_exec_id +) +) +) +select * from pivot_data +PIVOT ( count(*) FOR bucket IN (1,2,3,4,5)) +order by mx,av +/ + diff --git a/ashmasters/ash_sql_elapsed_hist_longestid.sql b/ashmasters/ash_sql_elapsed_hist_longestid.sql new file mode 100644 index 0000000..80f5cfc --- /dev/null +++ b/ashmasters/ash_sql_elapsed_hist_longestid.sql @@ -0,0 +1,85 @@ + +/* + +OUTPUT looks like: + +SQL_ID CT MX MN AV MAX_RUN_TIME LONGEST_SQ 1 2 3 4 5 +------------- ------ ---------- ---- -------- ----------------------------------- ---------- ------ ------ ----- ---- --- +2spgk3k0f7quz 251 29607 0 546.0 11-04-12 12:11:47 11-04-12 20:25:14 16781748 247 2 0 0 2 +990m08w8xav7s 591 7681 0 52.0 11-04-13 00:39:27 11-04-13 02:47:28 16786685 587 0 0 2 2 +64dqhdkkw63fd 1083 7147 0 7.0 11-03-07 04:01:01 11-03-07 06:00:08 16777218 1082 0 0 0 1 +0bujgc94rg3fj 604 4929 0 25.0 11-04-08 10:53:34 11-04-08 12:15:43 16814628 601 1 1 0 1 +0hbv80w9ypy0n 161 4089 0 1184.0 11-03-02 04:36:10 11-04-12 23:34:18 16777290 27 116 9 6 3 +bzyny95313u12 114 2599 0 47.0 11-03-03 03:06:18 11-03-03 03:49:37 16781191 113 0 0 0 1 +ds8cz0fb8w147 161 2531 13 274.0 11-03-01 23:11:48 11-04-12 16:10:37 16777285 136 18 5 1 1 +5k7vccwjr5ahd 2653 1963 0 33.0 11-03-01 23:10:12 11-04-12 09:06:12 16778244 2623 15 8 4 3 +4d6m2q3ngjcv9 320 1701 3 485.0 11-03-01 23:10:53 11-04-10 18:01:26 16777261 92 168 50 9 1 +g5u58zpg0tuk8 97 1359 1 62.0 11-04-12 02:23:37 11-04-13 02:51:09 16777217 92 3 1 0 1 +34cgtc9xkgxny 61 1272 978 1163.0 11-03-02 10:06:24 11-03-02 10:27:36 16777250 4 4 14 + + +*/ + +col 1 for 99999 +col 2 for 99999 +col 3 for 9999 +col 4 for 999 +col 5 for 99 +col av for 99999 +col ct for 99999 +col mn for 999 +col av for 99999.9 +col longest_sql_exec_id for A10 + +WITH pivot_data AS ( +SELECT + sql_id, + ct, + mxdelta mx, + mndelta mn, + round(avdelta) av, + WIDTH_BUCKET(delta_in_seconds,mndelta,mxdelta+.1,5) AS bucket , + SUBSTR(times,12) max_run_time, + SUBSTR(longest_sql_exec_id, 12) longest_sql_exec_id +FROM ( +SELECT + sql_id, + delta_in_seconds, + COUNT(*) OVER (PARTITION BY sql_id) ct, + MAX(delta_in_seconds) OVER (PARTITION BY sql_id) mxdelta, + MIN(delta_in_seconds) OVER (PARTITION BY sql_id) mndelta, + AVG(delta_in_seconds) OVER (PARTITION BY sql_id) avdelta, + MAX(times) OVER (PARTITION BY sql_id) times, + MAX(longest_sql_exec_id) OVER (PARTITION BY sql_id) longest_sql_exec_id +FROM ( + SELECT + sql_id, + sql_exec_id, + MAX(delta_in_seconds) delta_in_seconds , + LPAD(ROUND(MAX(delta_in_seconds),0),10) || ' ' || + TO_CHAR(MIN(start_time),'YY-MM-DD HH24:MI:SS') || ' ' || + TO_CHAR(MAX(end_time),'YY-MM-DD HH24:MI:SS') times, + LPAD(ROUND(MAX(delta_in_seconds),0),10) || ' ' || + TO_CHAR(MAX(sql_exec_id)) longest_sql_exec_id + FROM ( SELECT + sql_id, + sql_exec_id, + CAST(sample_time AS DATE) end_time, + CAST(sql_exec_start AS DATE) start_time, + ((CAST(sample_time AS DATE)) - + (CAST(sql_exec_start AS DATE))) * (3600*24) delta_in_seconds + FROM + dba_hist_active_sess_history + WHERE sql_exec_id IS NOT NULL + ) + GROUP BY sql_id,sql_exec_id +) +) +where ct > &min_repeat_executions_filter + and mxdelta > &min_elapsed_time +) +SELECT * FROM pivot_data +PIVOT ( COUNT(*) FOR bucket IN (1,2,3,4,5)) +ORDER BY mx DESC,av DESC +; + diff --git a/ashmasters/ash_top_procedure.sql b/ashmasters/ash_top_procedure.sql new file mode 100644 index 0000000..8d27daa --- /dev/null +++ b/ashmasters/ash_top_procedure.sql @@ -0,0 +1,57 @@ + + +/* + + only 10.2.0.3 and above + +COUNT(*) SQL_ID calling_code +--------- ------------- -------------------------------------------------------------------- + 2 1xxksrhwtz3zf ORDERENTRY.NEWORDER => DBMS_RANDOM.VALUE + 2 07p193phmhx3z ORDERENTRY.BROWSEPRODUCTS => DBMS_APPLICATION_INFO.SET_ACTION + 2 1xxksrhwtz3zf ORDERENTRY.NEWORDER => DBMS_LOCK.SLEEP + 3 1xxksrhwtz3zf ORDERENTRY.NEWORDER => DBMS_APPLICATION_INFO.SET_ACTION + 13 1xxksrhwtz3zf ORDERENTRY.NEWORDER + 16 0bzhqhhj9mpaa ORDERENTRY.NEWCUSTOMER + 45 41zu158rqf4kf ORDERENTRY.BROWSEANDUPDATEORDERS + 70 0yas01u2p9ch4 ORDERENTRY.NEWORDER + 76 dw2zgaapax1sg ORDERENTRY.NEWORDER + 82 05s4vdwsf5802 ORDERENTRY.BROWSEANDUPDATEORDERS + 111 75621g9y3xmvd ORDERENTRY.NEWORDER + 120 75621g9y3xmvd ORDERENTRY.BROWSEPRODUCTS + 131 75621g9y3xmvd ORDERENTRY.BROWSEANDUPDATEORDERS + 163 0uuqgjq7k12nf ORDERENTRY.NEWORDER + +*/ + + +set linesize 120 +col entry_package for a25 +col entry_procedure for a25 +col cur_package for a25 +col cur_procedure for a25 +col calling_code for a70 +select + count(*), + sql_id, + procs1.object_name || decode(procs1.procedure_name,'','','.')|| + procs1.procedure_name ||' '|| + decode(procs2.object_name,procs1.object_name,'', + decode(procs2.object_name,'','',' => '||procs2.object_name)) + || + decode(procs2.procedure_name,procs1.procedure_name,'', + decode(procs2.procedure_name,'','',null,'','.')||procs2.procedure_name) + "calling_code" +from v$active_session_history ash, + all_procedures procs1, + all_procedures procs2 + where + ash.PLSQL_ENTRY_OBJECT_ID = procs1.object_id (+) + and ash.PLSQL_ENTRY_SUBPROGRAM_ID = procs1.SUBPROGRAM_ID (+) + and ash.PLSQL_OBJECT_ID = procs2.object_id (+) + and ash.PLSQL_SUBPROGRAM_ID = procs2.SUBPROGRAM_ID (+) + and ash.sample_time > sysdate - &minutes/(60*24) +group by procs1.object_name, procs1.procedure_name, + procs2.object_name, procs2.procedure_name,sql_id +order by count(*) +/ + diff --git a/ashmasters/ash_top_session.sql b/ashmasters/ash_top_session.sql new file mode 100644 index 0000000..c8a9d09 --- /dev/null +++ b/ashmasters/ash_top_session.sql @@ -0,0 +1,73 @@ + + +/* + +STATUS SID NAME PROGRAM CPU WAITING IO TOTAL +------------ ----- ------------ ------------------------- ----- ---------- ----- ------ +CONNECTED 165 SYS ORACLE.EXE (CKPT) 232 173 0 405 +DISCONNECTED 158 SYS ORACLE.EXE (J003) 43 6 303 352 +DISCONNECTED 141 SYS ORACLE.EXE (J002) 13 3 333 349 +CONNECTED 162 SYS ORACLE.EXE (CJQ0) 149 14 2 165 +CONNECTED 167 SYS ORACLE.EXE (DBW0) 26 116 0 142 +CONNECTED 166 SYS ORACLE.EXE (LGWR) 46 94 0 140 +CONNECTED 161 SYS ORACLE.EXE (MMON) 34 13 16 63 +CONNECTED 170 SYS ORACLE.EXE (PMON) 59 0 0 59 +DISCONNECTED 147 SYS ORACLE.EXE (m000) 0 24 12 36 + + +*/ + + +col name for a12 +col program for a25 +col CPU for 9999 +col IO for 9999 +col TOTAL for 99999 +col WAIT for 9999 +col user_id for 99999 +col sid for 9999 + +set linesize 120 + +select + decode(nvl(to_char(s.sid),-1),-1,'DISCONNECTED','CONNECTED') + "STATUS", + topsession.sid "SID", + u.username "NAME", + topsession.program "PROGRAM", + max(topsession.CPU) "CPU", + max(topsession.WAIT) "WAITING", + max(topsession.IO) "IO", + max(topsession.TOTAL) "TOTAL" + from ( +select * from ( +select + ash.session_id sid, + ash.session_serial# serial#, + ash.user_id user_id, + ash.program, + sum(decode(ash.session_state,'ON CPU',1,0)) "CPU", + sum(decode(ash.session_state,'WAITING',1,0)) - + sum(decode(ash.session_state,'WAITING', + decode(wait_class,'User I/O',1, 0 ), 0)) "WAIT" , + sum(decode(ash.session_state,'WAITING', + decode(wait_class,'User I/O',1, 0 ), 0)) "IO" , + sum(decode(session_state,'ON CPU',1,1)) "TOTAL" +from v$active_session_history ash +group by session_id,user_id,session_serial#,program +order by sum(decode(session_state,'ON CPU',1,1)) desc +) where rownum < 10 + ) topsession, + v$session s, + all_users u + where + u.user_id =topsession.user_id and + /* outer join to v$session because the session might be disconnected */ + topsession.sid = s.sid (+) and + topsession.serial# = s.serial# (+) + group by topsession.sid, topsession.serial#, + topsession.user_id, topsession.program, s.username, + s.sid,s.paddr,u.username + order by max(topsession.TOTAL) desc +/ + diff --git a/ashmasters/ash_top_sql.sql b/ashmasters/ash_top_sql.sql new file mode 100644 index 0000000..e780736 --- /dev/null +++ b/ashmasters/ash_top_sql.sql @@ -0,0 +1,41 @@ + +/* + TOP SQL from dba_hist_active_sess_history no v$active_session_history + filter by DBID + + output looks like + + SQL_ID PLAN_HASH TYPE CPU WAIT IO TOTAL + ------------- ---------- ---------------- --------- ---------- --------- ---------- + fgzp9yqqjcjvm 707845071 UPDATE 25.0 95 4081.0 4201 + 8u8y8mc1qxd98 131695425 SELECT 18.0 57 3754.0 3829 + cfk8gy594h42s 3743737989 SELECT 2021.0 17 82.0 2120 + cnx6ht8bdmf4c 0 PL/SQL EXECUTE 546.0 367 868.0 1781 + gyj8wh7vx960y 1736948211 SELECT 197.0 11 1227.0 1435 + 1wmz1trqkzhzq 1384060092 SELECT 639.0 20 679.0 1338 + 5vjzz8f5ydqm7 1375932572 SELECT 538.0 0 541.0 1079 + 8w08jp8urfj6t 3134135242 SELECT 118.0 10 945.0 1073 + +*/ +col type for a10 +col "CPU" for 999999.9 +col "IO" for 999999.9 +select * from ( +select + ash.SQL_ID , ash.SQL_PLAN_HASH_VALUE Plan_hash, aud.name type, + sum(decode(ash.session_state,'ON CPU',1,0)) "CPU", + sum(decode(ash.session_state,'WAITING',1,0)) - + sum(decode(ash.session_state,'WAITING', decode(wait_class, 'User I/O',1,0),0)) "WAIT" , + sum(decode(ash.session_state,'WAITING', decode(wait_class, 'User I/O',1,0),0)) "IO" , + sum(decode(ash.session_state,'ON CPU',1,1)) "TOTAL" +from dba_hist_active_sess_history ash, + audit_actions aud +where SQL_ID is not NULL + and ash.dbid=&DBID + and ash.sql_opcode=aud.action + -- and ash.sample_time > sysdate - &minutes /( 60*24) +group by sql_id, SQL_PLAN_HASH_VALUE , aud.name +order by sum(decode(session_state,'ON CPU',1,1)) desc +) where rownum < 10 +/ + diff --git a/ashmasters/awr_sqlid_perf_trend.sql b/ashmasters/awr_sqlid_perf_trend.sql new file mode 100644 index 0000000..fcb1a5a --- /dev/null +++ b/ashmasters/awr_sqlid_perf_trend.sql @@ -0,0 +1,51 @@ +-- Maris Elsins / Pythian / 2013 +-- SQL performance trends from AWR +-- Usage: @awr_sqlid_perf_trend.sql +-- i.e. @awr_sqlid_perf_trend.sql 46ah673phw02j 2 4 +-- i.e. The example above summarizes the execution statistics for sql_id 46ah673phw02j in last 2 days breaking down the statistics by 4 hours. +-- v1.0 - inital version +-- v1.1 - Adding instance_number to the outputs +set ver off pages 50000 lines 260 tab off +undef sql_id +undef days_history +undef interval_hours +def sql_id="&1" +def days_history="&2" +def interval_hours="&3" +col inst for 9999 +col time for a19 +col executions for 9999999999 +col rows_processed_1exec for 9999999.999 +col elapsed_time_s_1exec for 9999999.999 +col cpu_time_s_1exec for 9999999.999 +col iowait_s_1exec for 9999999.999 +col clwait_s_1exec for 9999999.999 +col apwait_s_1exec for 9999999.999 +col ccwait_s_1exec for 9999999.999 +col plsexec_time_s_1exec for 9999999.999 +col javexec_time_s_1exec for 9999999.999 +col buffer_gets_1exec for 999999999999.999 +col disk_reads_1exec for 999999999999.999 +col direct_writes_1exec for 999999999999.999 +BREAK ON inst SKIP 1 +select hss.instance_number inst, + to_char(trunc(sysdate-&days_history+1)+trunc((cast(hs.begin_interval_time as date)-(trunc(sysdate-&days_history+1)))*24/(&interval_hours))*(&interval_hours)/24,'dd.mm.yyyy hh24:mi:ss') time, + sum(hss.executions_delta) executions, + round(sum(hss.elapsed_time_delta)/1000000/decode(sum(hss.executions_delta),0,null,sum(hss.executions_delta)),3) elapsed_time_s_1exec, + round(sum(hss.cpu_time_delta)/1000000/decode(sum(hss.executions_delta),0,null,sum(hss.executions_delta)),3) cpu_time_s_1exec, + round(sum(hss.iowait_delta)/1000000/decode(sum(hss.executions_delta),0,null,sum(hss.executions_delta)),3) iowait_s_1exec, + round(sum(hss.clwait_delta)/1000000/decode(sum(hss.executions_delta),0,null,sum(hss.executions_delta)),3) clwait_s_1exec, + round(sum(hss.apwait_delta)/1000000/decode(sum(hss.executions_delta),0,null,sum(hss.executions_delta)),3) apwait_s_1exec, + round(sum(hss.ccwait_delta)/1000000/decode(sum(hss.executions_delta),0,null,sum(hss.executions_delta)),3) ccwait_s_1exec, + --round(sum(hss.plsexec_time_delta)/1000000/decode(sum(hss.executions_delta),0,null,sum(hss.executions_delta)),3) plsexec_time_s_1exec, + --round(sum(hss.javexec_time_delta)/1000000/decode(sum(hss.executions_delta),0,null,sum(hss.executions_delta)),3) javexec_time_s_1exec, + round(sum(hss.rows_processed_delta)/decode(sum(hss.executions_delta),0,null,sum(hss.executions_delta)),3) rows_processed_1exec, + round(sum(hss.buffer_gets_delta)/decode(sum(hss.executions_delta),0,null,sum(hss.executions_delta)),3) buffer_gets_1exec, + round(sum(hss.disk_reads_delta)/decode(sum(hss.executions_delta),0,null,sum(hss.executions_delta)),3) disk_reads_1exec, + round(sum(hss.direct_writes_delta)/decode(sum(hss.executions_delta),0,null,sum(hss.executions_delta)),3) direct_writes_1exec +from dba_hist_sqlstat hss, dba_hist_snapshot hs +where hss.sql_id='&sql_id' + and hss.snap_id=hs.snap_id + and hs.begin_interval_time>=trunc(sysdate)-&days_history+1 +group by hss.instance_number, trunc(sysdate-&days_history+1)+trunc((cast(hs.begin_interval_time as date)-(trunc(sysdate-&days_history+1)))*24/(&interval_hours))*(&interval_hours)/24 +order by hss.instance_number,trunc(sysdate-&days_history+1)+trunc((cast(hs.begin_interval_time as date)-(trunc(sysdate-&days_history+1)))*24/(&interval_hours))*(&interval_hours)/24; diff --git a/ashmasters/awr_stat_trend.sql b/ashmasters/awr_stat_trend.sql new file mode 100644 index 0000000..c35a7fd --- /dev/null +++ b/ashmasters/awr_stat_trend.sql @@ -0,0 +1,31 @@ +-- Maris Elsins / Pythian / 2013 +-- System Statistic trends from AWR +-- Usage: @awr_stat_trend.sql +-- i.e. @awr_stat_trend.sql "physical read bytes" 2 4 +-- i.e. The example above summarizes the number of "physical read bytes" each 4 hours in last 2 days. +-- v1.0 - inital version +-- v1.1 - Adding instance_number to the outputs +set ver off pages 50000 lines 140 tab off +undef stat_name +undef days_history +undef interval_hours +def stat_name="&1" +def days_history="&2" +def interval_hours="&3" +col inst for 9999 +col time for a19 +col stat_name for a64 +col value for 9999999999999999 +BREAK ON inst SKIP 1 +select instance_number inst, to_char(time,'DD.MM.YYYY HH24:MI:SS') time, stat_name, sum(delta_value) value from + (select hss.instance_number, hss.snap_id, + trunc(sysdate-&days_history+1)+trunc((cast(hs.begin_interval_time as date)-(trunc(sysdate-&days_history+1)))*24/(&interval_hours))*(&interval_hours)/24 time, + stat_name, + value, + (lead(value,1) over(partition by hss.instance_number, hs.startup_time, stat_name order by hss.snap_id))-value delta_value + from DBA_HIST_SYSSTAT hss, dba_hist_snapshot hs + where hss.snap_id=hs.snap_id + and hs.begin_interval_time>=trunc(sysdate)-&days_history+1 + and hss.stat_name like '&stat_name') a +group by instance_number, time, stat_name +order by 1, 3, a.time; diff --git a/ashmasters/awr_top_by_fms_noinst.sql b/ashmasters/awr_top_by_fms_noinst.sql new file mode 100644 index 0000000..735a869 --- /dev/null +++ b/ashmasters/awr_top_by_fms_noinst.sql @@ -0,0 +1,54 @@ +-- Maris Elsins / Pythian / 2014 +-- Sorry, no description yet, but you can check http://www.pythian.com/blog/do-awr-reports-show-the-whole-pictureset ver off pages 50000 lines 260 tab off +undef days_history +undef interval_hours +def fms="&1" +def days_history="&2" +def interval_hours="&3" +def sort_col_nr="&4" +def top_n="&5" +col inst for 9999 +col time for a19 +col force_matching_signature for 99999999999999999999 +col executions for 9999999999 +col rows_processed for 9999999.999 +col elapsed_time_s for 9999999.999 +col cpu_time_s for 9999999.999 +col iowait_s for 9999999.999 +col clwait_s for 9999999.999 +col apwait_s for 9999999.999 +col ccwait_s for 9999999.999 +col plsexec_time_s for 9999999.999 +col javexec_time_s for 9999999.999 +col buffer_gets for 999999999999.999 +col disk_reads for 999999999999.999 +col direct_writes for 999999999999.999 +col diff_sqlid for a13 +col diff_plans for 9999999999 +col diff_fms for 99999999999999999999 + +BREAK ON inst SKIP 1 + +select * from ( +select force_matching_signature, + decode(count(unique(plan_hash_value)),1,max(plan_hash_value),count(unique(plan_hash_value))) diff_plans, + decode(count(unique(sql_id)),1,max(sql_id),count(unique(sql_id))) diff_sqlid, + sum(hss.executions_delta) executions, + round(sum(hss.elapsed_time_delta)/1000000,3) elapsed_time, + round(sum(hss.cpu_time_delta)/1000000,3) cpu_time, + round(sum(hss.iowait_delta)/1000000,3) iowait_s, + round(sum(hss.clwait_delta)/1000000,3) clwait_s, + round(sum(hss.apwait_delta)/1000000,3) apwait_s, + round(sum(hss.ccwait_delta)/1000000,3) ccwait_s, + round(sum(hss.rows_processed_delta),3) rows_processed, + round(sum(hss.buffer_gets_delta),3) buffer_gets, + round(sum(hss.disk_reads_delta),3) disk_reads, + round(sum(hss.direct_writes_delta),3) direct_writes +from dba_hist_sqlstat hss, dba_hist_snapshot hs +where hss.snap_id=hs.snap_id + and hss.force_matching_signature like '&fms' + and hs.begin_interval_time>=trunc(sysdate)-&days_history+1 + and hs.begin_interval_time<=trunc(sysdate)-&days_history+1+(&interval_hours/24) +group by force_matching_signature +order by &sort_col_nr desc) +where rownum<=&top_n; diff --git a/ashmasters/awr_top_by_plan_noinst.sql b/ashmasters/awr_top_by_plan_noinst.sql new file mode 100644 index 0000000..6de37e3 --- /dev/null +++ b/ashmasters/awr_top_by_plan_noinst.sql @@ -0,0 +1,53 @@ +-- Maris Elsins / Pythian / 2014 +-- Sorry, no description yet, but you can check http://www.pythian.com/blog/do-awr-reports-show-the-whole-picture +set ver off pages 50000 lines 260 tab off +undef days_history +undef interval_hours +def plan="&1" +def days_history="&2" +def interval_hours="&3" +def sort_col_nr="&4" +def top_n="&5" +col inst for 9999 +col time for a19 +col force_matching_signature for 99999999999999999999 +col executions for 9999999999 +col rows_processed for 9999999.999 +col elapsed_time_s for 9999999.999 +col cpu_time_s for 9999999.999 +col iowait_s for 9999999.999 +col clwait_s for 9999999.999 +col apwait_s for 9999999.999 +col ccwait_s for 9999999.999 +col plsexec_time_s for 9999999.999 +col javexec_time_s for 9999999.999 +col buffer_gets for 999999999999.999 +col disk_reads for 999999999999.999 +col direct_writes for 999999999999.999 +col diff_sqlid for a13 +col diff_plans for 9999999999 +col diff_fms for 99999999999999999999 + +select * from ( +select plan_hash_value, + decode(count(unique(force_matching_signature)),1,max(force_matching_signature),count(unique(force_matching_signature))) diff_fms, + decode(count(unique(sql_id)),1,max(sql_id),count(unique(sql_id))) diff_sqlid, + sum(hss.executions_delta) executions, + round(sum(hss.elapsed_time_delta)/1000000,3) elapsed_time, + round(sum(hss.cpu_time_delta)/1000000,3) cpu_time, + round(sum(hss.iowait_delta)/1000000,3) iowait_s, + round(sum(hss.clwait_delta)/1000000,3) clwait_s, + round(sum(hss.apwait_delta)/1000000,3) apwait_s, + round(sum(hss.ccwait_delta)/1000000,3) ccwait_s, + round(sum(hss.rows_processed_delta),3) rows_processed, + round(sum(hss.buffer_gets_delta),3) buffer_gets, + round(sum(hss.disk_reads_delta),3) disk_reads, + round(sum(hss.direct_writes_delta),3) direct_writes +from dba_hist_sqlstat hss, dba_hist_snapshot hs +where hss.snap_id=hs.snap_id + and hss.plan_hash_value like '&plan' + and hs.begin_interval_time>=trunc(sysdate)-&days_history+1 + and hs.begin_interval_time<=trunc(sysdate)-&days_history+1+(&interval_hours/24) +group by plan_hash_value +order by &sort_col_nr desc) +where rownum<=&top_n; diff --git a/ashmasters/awr_top_by_plan_noinst_sqlid.sql b/ashmasters/awr_top_by_plan_noinst_sqlid.sql new file mode 100644 index 0000000..c21e9ef --- /dev/null +++ b/ashmasters/awr_top_by_plan_noinst_sqlid.sql @@ -0,0 +1,52 @@ +-- Maris Elsins / Pythian / 2014 +-- Sorry, no description yet, but you can check http://www.pythian.com/blog/do-awr-reports-show-the-whole-pictureset ver off pages 50000 lines 260 tab off +undef days_history +undef interval_hours +def plan="&1" +def days_history="&2" +def interval_hours="&3" +def sort_col_nr="&4" +def top_n="&5" +col inst for 9999 +col time for a19 +col force_matching_signature for 99999999999999999999 +col executions for 9999999999 +col rows_processed for 9999999.999 +col elapsed_time_s for 9999999.999 +col cpu_time_s for 9999999.999 +col iowait_s for 9999999.999 +col clwait_s for 9999999.999 +col apwait_s for 9999999.999 +col ccwait_s for 9999999.999 +col plsexec_time_s for 9999999.999 +col javexec_time_s for 9999999.999 +col buffer_gets for 999999999999.999 +col disk_reads for 999999999999.999 +col direct_writes for 999999999999.999 +col sql_id for a13 +col diff_plans for 9999999999 +col force_matching_signature for 99999999999999999999 + +select * from ( +select plan_hash_value, + force_matching_signature, + sql_id, + sum(hss.executions_delta) executions, + round(sum(hss.elapsed_time_delta)/1000000,3) elapsed_time, + round(sum(hss.cpu_time_delta)/1000000,3) cpu_time, + round(sum(hss.iowait_delta)/1000000,3) iowait_s, + round(sum(hss.clwait_delta)/1000000,3) clwait_s, + round(sum(hss.apwait_delta)/1000000,3) apwait_s, + round(sum(hss.ccwait_delta)/1000000,3) ccwait_s, + round(sum(hss.rows_processed_delta),3) rows_processed, + round(sum(hss.buffer_gets_delta),3) buffer_gets, + round(sum(hss.disk_reads_delta),3) disk_reads, + round(sum(hss.direct_writes_delta),3) direct_writes +from dba_hist_sqlstat hss, dba_hist_snapshot hs +where hss.snap_id=hs.snap_id + and hss.plan_hash_value like '&plan' + and hs.begin_interval_time>=trunc(sysdate)-&days_history+1 + and hs.begin_interval_time<=trunc(sysdate)-&days_history+1+(&interval_hours/24) +group by plan_hash_value, force_matching_signature, sql_id +order by &sort_col_nr desc) +where rownum<=&top_n; diff --git a/ashmasters/awr_top_by_sqlid_noinst.sql b/ashmasters/awr_top_by_sqlid_noinst.sql new file mode 100644 index 0000000..38ac849 --- /dev/null +++ b/ashmasters/awr_top_by_sqlid_noinst.sql @@ -0,0 +1,52 @@ +-- Maris Elsins / Pythian / 2014 +-- Sorry, no description yet, but you can check http://www.pythian.com/blog/do-awr-reports-show-the-whole-pictureset ver off pages 50000 lines 260 tab off +undef days_history +undef interval_hours +def sql_id="&1" +def days_history="&2" +def interval_hours="&3" +def sort_col_nr="&4" +def top_n="&5" +col inst for 9999 +col time for a19 +col force_matching_signature for 99999999999999999999 +col executions for 9999999999 +col rows_processed for 9999999.999 +col elapsed_time_s for 9999999.999 +col cpu_time_s for 9999999.999 +col iowait_s for 9999999.999 +col clwait_s for 9999999.999 +col apwait_s for 9999999.999 +col ccwait_s for 9999999.999 +col plsexec_time_s for 9999999.999 +col javexec_time_s for 9999999.999 +col buffer_gets for 999999999999.999 +col disk_reads for 999999999999.999 +col direct_writes for 999999999999.999 +col diff_sqlid for a13 +col diff_plans for 9999999999 +col diff_fms for 99999999999999999999 + +select * from ( +select hss.sql_id, + decode(count(unique(plan_hash_value)),1,max(plan_hash_value),count(unique(plan_hash_value))) diff_plans, + decode(count(unique(force_matching_signature)),1,max(force_matching_signature),count(unique(force_matching_signature))) diff_fms, + sum(hss.executions_delta) executions, + round(sum(hss.elapsed_time_delta)/1000000,3) elapsed_time_s, + round(sum(hss.cpu_time_delta)/1000000,3) cpu_time_s, + round(sum(hss.iowait_delta)/1000000,3) iowait_s, + round(sum(hss.clwait_delta)/1000000,3) clwait_s, + round(sum(hss.apwait_delta)/1000000,3) apwait_s, + round(sum(hss.ccwait_delta)/1000000,3) ccwait_s, + round(sum(hss.rows_processed_delta),3) rows_processed, + round(sum(hss.buffer_gets_delta),3) buffer_gets, + round(sum(hss.disk_reads_delta),3) disk_reads, + round(sum(hss.direct_writes_delta),3) direct_writes +from dba_hist_sqlstat hss, dba_hist_snapshot hs +where hss.snap_id=hs.snap_id + and hss.sql_id like '&sql_id' + and hs.begin_interval_time>=trunc(sysdate)-&days_history+1 + and hs.begin_interval_time<=trunc(sysdate)-&days_history+1+(&interval_hours/24) +group by sql_id +order by &sort_col_nr desc nulls last) +where rownum<=&top_n; diff --git a/ashmasters/awr_wait_trend.sql b/ashmasters/awr_wait_trend.sql new file mode 100644 index 0000000..bed2968 --- /dev/null +++ b/ashmasters/awr_wait_trend.sql @@ -0,0 +1,33 @@ +-- Maris Elsins / Pythian / 2013 +-- Wait event trends from AWR +-- Usage: @awr_wait_trend.sql +-- i.e. @awr_wait_trend.sql "db file sequential read" 2 4 +-- i.e. The example above summarizes the number of "db file sequential read" each 4 hours in last 2 days. +-- v1.0 - inital version +-- v1.1 - Adding instance_number to the outputs +set ver off pages 50000 lines 140 tab off +undef event_name +undef days_history +undef interval_hours +def event_name="&1" +def days_history="&2" +def interval_hours="&3" +col inst for 9 +col time for a19 +col EVENT_NAME for a64 +col total_waits for 99999999999999 +col total_time_s for 999999999.999 +col avg_time_ms for 999999999.999 +BREAK ON inst SKIP 1 +select instance_number inst, to_char(time,'DD.MM.YYYY HH24:MI:SS') time, event_name, sum(delta_total_waits) total_waits, round(sum(delta_time_waited/1000000),3) total_time_s, round(sum(delta_time_waited)/decode(sum(delta_total_waits),0,null,sum(delta_total_waits))/1000,3) avg_time_ms from + (select hse.instance_number, hse.snap_id, + trunc(sysdate-&days_history+1)+trunc((cast(hs.begin_interval_time as date)-(trunc(sysdate-&days_history+1)))*24/(&interval_hours))*(&interval_hours)/24 time, + EVENT_NAME, + (lead(TOTAL_WAITS,1) over(partition by hse.instance_number, hs.STARTUP_TIME, EVENT_NAME order by hse.snap_id))-TOTAL_WAITS delta_total_waits, + (lead(TIME_WAITED_MICRO,1) over(partition by hse.instance_number, hs.STARTUP_TIME, EVENT_NAME order by hse.snap_id))-TIME_WAITED_MICRO delta_time_waited + from DBA_HIST_SYSTEM_EVENT hse, DBA_HIST_SNAPSHOT hs + where hse.snap_id=hs.snap_id + and hs.begin_interval_time>=trunc(sysdate)-&days_history+1 + and hse.EVENT_NAME like '&event_name') a +group by instance_number, time, event_name +order by 1, 3, a.time; diff --git a/ashmasters/event_histograms_delta_from_AWR.sql b/ashmasters/event_histograms_delta_from_AWR.sql new file mode 100644 index 0000000..f3b0cee --- /dev/null +++ b/ashmasters/event_histograms_delta_from_AWR.sql @@ -0,0 +1,47 @@ +select begin_interval_time, +ms1 - lag(ms1) over (order by begin_interval_time) ms1, +ms2 - lag(ms2) over (order by begin_interval_time) ms2, +ms4 - lag(ms4) over (order by begin_interval_time) ms4, +ms8 - lag(ms8) over (order by begin_interval_time) ms8, +ms16 - lag(ms16) over (order by begin_interval_time) ms16, +ms32 - lag(ms32) over (order by begin_interval_time) ms32, +ms64 - lag(ms64) over (order by begin_interval_time) ms64, +ms128 - lag(ms128) over (order by begin_interval_time) ms128, +ms256 - lag(ms256) over (order by begin_interval_time) ms256, +ms512 - lag(ms512) over (order by begin_interval_time) ms512, +ms1024 - lag(ms1024) over (order by begin_interval_time) ms1024, +ms2048 - lag(ms2048) over (order by begin_interval_time) ms2048 +from ( +select begin_interval_time, +max(ms1) ms1, +max(ms2) ms2, +max(ms4) ms4, +max(ms8) ms8, +max(ms16) ms16, +max(ms32) ms32, +max(ms64) ms64, +max(ms128) ms128, +max(ms256) ms256, +max(ms512) ms512, +max(ms1024) ms1024, +max(ms2048) ms2048 +from ( +select s.begin_interval_time, +decode (a.wait_time_milli,1,wait_count,0) ms1, +decode (a.wait_time_milli,2,wait_count,0) ms2, +decode (a.wait_time_milli,4,wait_count,0) ms4, +decode (a.wait_time_milli,8,wait_count,0) ms8, +decode (a.wait_time_milli,16,wait_count,0) ms16, +decode (a.wait_time_milli,32,wait_count,0) ms32, +decode (a.wait_time_milli,64,wait_count,0) ms64, +decode (a.wait_time_milli,128,wait_count,0) ms128, +decode (a.wait_time_milli,256,wait_count,0) ms256, +decode (a.wait_time_milli,512,wait_count,0) ms512, +decode (a.wait_time_milli,1024,wait_count,0) ms1024, +decode (a.wait_time_milli,2048,wait_count,0) ms2048 +from DBA_HIST_EVENT_HISTOGRAM a, dba_hist_snapshot s +where a.snap_id = s.snap_id and a.event_name like '%&event_name%' +) +group by begin_interval_time +order by begin_interval_time +) \ No newline at end of file diff --git a/ashmasters/latency_eventmetric.sql b/ashmasters/latency_eventmetric.sql new file mode 100644 index 0000000..42d64f9 --- /dev/null +++ b/ashmasters/latency_eventmetric.sql @@ -0,0 +1,39 @@ + + +/* wait event latency last minute + + output looks like + + NAME TIME_WAITED WAIT_COUNT AVGMS + ------------------------- ----------- ---------- ---------- + log file parallel write 2.538 4 6.345 + log file sync 2.329 1 23.287 + db file sequential read 0 0 + db file scattered read 0 0 + direct path read 0 0 + direct path read temp 0 0 + direct path write 0 0 + direct path write temp 0 0 + +*/ + +col name for a25 +select -- m.intsize_csec, + n.name , + round(m.time_waited,3) time_waited, + m.wait_count, + round(10*m.time_waited/nullif(m.wait_count,0),3) avgms +from v$eventmetric m, + v$event_name n +where m.event_id=n.event_id + and n.name in ( + 'db file sequential read', + 'db file scattered read', + 'direct path read', + 'direct path read temp', + 'direct path write', + 'direct path write temp', + 'log file sync', + 'log file parallel write' +) +/ diff --git a/ashmasters/latency_system_event.sql b/ashmasters/latency_system_event.sql new file mode 100644 index 0000000..37c31e7 --- /dev/null +++ b/ashmasters/latency_system_event.sql @@ -0,0 +1,46 @@ + + +/* wait event latency averaged over each hour + + output looks like + + BTIME AVG_MS + --------------- ---------- + 20-JUL-11 06:00 5.854 + 20-JUL-11 07:00 4.116 + 20-JUL-11 08:00 21.158 + 20-JUL-11 09:02 5.591 + 20-JUL-11 10:00 4.116 + 20-JUL-11 11:00 6.248 + 20-JUL-11 12:00 23.634 + 20-JUL-11 13:00 22.529 + 20-JUL-11 14:00 21.62 + 20-JUL-11 15:00 18.038 + 20-JUL-11 16:00 23.127 + +*/ + + +select + btime, + round((time_ms_end-time_ms_beg)/nullif(count_end-count_beg,0),3) avg_ms +from ( +select + to_char(s.BEGIN_INTERVAL_TIME,'DD-MON-YY HH24:MI') btime, + total_waits count_end, + time_waited_micro/1000 time_ms_end, + Lag (e.time_waited_micro/1000) + OVER( PARTITION BY e.event_name ORDER BY s.snap_id) time_ms_beg, + Lag (e.total_waits) + OVER( PARTITION BY e.event_name ORDER BY s.snap_id) count_beg +from + DBA_HIST_SYSTEM_EVENT e, + DBA_HIST_SNAPSHOT s +where + s.snap_id=e.snap_id + and e.event_name like '%&1%' +order by begin_interval_time +) +order by btime +/ + diff --git a/ashmasters/latency_waitclassmetric.sql b/ashmasters/latency_waitclassmetric.sql new file mode 100644 index 0000000..1806064 --- /dev/null +++ b/ashmasters/latency_waitclassmetric.sql @@ -0,0 +1,17 @@ + + +/* wait event latency last minute + + output looks like + + AVG_IO_MS + ---------- + 8.916 + +*/ + +select 10*time_waited/nullif(wait_count,0) avg_io_ms -- convert centi-seconds to milliseconds +from v$waitclassmetric m + where wait_class_id= 1740759767 -- User I/O +/ + diff --git a/ashmasters/load_awr.sql b/ashmasters/load_awr.sql new file mode 100644 index 0000000..2355cd0 --- /dev/null +++ b/ashmasters/load_awr.sql @@ -0,0 +1,18 @@ +col "phy read / sec" format 9999999.99 +col "log read / sec" format 9999999.99 +col BEGIN_INTERVAL_TIME format a40 +select begin_interval_time, pr/sec "phy read / sec", lr/sec "log read / sec" from +( + select begin_interval_time, snap_id, + (cast(min(begin_interval_time) as date) - cast((lag(min(begin_interval_time)) over (order by snap_id)) as date))*24*60*60 sec, + sum(pr) pr, sum(lr) lr + from + ( + select s.snap_id, begin_interval_time, decode(stat_name, 'physical reads', delta, 0) pr, decode(stat_name, 'physical reads', 0, delta ) lr + from (select snap_id, INSTANCE_NUMBER, stat_name, value, value - lag(value) over (partition by stat_name order by snap_id) delta + from (select STAT_NAME, value , snap_id, INSTANCE_NUMBER + from dba_hist_sysstat where stat_name in ('physical reads','db block gets','consistent gets') + and INSTANCE_NUMBER = 1 order by snap_id)) s, + dba_hist_snapshot ss where s.snap_id = ss.snap_id and s.instance_number = ss.instance_number) + group by begin_interval_time, snap_id order by snap_id) +order by begin_interval_time; \ No newline at end of file diff --git a/ashmasters/top10_sql_with_events_from_AWR.sql b/ashmasters/top10_sql_with_events_from_AWR.sql new file mode 100644 index 0000000..e58788b --- /dev/null +++ b/ashmasters/top10_sql_with_events_from_AWR.sql @@ -0,0 +1,12 @@ + +select begin_interval_time, sql_id, event, cnt from ( +select begin_interval_time, sql_id, event, cnt, rank() over (partition by begin_interval_time order by total_sql desc) r, total_sql from ( +select begin_interval_time, sql_id, decode(session_state,'WAITING',event,'ON CPU') event, count(*) cnt, sum(count(*)) over (partition by begin_interval_time,sql_id) total_sql +from dba_hist_active_sess_history ash, dba_hist_snapshot d +where --program = 'xxxxxxxxx' and event = 'db file sequential read' +ash.snap_id = d.snap_id and sql_id is not null +group by begin_interval_time, sql_id, decode(session_state,'WAITING',event,'ON CPU') +having count(*) > 1 +order by begin_interval_time, cnt desc +) ) where r < 10 +order by begin_interval_time, r, cnt desc; diff --git a/ashmasters/topaas/runtopaas.sql b/ashmasters/topaas/runtopaas.sql new file mode 100644 index 0000000..3b45e5e --- /dev/null +++ b/ashmasters/topaas/runtopaas.sql @@ -0,0 +1,219 @@ +-- +-- TOPAAS +-- Copyright: Marcin Przepiorowski - All rights reserved. +-- +-- Special thanks go to Tanel Poder and Adrian Billington for idea of real time screen refresh in SQL*Plus window and PL/SQL collection based on internal Oracle package. +-- +-- runtopaas is displaying Oracle Average Active Session calculated based on v$session samples. It is read only and doesn't need any objects inside database. +-- It is sampling data using v$session so it will work on Standard and Enterprise Edition without any additional packs. +-- This tool is using two scripts: +-- runtopaas.sql - is a main script to parse run attributes and specify a run environment for topaas.sql script. It is calling topaas.sql 100 times +-- topaas.sql - is sampling v$session every 1 s for time specified in refresh rate parameters and keep it in PL/SQL collection +-- At the end AAS (divided into 3 sections: CPU, Disk I/O and other) is calculated and displayed on screen. +-- In addition to that AAS results are added to bind variables together with sample time. +-- When topaas.sql is called next time it is reading data from bind variables and it allow it to have history of AAS from past and display +-- it on screen. Default configuration allow to display 100 data point +-- +-- Usage: +-- Change SQL*Plus window / screen terminal to 45 characters height and 150 characters wide +-- Run in SQL*Plus window: +-- +-- @runtopaas.sql aas: - it will specify refresh rate (ex. 15 s) and with 100 samples it allow to keep 25 min of AAS in SQL*Plus window. +-- If script will be started again after 100 cycles or after user break in this same session it will still be able to display historical data +-- @runtopaas.sql aas::reset - like above but historical data are cleared +-- @runtopaas.sql aas:: - like above but maximum value of AAS (y axis) is set by user +-- @runtopaas.sql aas:::reset - like above but historical data are cleared + + +prompt "Waiting for first refresh" +set term off +DEFINE _OLD_ONCPU = "" +DEFINE _OLD_USERIO = "" +DEFINE _OLD_OTHER = "" +DEFINE _OLD_AAS_TIME = "" +DEFINE _OLD_RUNMAX = "0" + + +col ifdefcpu noprint new_value _OLD_ONCPU +col ifdefio noprint new_value _OLD_USERIO +col ifdefother noprint new_value _OLD_OTHER +col ifdefaastime noprint new_value _OLD_AAS_TIME +col ifdefrunmax noprint new_value _OLD_RUNMAX + +select :on_cpu ifdefcpu from dual; +select :aas_time ifdefaastime from dual; +select :user_io ifdefio from dual; +select :other ifdefother from dual; +select :runmax ifdefrunmax from dual; + + +var on_cpu varchar2(1000); +var aas_time varchar2(1000); +var user_io varchar2(1000); +var other varchar2(1000); +var runmax number; +var usermax number; +var refresh number; +--def refresh = 15; + + +declare +reset number; + +procedure read_commandline is +begin + for c in (select * from (select level l, substr('&&1',instr('&&1',':',1,level)+1, decode(instr('&&1',':',1,level+1),0,length('&&1'),instr('&&1',':',1,level+1)-instr('&&1',':',1,level)-1)) conf +from dual connect by instr('&&1',':',1,level) > 0) where conf<>'aas') loop + if (lower(c.conf) like 'reset') then + reset:=1; + else + reset := 0; + case c.l + when 1 then :refresh:=to_number(c.conf); + when 2 then :usermax:=to_number(c.conf); + else null; + end case; + end if; + end loop; +end read_commandline; + +begin +read_commandline; +--dbms_output.put_line(nvl(length('&&_OLD_ONCPU'),'0')); +--dbms_output.put_line('&&_OLD_ONCPU'); +-- select count(*) into reset from dual where '&&1' like 'reset'; + if reset = 0 then + if nvl(length('&&_OLD_ONCPU'),'0') != 0 then + :on_cpu := '&&_OLD_ONCPU' ; + :aas_time := '&&_OLD_AAS_TIME' ; + :user_io := '&&_OLD_USERIO'; + :other := '&&_OLD_OTHER'; + :runmax := '&&_OLD_RUNMAX'; + end if; + else + :on_cpu := ''; + :aas_time := '' ; + :user_io := ''; + :other := ''; + :runmax := ''; + end if; +end; +/ + +set term on + +set serveroutput on format wrapped +set linesize 150 +set feedback off +set ver off + +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas +@topaas diff --git a/ashmasters/topaas/topaas.sql b/ashmasters/topaas/topaas.sql new file mode 100644 index 0000000..a3a6b03 --- /dev/null +++ b/ashmasters/topaas/topaas.sql @@ -0,0 +1,328 @@ +-- +-- TOPAAS v.0.2 +-- Copyright: Marcin Przepiorowski - All rights reserved. +-- +-- Special thanks go to Tanel Poder and Adrian Billington for idea of real time screen refresh in SQL*Plus window and PL/SQL collection based on internal Oracle package. +-- +-- Usage: +-- runtopaas is displaying Oracle Average Active Session calculated based on v$session samples +-- This tool is using two scripts: +-- runtopaas.sql - is a main script to parse run attributes and specify a run environment for topaas.sql script. It is calling topaas.sql 100 times +-- topaas.sql - is sampling v$session every 1 s for time specified in refresh rate parameters and keep it in PL/SQL collection +-- At the end AAS (divided into 3 sections: CPU, Disk I/O and other) is calculated and displayed on screen. +-- In addition to that AAS results are added to bind variables together with sample time. +-- When topaas.sql is called next time it is reading data from bind variables and it allow it to have history of AAS from past and display +-- it on screen. Default configuration allow to display 100 data point +-- +-- Usage: +-- Change SQL*Plus window / screen terminal to 45 characters height and 150 characters wide +-- Run in SQL*Plus window: +-- +-- @runtopaas.sql aas: - it will specify refresh rate (ex. 15 s) and with 100 samples it allow to keep 25 min of AAS in SQL*Plus window. +-- If script will be started again after 100 cycles or after user break in this same session it will still be able to display historical data +-- @runtopaas.sql aas::reset - like above but historical data are cleared +-- @runtopaas.sql aas:: - like above but maximum value of AAS (y axis) is set by user +-- @runtopaas.sql aas:::reset - like above but historical data are cleared + +-- new in 0.2 +-- - history separator changed from , to | and moved to variable + +-- RUN RUNTOPAAS.SQL NOT THIS SCRIPT + + declare + type type_lines is table of varchar2(200) index by pls_integer; + lines type_lines; + top_sql type_lines; + + screen_hight number := 40; + axe_y_hight number := 20; + y_offset number := 4; + no_disp_samples number := 80; + maxrun number; -- := 10; + cpu_count number; + entry_separator char := '|'; + + procedure shift_data is + begin + if (instr(:on_cpu,entry_separator,1,no_disp_samples)>0) then + :on_cpu := substr(:on_cpu,instr(:on_cpu,entry_separator,1,1)+1); + :user_io:= substr(:user_io,instr(:user_io,entry_separator,1,1)+1); + :other:= substr(:other,instr(:other,entry_separator,1,1)+1); + :aas_time := substr(:aas_time,instr(:aas_time,entry_separator,1,1)+1); + end if; + end; + + procedure fill_lines(line varchar2) is + aassize number; + begin + aassize := length(line); + if (aassize > 0) then + for j in 1+y_offset..screen_hight+y_offset loop + if ((j<=aassize+y_offset) and (j<=axe_y_hight+y_offset)) then + lines(j) := lines(j) || substr(line,j-y_offset,1); + else + lines(j) := lines(j) || ' '; + end if; + end loop; + else + for j in 1+y_offset..screen_hight+y_offset loop + lines(j) := lines(j) || ' '; + end loop; + end if; + end; -- fill_lines + + procedure create_x_axe is + begin + lines(y_offset) := ' ' || lpad('-',no_disp_samples,'-'); + end create_x_axe; + + procedure create_y_axe(maxaas number) is + y_cpu number; + tick number; + ytick number; + begin + + tick := (axe_y_hight / maxaas); + --y_cpu := cpu_count*axe_y_hight/maxaas+y_offset; + y_cpu := cpu_count*tick+y_offset; + --dbms_output.put_line(' tick - ' || tick); + if (tick <= 1) then + ytick := 3; + else + ytick := tick; + end if; + --dbms_output.put_line(' ytick - ' || ytick); + for j in 1+y_offset..axe_y_hight+y_offset loop + --lines(j) := lines(j) || ' |'; + if (mod((j-y_offset),round(ytick)) = 0) then + lines(j) := ' ' || to_char((j-y_offset)/tick,'99999') || ' |' || lines(j) ; + else + lines(j) := ' |' || lines(j); + end if; + end loop; + --lines(axe_y_hight+2) := ' ' || to_char(maxaas,'99999') || substr(lines(axe_y_hight+2), length(to_char(maxaas,'99999'))+1+2); + lines(axe_y_hight+2+y_offset) := ' ' || to_char(maxaas,'99999'); + lines(axe_y_hight+3+y_offset) := ' Max AAS '; + lines(axe_y_hight+5+y_offset) := ' Refresh rate / Column size ' || :refresh || ' sec'; + if (trunc(y_cpu) <= axe_y_hight+y_offset) then + lines(trunc(y_cpu)) := 'cpu' || substr(lines(trunc(y_cpu)), 4); + end if; + end; -- create_y_axe + + + procedure reset_lines is + begin + for i in 1..screen_hight+y_offset loop + lines(i) := ''; + end loop; + end reset_lines; + + procedure sash (sleep number, refresh_rate number) is + start_time date; + g_aas sys.dbms_debug_vc2coll := new sys.dbms_debug_vc2coll(); + g_cats sys.dbms_debug_vc2coll := new sys.dbms_debug_vc2coll('ON CPU','Disk','Other'); + + begin + for i in 1..refresh_rate loop + for f in (select case wait_class + when 'Other' then 'Other' + when 'Application' then 'Other' + when 'Configuration' then 'Other' + when 'Administrative' then 'Other' + when 'Concurrency' then 'Other' + when 'Commit' then 'Other' + when 'Network' then 'Other' + when 'User I/O' then 'Disk' + when 'System I/O' then 'Disk' + when 'Scheduler' then 'Other' + when 'Cluster' then 'Other' + when 'Queueing' then 'Other' + when 'ON CPU' then 'ON CPU' + end wait_class, + sql_id, + cnt + from (select decode(WAIT_TIME,0,wait_class,'ON CPU') wait_class, sql_id, 1 cnt from v$session where nvl(wait_class,'on cpu') <> 'Idle' and sid != (select distinct sid from v$mystat) + --group by decode(WAIT_TIME,0,wait_class,'ON CPU') + ) + ) loop + g_aas.extend(1); + g_aas(g_aas.count) := f.wait_class || entry_separator || f.sql_id || entry_separator || f.cnt; + --dbms_output.put_line(f.wait_class || ',' || f.sql_id || ',' || f.cnt); + end loop; + dbms_lock.sleep(sleep); + end loop; + + for r in (select g.column_value wait_class, nvl(cnt,0) cnt, (sum(nvl(cnt,0)) over ())/15 aas from ( + select substr(t.column_value,0,instr(t.column_value,entry_separator,1,1)-1) wait_class, count(*) cnt + from table(cast(g_aas as sys.dbms_debug_vc2coll)) t + group by substr(t.column_value,0,instr(t.column_value,entry_separator,1,1)-1) + ) t, table(cast(g_cats as sys.dbms_debug_vc2coll)) g where t.wait_class(+) = g.column_value + ) loop + --dbms_output.put_line('Summary ' || r.wait_class || '-' || r.cnt || ' ass - ' || r.aas); + case r.wait_class + when 'ON CPU' then :on_cpu := :on_cpu || nvl(to_char(r.cnt/(refresh_rate*sleep),'9999.99'),0) || entry_separator; + when 'Disk' then :user_io := :user_io || nvl(to_char(r.cnt/(refresh_rate*sleep),'9999.99'),0) || entry_separator; + when 'Other' then :other := :other || nvl(to_char(r.cnt/(refresh_rate*sleep),'9999.99'),0) || entry_separator; + end case; + end loop; + + -- top SQL + + for r in (select sql_id, nvl(cnt,0)/total cnt, rownum rl, total from ( + select substr(t.column_value,instr(t.column_value,entry_separator,1,1)+1,13) sql_id, count(*) cnt, sum(count(*)) over () total + from table(cast(g_aas as sys.dbms_debug_vc2coll)) t + where substr(t.column_value,instr(t.column_value,entry_separator,1,1)+1,1) <> entry_separator + group by substr(t.column_value,instr(t.column_value,entry_separator,1,1)+1,13) + order by 2 desc + ) t where rownum < 6 + ) loop + --dbms_output.put_line('Summary ' || r.wait_class || '-' || r.cnt || ' ass - ' || r.aas); + --dbms_output.put_line(r.sql_id || ' - ' || r.cnt || ' - ' || r.total); + top_sql(r.rl) := r.sql_id || ' - ' || to_char(r.cnt*100,'999.99') || ' % '; + + end loop; + + + :aas_time:= :aas_time || to_char(sysdate,'HH24:MI:SS') || entry_separator; + end sash; + + procedure read_data(maxaas in out number) is + aas varchar2(1000); +-- maxaas number := 10; + runmax number := 1; + x_axe_tick varchar2(1000) := ' '; + x_axe_time varchar2(1000) := ' '; + tick number; + begin + + for r in + ( select on_cpu_item, user_io_item, aas_time_item, other_item, l, max(other_item+on_cpu_item + user_io_item) over () maxaas from ( + select substr + ( :on_cpu + , case when level = 1 then 0 else instr(:on_cpu,entry_separator,1,level-1) + 1 end + , instr(:on_cpu,entry_separator,1,level) - case when level = 1 then 1 else instr(:on_cpu,entry_separator,1,level-1) + 1 end + ) on_cpu_item, + substr + ( :other + , case when level = 1 then 0 else instr(:other,entry_separator,1,level-1) + 1 end + , instr(:other,entry_separator,1,level) - case when level = 1 then 1 else instr(:other,entry_separator,1,level-1) + 1 end + ) other_item, + substr + ( :user_io + , case when level = 1 then 0 else instr(:user_io,entry_separator,1,level-1) + 1 end + , instr(:user_io,entry_separator,1,level) - case when level = 1 then 1 else instr(:user_io,entry_separator,1,level-1) + 1 end + ) user_io_item, + substr + ( :aas_time + , case when level = 1 then 0 else instr(:aas_time,entry_separator,1,level-1) + 1 end + , instr(:aas_time,entry_separator,1,level) - case when level = 1 then 1 else instr(:aas_time,entry_separator,1,level-1) + 1 end + ) aas_time_item, + level l + from dual + connect by INSTR(:user_io, entry_separator, 1, LEVEL)>0 + ) + ) + loop + tick := (axe_y_hight/greatest(r.maxaas, cpu_count)); + if (:usermax is not null) then + runmax:=:usermax; + else + runmax:=r.maxaas; + end if; + --tick := (axe_y_hight/greatest(4, cpu_count)); + --runmax:=4; + --dbms_output.put_line('read_data tick ' || tick); + --dbms_output.put_line('read_data axe_y_hight ' || axe_y_hight); + --dbms_output.put_line('read_data r.maxaas' || r.maxaas); + --aas := lpad('#',r.on_cpu_item*axe_y_hight/maxaas,'#') || lpad('D',r.user_io_item*axe_y_hight/maxaas,'D'); + --aas := lpad('#',r.on_cpu_item*tick,'#') || lpad('+',r.user_io_item*tick,'+') || lpad('O',r.other_item*tick,'O'); + aas := lpad('#',round(r.on_cpu_item*tick),'#') || lpad('+',round(r.user_io_item*tick),'+') || lpad('O',round(r.other_item*tick),'O'); + --dbms_output.put_line('lenght - ' || length(aas) || ' on cpu ' || r.on_cpu_item || ' user ' || r.user_io_item || ' multi ' || tick); + --dbms_output.put_line('lenght - ' || length(aas) || ' on cpu ' || r.on_cpu_item || ' user ' || r.user_io_item || ' multi ' || tick); + --if ((length(aas)/axe_y_hight*maxaas) > runmax) then + -- runmax := length(aas)/axe_y_hight*maxaas; + --end if; + --if ((length(aas)/tick) > runmax) then + -- runmax := length(aas)/tick; + --end if; + if (mod(r.l-1,16)=0) then + x_axe_time := x_axe_time || r.aas_time_item || lpad(' ',16-length(r.aas_time_item)); + --x_axe_tick := x_axe_tick || '+' || lpad(' ',14); + end if; + if (mod(r.l-1,8)=0) then + x_axe_tick := x_axe_tick || '+' || lpad(' ',7); + end if; + fill_lines(aas); + --dbms_output.put_line('aas - ' ||aas); + --dbms_output.put_line('w perli runmax - ' ||runmax); + end loop; + maxaas := greatest(runmax, cpu_count); + --maxaas:=4; + --dbms_output.put_line('po petli runmax - ' ||maxaas || ' ' || cpu_count); + create_y_axe(maxaas); + create_x_axe; + lines(2):=x_axe_time; + lines(3):=x_axe_tick; + --dbms_output.put_line(runmax); + end read_data; + + procedure print_legend is + begin + lines(4+y_offset) := substr(lines(4+y_offset), 0, 100) || lpad(' ', 100-length(lines(4+y_offset))) || ' Legend '; + lines(3+y_offset) := substr(lines(3+y_offset), 0, 100) || lpad(' ', 100-length(lines(3+y_offset))) || ' # - ON CPU '; + lines(2+y_offset) := substr(lines(2+y_offset), 0, 100) || lpad(' ', 100-length(lines(2+y_offset))) || ' + - Disk I/O '; + lines(1+y_offset) := substr(lines(1+y_offset), 0, 100) || lpad(' ', 100-length(lines(1+y_offset))) || ' O - Other '; + end print_legend; + + procedure print_top5 is + begin + lines(14+y_offset) := substr(lines(14+y_offset), 0, 100) || lpad(' ', 100-length(lines(14+y_offset))) || top_sql(1); + lines(13+y_offset) := substr(lines(13+y_offset), 0, 100) || lpad(' ', 100-length(lines(13+y_offset))) || top_sql(2); + lines(12+y_offset) := substr(lines(12+y_offset), 0, 100) || lpad(' ', 100-length(lines(12+y_offset))) || top_sql(3); + lines(11+y_offset) := substr(lines(11+y_offset), 0, 100) || lpad(' ', 100-length(lines(11+y_offset))) || top_sql(4); + lines(10+y_offset) := substr(lines(10+y_offset), 0, 100) || lpad(' ', 100-length(lines(10+y_offset))) || top_sql(5); + exception when no_data_found then + null; + end print_top5; + + procedure display is + begin + print_legend; + print_top5; + for i in 1..screen_hight loop + dbms_output.put_line(lines(screen_hight-i+1)); + end loop; + end; + + + begin + reset_lines; + --select value into cpu_count from v$system_parameter where name = 'cpu_count'; + select sum(value) into cpu_count from (select lag(value) over (order by name) / value value from v$system_parameter where name in ('cpu_count','parallel_threads_per_cpu')); + maxrun := cpu_count+1; + if (:usermax is not null) then + maxrun := :usermax; + cpu_count:=:usermax; + end if; + if (:runmax != maxrun) then + maxrun := :runmax; + end if; + --:on_cpu:= :on_cpu || to_char(dbms_random.value(0,8),'99.99') || ','; + --:aas_time:= :aas_time || to_char(sysdate,'HH24:MI:SS') || ','; + --:user_io:= :user_io || to_char(dbms_random.value(0,20),'99.99') || ','; + + if (:refresh is null) then + :refresh := 15; + end if; + --dbms_output.put_line('maxrun ' || :usermax ); + sash(1,:refresh); + read_data(maxrun); + --dbms_output.put_line('maxrun ' || maxrun ); + + display; + :runmax := maxrun; + shift_data; + end; + / + +--@topaas_full.sql diff --git a/ashmasters/topsql.sql b/ashmasters/topsql.sql new file mode 100644 index 0000000..89a713b --- /dev/null +++ b/ashmasters/topsql.sql @@ -0,0 +1,36 @@ +select * from ( +select sql_id, round(w*100,2) pct, +nvl("'ON CPU'",0) "CPU", +nvl("'Scheduler'",0) Scheduler , +nvl("'User I/O'",0) "User I/O" , +nvl("'System I/O'",0) "System I/O" , +nvl("'Concurrency'",0) Concurrency , +nvl("'Application'",0) Application , +nvl("'Commit'",0) Commit, +nvl("'Configuration'",0) Configuration, +nvl("'Administrative'",0) Administrative , +nvl("'Network'",0) Network , +nvl("'Queueing'",0) Queueing , +nvl("'Cluster'",0) "Cluster", +nvl("'Other'",0) Other +from ( + select sql_id, + decode(session_state,'WAITING',wait_class,'ON CPU') wait_class, + sum(count(*)) over (partition by sql_id) / sum(count(*)) over () w, + count(*) cnt, + sum(count(*)) over () totalsum + from v$active_session_history + where sample_time > sysdate - &NUM_MIN/24/60 + group by sql_id, + decode(session_state,'WAITING',wait_class,'ON CPU') + order by sql_id +) +pivot ( + sum(round(cnt/totalsum*100,2)) + for (wait_class) in + ('Administrative','Application','Cluster','Commit','Concurrency', + 'Configuration','Network','Other','Queueing','Scheduler','System I/O', + 'User I/O','ON CPU' + ) +) where sql_id is not null order by 2 desc +) where rownum < 10;