Oracle DB_FILE_MULTIBLOCK_READ_COUNT是Oracle比较重要的一个全局性参数,可以影响系统级别及sessioin级别。主要是用于设置最小化表扫描时Oracle一次按顺序能够读取的数据块数。通常情况下,我们看到top events中的等待事件db file scattered read时会考虑到增加该参数的值。但是否增加了DB_FILE_MULTIBLOCK_READ_COUNT的值就一定可以减少db file scattered read? 本文描述了DB_FILE_MULTIBLOCK_READ_COUNT的设置并给出演示。
1、参数DB_FILE_MULTIBLOCK_READ_COUNT(MBRC)
参数DB_FILE_MULTIBLOCK_READ_COUNT简写为(MBRC)。
该参数是最小化表扫描的重要参数,用于指定Oracle一次按顺序能够读取的数据块数。理论上该值越大则能够读取的数据块越多。
实现全表扫描,索引全扫描及索引快速扫描所需的I/O总数取决于该参数,以及表自身的大小,是否使用并行等等。
Oracle 10gR2以后会根据相应的操作系统及buffer cache以最优化的方式来自动设定该参数的值。通常情况下该值为1MB/db_block_size。
在最大I/O为1MB的情况下,block的大小为8KB,则参数的值为128。如果在最大I/O为64KB,block为8KB,则参数的值为8。
对于OLTP和batch环境该参数的值为4到16,DSS环境应设置大于16以上或大的值。
该参数的变化对数据库性能产生整体性的影响,过大的设置会导致大量SQL访问路径发生变化,如原先的索引扫描倾向于使用全表扫描。
按照Oracle的建议在10g R2之后尽可能使用oracle自动设置的值。
2、参数DB_FILE_MULTIBLOCK_READ_COUNT与SSTIOMAX
In Release 9.2 and above; follow the explanation below:
Each version of Oracle on each port, is shipped with a preset maximum of how much data can be transferred in a single read (which of course is equivalent to the db_file_multiblock_read_count since the block size is fixed).
For 8i and above (on most platforms) this is 1Mb and is referred to as SSTIOMAX.
To determine it for your port and Oracle version, simply set db_file_multiblock_read_count to a nonsensical value and Oracle will size it down for you.
从上面的描述可知,Oracle 9.2之后,有一个名叫SSTIOMAX的东东,限制了MBRC的设置。
由于SSTIOMAX大多数平台最大单次I/O为1MB,db_block_size为8kb,因此MBRC参数的最大值通常为128。128*8kb=1mb。
对于设置大于1MB的情形,即MBRC*db_block_size>SSTIOMAX的情形,则设置的值并不生效,而是使用符合SSTIOMAX的最大MBRC值。
3、如何计算MBRC
The formula as internally used is as below:
db_file_multiblock_read_count = min(1048576/db_block_size , db_cache_size/(sessions * db_block_size))
Without WORKLOAD stats, CBO computes multiblock reads as:
io_cost = blocks/(1.6765 * power(db_file_multiblock_read_count,0.6581))
With WORKLOAD stats, then:
io_cost = blocks/mbrc * mreadtim/sreadtim
下面是不同情形设置所致的最大i/o
db_blocks_size tablespace block size db_file_multiblock_read_count max_fetch_blocks_in_single_read
--------------- ---------------------- ----------------------------- -------------------------------
8k 8k 32 8*32=256kb(i/o)
8k 4k 32 8*32/4=64kb(i/o)
8k 8k not explicitly set determined by OS and db_cache_size
8k 8k >128 8*128=1MB(i/o)
4、哪些情形导致单次多块读少于预设置
a、读段头时单块读(此情形显而易见,通常一个extent包含一个段头header)
b、物理读不能跨越多个区(extent)
c、部分数据块已经位于高速缓存则不会从I/O子系统再次读取,除非是直接读(direct path read)。
5、演示不同值的MBRC单次读的block(system级别)
a、MBRC为16的情形 --演示环境 sys@SYBO2SZ> ho cat /etc/issue Welcome to SUSE Linux Enterprise Server 10 SP3 (x86_64) - Kernel \r (\l). sys@SYBO2SZ> select * from v$version where rownum=1; BANNER ---------------------------------------------------------------- Oracle Database 10g Release 10.2.0.3.0 - 64bit Production --Author: Robinson --Blog : http://blog.csdn.net/robinson_0612 --查看MBRC的值 sys@SYBO2SZ> show parameter read_count; NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ db_file_multiblock_read_count integer 16 --查看和read_count相关的隐藏参数 sys@SYBO2SZ> @hidden_para Enter value for para: read_count KSPPINM KSPPSTVL DESCRIB ----------------------------------- -------------------- --------------------------------------------- _db_file_exec_read_count 48 multiblock read count for regular clients _db_file_optimizer_read_count 8 multiblock read count for regular clients _db_file_noncontig_mblock_read_count 11 number of noncontiguous db blocks to be prefetched _sort_multiblock_read_count 2 multi-block read count for sort sys@SYBO2SZ> get trace_enable_cur.sql 1* alter session set events '10046 trace name context forever,level 8'; sys@ORA11G> @trace_enable_cur Session altered. sys@SYBO2SZ> select count(*) from scott.big_table where owner='SYS'; COUNT(*) ---------- 468066 sys@SYBO2SZ> get trace_disable_cur.sql 1* alter session set events '10046 trace name context off'; sys@SYBO2SZ> @trace_disable_cur.sql Session altered. sys@SYBO2SZ> @my_env SPID SID SERIAL# USERNAME PROGRAM ------------ ---------- ---------- --------------- ------------------------------------------------ 24472 1094 30 robin oracle@SZDB (TNS V1-V3) sys@SYBO2SZ> @get_spec_sess_trace_file Enter value for input_sid: 1094 Enter value for input_serial: 30 SID SERIAL# SPID TRACE_FILE ---------- ---------- ------------ ---------------------------------------------------------- 1094 30 24472 /u02/database/SYBO2SZ/udump/sybo2sz_ora_24472.trc --下面的blocks即为单次读取时的块数 sys@SYBO2SZ> ho grep scatter /u02/database/SYBO2SZ/udump/sybo2sz_ora_24472.trc |tail WAIT #7: nam='db file scattered read' ela= 1491 file#=5 block#=18363 blocks=16 obj#=52884 tim=1337624821997106 WAIT #7: nam='db file scattered read' ela= 5148 file#=5 block#=18443 blocks=2 obj#=52884 tim=1337624822005413 WAIT #7: nam='db file scattered read' ela= 32363 file#=5 block#=18571 blocks=16 obj#=52884 tim=1337624822041788 WAIT #7: nam='db file scattered read' ela= 1930 file#=5 block#=18587 blocks=16 obj#=52884 tim=1337624822044227 WAIT #7: nam='db file scattered read' ela= 345 file#=5 block#=18603 blocks=16 obj#=52884 tim=1337624822045165 WAIT #7: nam='db file scattered read' ela= 1712 file#=5 block#=18619 blocks=16 obj#=52884 tim=1337624822047555 WAIT #7: nam='db file scattered read' ela= 58 file#=5 block#=18635 blocks=2 obj#=52884 tim=1337624822048219 b、MBRC大于128的情形 sys@SYBO2SZ> alter system set db_file_multiblock_read_count=256; System altered. sys@SYBO2SZ> show parameter read_count; --->从这个查询可知,大于128的情形并没有生效 NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ db_file_multiblock_read_count integer 128 --对于MBRC为128的情形演示步骤同上,下面仅仅列出最终结果 --注意在使用不同的MBRC在系统级别测试前应将buffer cache清空(alter system flush buffer_cache) sys@SYBO2SZ> ho grep scatter /u02/database/SYBO2SZ/udump/sybo2sz_ora_24750.trc |tail WAIT #7: nam='db file scattered read' ela= 2070 file#=5 block#=20875 blocks=126 obj#=53208 tim=1337625626875769 WAIT #7: nam='db file scattered read' ela= 1991 file#=5 block#=21003 blocks=126 obj#=53208 tim=1337625626880199 WAIT #7: nam='db file scattered read' ela= 1970 file#=5 block#=21131 blocks=126 obj#=53208 tim=1337625626884412 WAIT #7: nam='db file scattered read' ela= 2078 file#=5 block#=21259 blocks=126 obj#=53208 tim=1337625626888846 WAIT #7: nam='db file scattered read' ela= 2035 file#=5 block#=21387 blocks=126 obj#=53208 tim=1337625626893039 WAIT #7: nam='db file scattered read' ela= 2040 file#=5 block#=21515 blocks=126 obj#=53208 tim=1337625626897021 WAIT #7: nam='db file scattered read' ela= 1048 file#=5 block#=21643 blocks=66 obj#=53208 tim=1337625626900379 c、MBRC为缺省值的情形 sys@SYBO2SZ> alter system reset db_file_multiblock_read_count scope=spfile sid='*'; System altered. sys@SYBO2SZ> show parameter read_count; NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ db_file_multiblock_read_count integer 128 sys@SYBO2SZ> startup force; --->reset mbrc后需要重新启动db sys@SYBO2SZ> show parameter read_count NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ db_file_multiblock_read_count integer 44 sys@SYBO2SZ> ho grep scatter /u02/database/SYBO2SZ/udump/sybo2sz_ora_24890.trc | tail WAIT #14: nam='db file scattered read' ela= 682 file#=5 block#=21431 blocks=44 obj#=53208 tim=1337626216154292 WAIT #14: nam='db file scattered read' ela= 4497 file#=5 block#=21475 blocks=38 obj#=53208 tim=1337626216163586 WAIT #14: nam='db file scattered read' ela= 586 file#=5 block#=21515 blocks=44 obj#=53208 tim=1337626216166611 WAIT #14: nam='db file scattered read' ela= 691 file#=5 block#=21559 blocks=44 obj#=53208 tim=1337626216170137 WAIT #14: nam='db file scattered read' ela= 4860 file#=5 block#=21603 blocks=38 obj#=53208 tim=1337626216177698 WAIT #14: nam='db file scattered read' ela= 592 file#=5 block#=21643 blocks=44 obj#=53208 tim=1337626216180540 WAIT #14: nam='db file scattered read' ela= 292 file#=5 block#=21687 blocks=22 obj#=53208 tim=1337626216183493
6、演示不同MBRC所耗用的时间(session级别)
--下面的PL/SQL代码用于测试不同的MBRC时所读的块数以及耗用的时间 scott@SYBO2SZ> get assess_mbrc.sql 1 DECLARE 2 l_count PLS_INTEGER; 3 l_time NUMBER(10,1); 4 l_starting_time PLS_INTEGER; 5 l_ending_time PLS_INTEGER; 6 l_blocks PLS_INTEGER; 7 l_starting_blocks PLS_INTEGER; 8 l_ending_blocks PLS_INTEGER; 9 l_dbfmbrc PLS_INTEGER; 10 BEGIN 11 dbms_output.put_line('dbfmbrc blocks seconds'); 12 dbms_output.put_line('------- ------ -------'); 13 FOR i IN 1..32 14 LOOP 15 l_dbfmbrc := i * 4; 16 EXECUTE IMMEDIATE 'ALTER SESSION SET db_file_multiblock_read_count = '||l_dbfmbrc; 17 EXECUTE IMMEDIATE 'ALTER SYSTEM SET EVENTS ''IMMEDIATE TRACE NAME FLUSH_CACHE'''; 18 SELECT value INTO l_starting_blocks 19 FROM v$mystat ms JOIN v$statname USING (statistic#) 20 WHERE name = 'physical reads'; 21 l_starting_time := dbms_utility.get_time(); 22 SELECT count(*) INTO l_count FROM big_table; 23 l_ending_time := dbms_utility.get_time(); 24 SELECT value INTO l_ending_blocks 25 FROM v$mystat ms JOIN v$statname USING (statistic#) 26 WHERE name = 'physical reads'; 27 l_time := l_ending_time-l_starting_time; 28 l_blocks := l_ending_blocks-l_starting_blocks; 29 dbms_output.put_line(l_dbfmbrc||' '||l_blocks||' '||to_char(l_time)||'hsec'); 30 END LOOP; 31* END; 32 / dbfmbrc blocks seconds ------- ------ ------- 4 2119 18hsec 8 2093 15hsec 12 2093 7hsec 16 2093 8hsec 20 2093 9hsec 24 2093 8hsec 28 2093 9hsec 32 2093 8hsec 36 2093 8hsec 40 2093 8hsec 44 2093 9hsec 48 2093 9hsec 52 2093 9hsec 56 2093 8hsec 60 2093 9hsec 64 2093 8hsec 68 2093 9hsec 72 2093 8hsec 76 2093 9hsec 80 2093 9hsec 84 2093 9hsec 88 2093 8hsec 92 2093 9hsec 96 2093 9hsec 100 2093 9hsec 104 2093 8hsec 108 2093 9hsec 112 2093 8hsec 116 2093 9hsec 120 2093 8hsec 124 2093 9hsec 128 2093 9hsec PL/SQL procedure successfully completed. --从上面的结果可以看出,当设置MBRC为16时,所读取的块数以及所耗用的时间基本上不再受到MBRC的影响。 --由此可知,单纯增加MBRC的值也不能够彻底地解决db file scattered read。 --到底如何设置多少,还是按照Oracle的建议保留缺省值。再在缺省值的基础之上作相应调整。 --Reference:[841444.1] [473740.1] [1398860.1] [291239.1]
更多参考
PL/SQL 联合数组与嵌套表
PL/SQL 变长数组
PL/SQL --> PL/SQL记录