Skip to content

Commit 6d63fd4

Browse files
committed
adding new awr analysis tools
1 parent b52dc2f commit 6d63fd4

File tree

2 files changed

+81
-0
lines changed

2 files changed

+81
-0
lines changed

top_excel.sql

+29
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,29 @@
1+
select * from dba_hist_snapshot order by snap_id
2+
108 132
3+
4+
with awr_ranks as
5+
(
6+
select snap_id, sql_id,
7+
buffer_gets_delta,
8+
dense_rank() over (partition by snap_id order by buffer_gets_delta desc) gets_rank,
9+
cpu_time_delta,
10+
dense_rank() over (partition by snap_id order by cpu_time_delta desc) cpu_rank,
11+
elapsed_time_delta,
12+
dense_rank() over (partition by snap_id order by elapsed_time_delta desc) elapsed_rank,
13+
executions_delta,
14+
dense_rank() over (partition by snap_id order by executions_delta desc) executions_rank
15+
from sys.wrh$_sqlstat
16+
), rank as
17+
(
18+
select level rank from dual connect by level <= 5
19+
)
20+
select snap_id,
21+
rank,
22+
max(case gets_rank when rank then to_char(buffer_gets_delta)||': '||sql_id end) gets_sql,
23+
max(case cpu_rank when rank then to_char(round(cpu_time_delta/1000000,2))||': '||sql_id end) cpu_sql,
24+
max(case elapsed_rank when rank then to_char(round(elapsed_time_delta/1000000,2))||': '||sql_id end) elapsed_sql,
25+
max(case executions_rank when rank then to_char(executions_delta)||': '||sql_id end) executions_sql
26+
from awr_ranks, rank
27+
where snap_id between 110 and 131
28+
group by snap_id, rank
29+
order by snap_id, rank;

top_queries.sql

+52
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,52 @@
1+
set serveroutput on
2+
declare
3+
clobsqltext CLOB;
4+
v_start_snap_id number := 110;
5+
v_end_snap_id number := 131;
6+
begin
7+
for v_sql_id in (select sql_id,count(*) cnt from (
8+
select snap_id, sql_id,
9+
buffer_gets_delta,
10+
dense_rank() over (partition by snap_id order by buffer_gets_delta desc) gets_rank,
11+
cpu_time_delta,
12+
dense_rank() over (partition by snap_id order by cpu_time_delta desc) cpu_rank,
13+
elapsed_time_delta,
14+
dense_rank() over (partition by snap_id order by elapsed_time_delta desc) elapsed_rank
15+
--,executions_delta
16+
--,dense_rank() over (partition by snap_id order by executions_delta desc) executions_rank
17+
from sys.wrh$_sqlstat
18+
where snap_id>=v_start_snap_id and snap_id<=v_end_snap_id)
19+
where gets_rank<=5 or cpu_rank<=5 or elapsed_rank<=5
20+
--or executions_rank<=5
21+
group by sql_id
22+
order by cnt desc)
23+
loop
24+
dbms_output.put_line('SQL='||v_sql_id.sql_id || ' was top SQL ' || v_sql_id.cnt || ' times');
25+
26+
for line in (select plan_table_output from table(DBMS_XPLAN.DISPLAY_AWR(v_sql_id.sql_id)))
27+
loop
28+
dbms_output.put_line(line.plan_table_output);
29+
END LOOP;
30+
31+
for line in (select snap_id,executions_delta execs,
32+
round(buffer_gets_delta/executions_delta,2) gets_per_exec,
33+
round(rows_processed_delta/executions_delta,2) rows_per_exec,
34+
round((elapsed_time_delta/1000000)/executions_delta,2) ela_per_exec
35+
from sys.wrh$_sqlstat
36+
where sql_id=v_sql_id.sql_id
37+
and executions_delta > 0)
38+
loop
39+
dbms_output.put_line('snapshot = ' || line.snap_id || ' ** execs = ' || line.execs
40+
|| ' ** gets_per_exec = ' || line.gets_per_exec || ' ** rows_per_exec ' || line.rows_per_exec || ' ** ela_per_exec '|| line.ela_per_exec);
41+
end loop;
42+
43+
for line in ( select snap_id,name, position, datatype_string, value_string from dba_hist_sqlbind where sql_id=v_sql_id.sql_id)
44+
loop
45+
if line.value_string is not null then
46+
dbms_output.put_line('**** bind variables for snapshot = ' || line.snap_id || ' name=' || line.name
47+
|| ' position=' || line.position || ' datatype=' || line.datatype_string || ' value=' || line.value_string);
48+
end if;
49+
end loop;
50+
end loop;
51+
END;
52+
/

0 commit comments

Comments
 (0)