eygle.com   eygle.com
eygle.com eygle
eygle.com  
 

« 一个命题:列举你认为最重要的9个动态性能视图 | Blog首页 | Find DBA for My friends »

Oracle HowTo:如何强制刷新Buffer Cache
modb.pro

很多时候,为了排除Cache对于测试的影响,我们常常需要手动刷新Buffer Cache,以促使Oracle重新执行物理访问。我曾经在使用 db_file_multiblock_read_count测试Oracle在不同系统中的IO能力一文中用到这个方法,在Itpub上也有朋友到,今天整理一下并作简要说明。

在Oracle9i里,Oracle提供了一个内部事件,用以强制刷新Buffer Cache,其语法为:

alter session set events 'immediate trace name flush_cache level 1';

或者:

alter session set events = 'immediate trace name flush_cache';

类似的也可以使用alter system系统级设置:

alter system set events = 'immediate trace name flush_cache';

在Oracle10g中,Oracle提供一个新的特性,可以通过如下命令刷新Buffer Cache:

alter system flush buffer_cache;

我们通过试验来看一下刷新Cache的作用:


1.创建测试表

SQL> create table t as select * from dba_objects;
Table created.
SQL> analyze table t compute statistics;
Table analyzed.
SQL> select blocks,empty_blocks from dba_tables 
   2 where table_name='T' and owner='SYS';
    BLOCKS EMPTY_BLOCKS
---------- ------------
        78            1

表T共有79个Block.

2. x$bh

SQL> select count(*) from x$bh;
  COUNT(*)
----------
     14375
SQL> select count(*) from x$bh where state=0;  -- state =0 is free
  COUNT(*)
----------
     13960

SQL> alter system set events = 'immediate trace name flush_cache';
System altered.
SQL> select count(*) from x$bh where state=0;
  COUNT(*)
----------
     14375

我们注意到flush_cache以后,所有Buffer都被标记为free.

3. 观察flush_cache对于查询的影响

SQL> set autotrace trace stat
SQL> select count(*) from t;

Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
         81  consistent gets
         79  physical reads
          0  redo size
....
SQL> 
SQL> select count(*) from t;

Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
         81  consistent gets
          0  physical reads
          0  redo size
....
SQL> alter system set events = 'immediate trace name flush_cache';
System altered.
SQL> select count(*) from t;

Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
         81  consistent gets
         79  physical reads
          0  redo size
....
SQL> 

以上说明仅供参考。


历史上的今天...
    >> 2018-12-22文章:
    >> 2011-12-22文章:
    >> 2010-12-22文章:
    >> 2008-12-22文章:
    >> 2007-12-22文章:
    >> 2006-12-22文章:
    >> 2004-12-22文章:

By eygle on 2005-12-22 23:29 | Comments (0) | HowTo | Internal | 593 |


CopyRight © 2004~2020 云和恩墨,成就未来!, All rights reserved.
数据恢复·紧急救援·性能优化 云和恩墨 24x7 热线电话:400-600-8755 业务咨询:010-59007017-7040 or 7037 业务合作: marketing@enmotech.com