« ORA-600 2252 错误与SCN的一致性 | Blog首页 | Oracle SQLID 与 Hash_value 算法及转换 »
Oracle 11g全表扫描以Direct Path Read方式执行
链接:https://www.eygle.com/archives/2012/05/oracle_11g_direct_path_read.html
在Oracle Database 11g中有一个新特性,全表扫描可以通过直接路径读的方式来执行(Direct Path Read),这是一个合理的变化,如果全表扫描的大量数据读取是偶发性的,则直接路径读可以避免大量数据对于Buffer Cache的冲击。
当然对于小表来说,Oracle允许通过Buffer Cache来进行全表扫描,因为这可能更快,也对性能影响不大。
小表受到隐含参数:_small_table_threshold 影响。如果表大于 5 倍的小表限制,则自动会使用DPR替代FTS。
可以设置初始化参数: _serial_direct_read 来禁用串行直接路径读。
当然,Oracle通过一个内部的限制,来决定执行DPR的阈值。
可以通过设置10949事件屏蔽这个特性,返回到Oracle 11g之前的模式上:alter
session
set
events
'10949 trace name context forever, level 1'
;
还有一个参数 _very_large_object_threshold 用于设定(MB单位)使用DPR方式的上限,这个参数需要结合10949事件共同发挥作用。
10949 事件设置任何一个级别都将禁用DPR的方式执行FTS,但是仅限于小于 5 倍 BUFFER Cache的数据表,同时,如果一个表的大小大于 0.8 倍的 _very_large_object_threshold 设置,也会执行DPR。
这些限定的目标在于:
对于大表的全表扫描,必须通过Direct Path Read方式执行,以减少对于Buffer Cache的冲击和性能影响。
但是我们可以通过参数调整来决定执行DPR的上限和下限。
Event 10949 可以在线设置,但对现有session可能不会生效,新登录的会话会执行新的设置:
在实例级别修改参数设置:
- ALTER SYSTEM SET EVENTS '10949 TRACE NAME CONTEXT FOREVER';
增加参数到SPFILE中:
- alter system set event='10949 TRACE NAME CONTEXT FOREVER' scope=spfile;
对当前会话设置:
- ALTER SESSION SET EVENTS '10949 TRACE NAME CONTEXT FOREVER';
隐含参数"_serial_direct_read" 可以达到类似的限制,其默认值为AUTO,设置为NEVER时禁用 11g 的自动direct path read的特性。该参数可以动态在实例或会话级别修改,而无需重启实例。
- SQL> alter system set "_serial_direct_read"=auto;
- SQL> alter system set "_serial_direct_read"=never;
引用以下链接的一点英文描述供参考:
http://sai-oracle.blogspot.com/2010/06/full-table-scan-behavior-in-11g.html
Before 11gr2, full table scan access path read all the blocks of a table (or index fast full scan) under high water mark into the buffer cache unless either "_serial_direct_read" hidden parameter is set to true or the table/index have default parallelism set.此外,以下链接可以提供参考:
In 11gR2, Oracle will automatically decide whether to use direct path reads bypassing buffer cache for serial full table scans.
For using direct path reads, Oracle first has to write any dirty blocks of the table to disk by issuing object level checkpoint and then read all the blocks from disk into the PGA of server process. If it has to undo any uncommitted transactions to provide read consistency or to do delayed block clean out, Oracle will use server process PGA to construct read consistent block buffers.
If block clean out has to be performed by the server process using direct path reads for full table scans, it won't write those modified blocks back to disk, so every time you perform full table scan using direct path reads it'd have to keep doing the same work of cleaning out the blocks for every execution. For this reason, it is recommended to manually clean out those blocks by performing full table scan without using direct path reads.
Following behavior was observed with my testing on 11.2.0.1:
Hidden parameter "_small_table_threshold" defines the number of blocks to consider a table as small. Any table having more blocks (about 5 times the value of "_small_table_threshold" if you leave it at default value) will automatically use direct path reads for serial full table scans (FTS).
Hidden parameter "_very_large_object_threshold" defines the upper limit of object size in MB for using direct path reads. There is no effect on FTS behavior just by setting this parameter alone.
Event 10949 set to any level will disable direct path reads for serial scans only if the size of an object is less then 5 times the size of buffer cache.
Combination of event 10949 and "_very_large_object_threshold" parameter will disable direct path reads for serial scans if the size of an object is less than 5 times the size of buffer cache or the value of "_very_large_object_threshold" is less than about 0.8 times the size of an object.
So, if you want to disable direct path reads for serial scans for any object, then set event 10949 at any level and set "_very_large_object_threshold" to greater than the size of largest object in MB.
Hidden parameter "_serial_direct_read" (or event 10355 set at any level) set to TRUE will enable direct path reads for all serial scans, unless the table is considered as small table and it's caching attribute is set (by issuing alter table xxxx cache). Remember that any sql statement already parsed and not using direct path reads will continue to do so unless hard parse is forced after setting these parameters. For this reason, it is better not to set these parameters.
It is not recommended to set any of the above mentioned hidden parameters if you want direct path reads to be used for serial scans, let Oracle decide dynamically based on the size of an object.
http://www.dbthink.com/?p=17
http://dioncho.wordpress.com/2009/07/21/disabling-direct-path-read-for-the-serial-full-table-scan-11g/
历史上的今天...
>> 2009-05-24文章:
>> 2007-05-24文章:
>> 2006-05-24文章:
By eygle on 2012-05-24 08:55 | Comments (0) | Oracle12c/11g | 3011 |