Oracle 如何强制刷新Buffer Cache


在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';

在Oracle 10g中,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(*)
----------
    14375SQL> select count(*) from x$bh where state=0;  -- state =0 is free  COUNT(*)
----------
    13960SQL> 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> 


以上说明仅供参考。

相关内容