对 Tom 的 RunStats 包的两点说明

Tom 的 RUNSTATS 是一个很好用的 Benchmark 工具包.创建的时候有两点需要注意:

一. V$TIMER 这个视图的访问要和 SYS.V_$STATNAME, SYS.V_$MYSTAT, SYS.V_$LATCH 一样的进行一下处理,否则会报错

SQL>grant select on sys.v_$timer to MyUser;

二.为了避免 ORA-20000 的错误,可以考虑在创建脚本中加上 dbms_output.enable(480000); 这样以后在调用的时候只需要 set serveroutput on 即可.省事不少.当然也可以通过 set serveroutput on buffer …来控制,我个人不喜欢用 :)

修改后的脚本(对过程名字稍稍有点调整):

create or replace package runstats
as
procedure bench_start;
procedure bench_middle;
procedure bench_stop( p_difference_threshold in number default 0 );
end;
/
create or replace package body runstats
as
g_start number;
g_run1  number;
g_run2  number;
procedure bench_start
is
begin
delete from run_stats;
insert into run_stats
select 'before', stats.* from stats;
g_start := dbms_utility.get_time;
end;
procedure bench_middle
is
begin
g_run1 := (dbms_utility.get_time-g_start);
insert into run_stats
select 'after 1', stats.* from stats;
g_start := dbms_utility.get_time;
end;
procedure bench_stop(p_difference_threshold in number default 0)
is
begin
g_run2 := (dbms_utility.get_time-g_start);
--add a line here to avoid ora-20000
dbms_output.enable(480000);
dbms_output.put_line
( 'Run1 ran in ' || g_run1 || ' hsecs' );
dbms_output.put_line
( 'Run2 ran in ' || g_run2 || ' hsecs' );
dbms_output.put_line
( 'run 1 ran in ' || round(g_run1/g_run2*100,2) ||
'% of the time' );
dbms_output.put_line( chr(9) );
insert into run_stats
select 'after 2', stats.* from stats;
dbms_output.put_line
( rpad( 'Name', 30 ) || lpad( 'Run1', 12 ) ||
lpad( 'Run2', 12 ) || lpad( 'Diff', 12 ) );
for x in
( select rpad( a.name, 30 ) ||
to_char( b.value-a.value, '999,999,999' ) ||
to_char( c.value-b.value, '999,999,999' ) ||
to_char( ( (c.value-b.value)-(b.value-a.value)), '999,999,999' ) data
from run_stats a, run_stats b, run_stats c
where a.name = b.name
and b.name = c.name
and a.runid = 'before'
and b.runid = 'after 1'
and c.runid = 'after 2'
-- and (c.value-a.value) > 0
and abs( (c.value-b.value) - (b.value-a.value) )
> p_difference_threshold
order by abs( (c.value-b.value)-(b.value-a.value))
) loop
dbms_output.put_line( x.data );
end loop;
dbms_output.put_line( chr(9) );
dbms_output.put_line
( 'Run1 latches total versus runs -- difference and pct' );
dbms_output.put_line
( lpad( 'Run1', 12 ) || lpad( 'Run2', 12 ) ||
lpad( 'Diff', 12 ) || lpad( 'Pct', 10 ) );
for x in
( select to_char( run1, '999,999,999' ) ||
to_char( run2, '999,999,999' ) ||
to_char( diff, '999,999,999' ) ||
to_char( round( run1/run2*100,2 ), '99,999.99' ) || '%' data
from ( select sum(b.value-a.value) run1, sum(c.value-b.value) run2,
sum( (c.value-b.value)-(b.value-a.value)) diff
from run_stats a, run_stats b, run_stats c
where a.name = b.name
and b.name = c.name
and a.runid = 'before'
and b.runid = 'after 1'
and c.runid = 'after 2'
and a.name like 'LATCH%'
)
) loop
dbms_output.put_line( x.data );
end loop;
end;
end;
/

附录:DBMS_OUTPUT.ENABLE vs SET SERVEROUTPUT ON

DBMS_OUTPUT.ENABLE enables calls to put, put_line, new_line, get_line and
get_lines. If the dbms_output package has not been enabled, calls to these
procedures will be ignored.
If DBMS_OUTPUT package has been enabled, calls to DBMS_OUTPUT.PUT_LINE write
lines into the buffer. Nothing is actually displayed until the program executes
completely and control is transfered back to SQL*Plus.
SET SERVEROUTPUT ON causes that SQL*Plus use DBMS_OUTPUT.GET_LINES
to read the buffer and writes it to the terminal. When you set serveroutput
on, DBMS_OUTPUT.ENABLE is implicitly called, with the default size of 2000.
If you want to change the default buffer size you can use:
SET SERVEROUTPUT ON SIZE n
or
DBMS_OUTPUT.ENABLE(n)
(where 'n' is the new buffer size) 

这两个设定之间的差别


Leave a Reply

Your email address will not be published. Required fields are marked *