oracle实用sql(7)--单个会话或会话间statistics对比


点击(此处)折叠或打开

  1. --初始化建表
  2. declare
  3.   v_count number;
  4. begin
  5.   select count(1) into v_count from dba_tables where owner='SCOTT' and table_name='T_STAT_TEMP';
  6.   if v_count=1 then
  7.     execute immediate 'truncate table scott.t_stat_temp';
  8.   else
  9.     execute immediate 'create table scott.t_stat_temp(snap_id integer,name varchar2(100),value int)';
  10.   end if;
  11. end;


  12. --Run1执行前收集
  13. --可从v$mystat中得到当前会话id,或从v$session中得到某会话id
  14. insert into scott.t_stat_temp
  15. select 1,a.name,b.value
  16. from v$statname a,v$sesstat b
  17. where a.statistic#=b.statistic# and b.sid=46
  18. and a.name in ('table scans (long tables)','bytes received via SQL*Net from client',
  19. 'bytes received via SQL*Net from dblink','consistent changes','consistent gets',
  20. 'CPU used by this session','physical reads','physical writes','session pga memory','session pga memory max',
  21. 'session uga memory','session logical reads','session uga memory max','sorts (disk)','sorts (memory)','table fetch continued row',
  22. 'opened cursors cumulative','opened cursors current','DDL statements parallelized','DML statements parallelized','queries parallelized',
  23. 'buffer is not pinned count','parse time cpu','redo blocks written','redo buffer allocation retries','redo entries',
  24. 'redo log space requests','redo size','redo synch time','redo synch writes','redo wastage','redo write time',
  25. 'redo writer latching time','redo writes');
  26. commit;

  27. /*执行语句或等待某会话运行*/

  28. --Run1执行后收集
  29. insert into scott.t_stat_temp
  30. select 2,a.name,b.value
  31. from v$statname a,v$sesstat b
  32. where a.statistic#=b.statistic# and b.sid=46
  33. and a.name in ('table scans (long tables)','bytes received via SQL*Net from client',
  34. 'bytes received via SQL*Net from dblink','consistent changes','consistent gets',
  35. 'CPU used by this session','physical reads','physical writes','session pga memory','session pga memory max',
  36. 'session uga memory','session logical reads','session uga memory max','sorts (disk)','sorts (memory)','table fetch continued row',
  37. 'opened cursors cumulative','opened cursors current','DDL statements parallelized','DML statements parallelized','queries parallelized',
  38. 'buffer is not pinned count','parse time cpu','redo blocks written','redo buffer allocation retries','redo entries',
  39. 'redo log space requests','redo size','redo synch time','redo synch writes','redo wastage','redo write time',
  40. 'redo writer latching time','redo writes');
  41. commit;

  42. --查看Run1的statistics
  43. select a.name,a.value begin_value,b.value end_value,b.value-a.value diff
  44. from scott.t_stat_temp a, scott.t_stat_temp b
  45. where a.name=b.name and a.snap_id=1 and b.snap_id=2
  46. order by 1 ;



  47. --若要对比Run2,继续
  48. --Run2执行前收集
  49. --可从v$mystat中得到当前会话id,或从v$session中得到某会话id
  50. insert into scott.t_stat_temp
  51. select 3,a.name,b.value
  52. from v$statname a,v$sesstat b
  53. where a.statistic#=b.statistic# and b.sid=46
  54. and a.name in ('table scans (long tables)','bytes received via SQL*Net from client',
  55. 'bytes received via SQL*Net from dblink','consistent changes','consistent gets',
  56. 'CPU used by this session','physical reads','physical writes','session pga memory','session pga memory max',
  57. 'session uga memory','session logical reads','session uga memory max','sorts (disk)','sorts (memory)','table fetch continued row',
  58. 'opened cursors cumulative','opened cursors current','DDL statements parallelized','DML statements parallelized','queries parallelized',
  59. 'buffer is not pinned count','parse time cpu','redo blocks written','redo buffer allocation retries','redo entries',
  60. 'redo log space requests','redo size','redo synch time','redo synch writes','redo wastage','redo write time',
  61. 'redo writer latching time','redo writes');
  62. commit;
  63. /*执行语句或等待某会话运行*/



  64. --Run2执行后收集
  65. insert into scott.t_stat_temp
  66. select 4,a.name,b.value
  67. from v$statname a,v$sesstat b
  68. where a.statistic#=b.statistic# and b.sid=46
  69. and a.name in ('table scans (long tables)','bytes received via SQL*Net from client',
  70. 'bytes received via SQL*Net from dblink','consistent changes','consistent gets',
  71. 'CPU used by this session','physical reads','physical writes','session pga memory','session pga memory max',
  72. 'session uga memory','session logical reads','session uga memory max','sorts (disk)','sorts (memory)','table fetch continued row',
  73. 'opened cursors cumulative','opened cursors current','DDL statements parallelized','DML statements parallelized','queries parallelized',
  74. 'buffer is not pinned count','parse time cpu','redo blocks written','redo buffer allocation retries','redo entries',
  75. 'redo log space requests','redo size','redo synch time','redo synch writes','redo wastage','redo write time',
  76. 'redo writer latching time','redo writes');
  77. commit;

  78. --查看Run2的statistics
  79. select a.name,a.value begin_value,b.value end_value,b.value-a.value diff
  80. from scott.t_stat_temp a, scott.t_stat_temp b
  81. where a.name=b.name and a.snap_id=3 and b.snap_id=4
  82. order by 1 ;

  83. --Run1,Run2 statistics对比
  84. select c.name,c.begin_value run1_begin_value,c.end_value run2_end_value,
  85. d.begin_value run2_begin_value,d.end_value run2_end_value,
  86. c.end_value-c.begin_value run1_diff,d.end_value-d.begin_value run2_diff,
  87. (d.end_value-d.begin_value)-(c.end_value-c.begin_value) run1_run2_diff
  88. from ( select a.name,a.value begin_value,b.value end_value,b.value-a.value diff
  89. from scott.t_stat_temp a, scott.t_stat_temp b
  90. where a.name=b.name and a.snap_id=1 and b.snap_id=2) c,
  91. ( select a.name,a.value begin_value,b.value end_value,b.value-a.value diff
  92. from scott.t_stat_temp a, scott.t_stat_temp b
  93. where a.name=b.name and a.snap_id=3 and b.snap_id=4) d
  94. where c.name=d.name
  95. order by 1;

请使用浏览器的分享功能分享到微信等