一. 参数说明
一般来说,我们建库时指定的db_block_size 都是使用默认的8k。 从这种角度来说,数据库的block size 都是一样的。 但Oracle 是可以配置Multiple Block Sizes的。
SYS@anqing1(rac1)> show parameter cache_size
NAME TYPE VALUE
———————————— —————————————–
db_16k_cache_size big integer 0
db_2k_cache_size big integer 0
db_32k_cache_size big integer 0
db_4k_cache_size big integer 0
db_8k_cache_size big integer 0
db_cache_size big integer 0
db_keep_cache_size big integer 0
db_recycle_cache_sizebig integer 0
SYS@anqing1(rac1)> show parameter db_block_size
NAMETYPE VALUE
———————————————– ——————————
db_block_size integer 8192
如果要配置Multiple Block Sizes,就需要配置db_nK_cache_size 参数,这些参数默认都是0. 配置完这些参数之后,我们在创建相关的表空间时,就可以指定对应的block。 这样就完成了Multiple Block Sizes。 但是,Multiple Block Sizes 给管理上代理一定的复杂度,所以实际使用的不多。
注意一点:
在创建非db_block_size 标准的表空间时,必须先执行对应的DB_nK_CACHE_SIZE 参数,来创建nK 的buffer,不然会报:
ORA-29339: tablespace block size 4096 does not matchconfigured block sizes
1.1 DB_BLOCK_SIZE
Property
Description
Parameter type
Integer
Default value
8192
Modifiable
No
Range of values
2048(2k) to 32768(32k), but your operating system may have a narrower range
Basic
Yes
Oracle RAC
You must set this parameter for every instance, and multiple instances must have the same value.
Caution:
Set this parameter at the time of database creation. Do notalter it afterward.
DB_BLOCK_SIZEspecifies (in bytes) the size of Oracle database blocks. Typical values are4096 and 8192. The value of this parameter must be a multiple of the physicalblock size at the device level.
Thevalue for DB_BLOCK_SIZE in effect at the time you create the databasedetermines the size of the blocks. The value must remain set to its initialvalue.
ForReal Application Clusters, this parameter affects the maximum value of theFREELISTS storage parameter for tables and indexes. Oracle uses one databaseblock for each freelist group. Decision support system (DSS) and data warehousedatabase environments tend to benefit from larger block size values.
Note:
(1)32-bit operating systems support a maximum DB_BLOCK_SIZE value of16384(16k)–32位系统,db_block_size最大16k
(2)64-bit operating systems support a maximum DB_BLOCK_SIZE value of32768(32k)–64位系统,db_block_size最大32k
1.2 DB_nK_CACHE_SIZE参数
官网的说明如下:
From: #REFRN10027
Property
Description
Parameter type
Big integer
Syntax
DB_[2 | 4 | 8 | 16 | 32]K_CACHE_SIZE = integer [K | M | G]
Default value
0 (additional block size caches are not configured by default)
Modifiable
ALTER SYSTEM
Range of values
Minimum: 0 (values greater than zero are automatically modified to be either the granule size * number of processor groups, or 4 MB * number of CPUs, whichever is greater)
Maximum: operating system-dependent
Basic
No
DB_nK_CACHE_SIZE (where n = 2, 4, 8, 16, 32) specifies thesize of the cache for the nK buffers. You can set this parameter onlywhen DB_BLOCK_SIZE has a value other than nK. For example, ifDB_BLOCK_SIZE=4096, then it is illegal to specify the parameterDB_4K_CACHE_SIZE (because the size for the 4 KB block cache is alreadyspecified by DB_CACHE_SIZE).
— DB_nK_CACHE_SIZE 参数指定nK 的buffer,在指定cache时,要确保有足够的空间。 不能和DB_BLOCK_SIZE参数冲突,n 可以取2,4,8,16,32.
Donot set this parameter to zero if there are any online tablespaces with an nKblock size.
Operating system-specific block size restrictions apply.For example, you cannot set DB_32K_CACHE_SIZE if the operating system’s maximumblock size is less than 32 KB. Also, you cannot set DB_2K_CACHE_SIZE if theminimum block size is greater than 2 KB.
— DB_nK_CACHE_SIZE要操作系统支持,如果n=32,但操作系统支持,也是不行的。
See Also:
Youroperating system-specific Oracle documentation for more information on blocksize restrictions
二. 测试
–查看db_block_size
SYS@anqing2(rac2)> show parameterdb_block_size
NAME TYPE VALUE
———————————— —————————————–
db_block_size integer 8192
–查看操作系统位数
[root@rac2 ~]# cat /proc/cpuinfo | grepflags | grep ‘lm’ | wc -l
1
结果大于0, 说明支持64bit计算. lm指long mode, 支持lm则是64bit。
有关CPU的更多信息参考:
Linux CPU 信息查看
–查看db_32k_cache_size值
SYS@anqing2(rac2)> show parameterdb_32k_cache_size
NAME TYPE VALUE
———————————————– ——————————
db_32k_cache_size big integer 0
— 指定32k 时,报错,提示系统不支持,看来只能用16k了
SYS@anqing1(rac1)> alter system setdb_32k_cache_size=1M scope=both sid=’anqing1′;
alter system set db_32k_cache_size=1Mscope=both sid=’anqing1′
*
ERROR at line 1:
ORA-32017: failure in updating SPFILE
ORA-00382: 32768 not a valid block size,valid range [..]
–指定16k 的cachebuffer
SYS@anqing1(rac1)> alter system set db_16k_cache_size=1M scope=bothsid=’anqing1′;
System altered.
SYS@anqing2(rac2)> alter system set db_16k_cache_size=1M scope=bothsid=’anqing2′;
System altered.
— 因为我的测试环境是RAC,所以在2个节点上都指定了参数
–查看cache,虽然指定了1M,,但系统使用了默认的最小值
SYS@anqing1(rac1)> show parameter db_16k_cache_size
NAME TYPE VALUE
———————————————– ——————————
db_16k_cache_size big integer 4M
SYS@anqing2(rac2)> show parameter db_16k_cache_size
NAME TYPE VALUE
———————————————– ——————————
db_16k_cache_size big integer 4M
— 这个最小的默认值,上面的官网说明有解释:
–values greater thanzero are automatically modified to be either the granule size * number ofprocessor groups, or 4 MB * number of CPUs, whichever is greater
–指定了16kcache,我们就可以创建block 为16k的表空间了
SYS@anqing1(rac1)> CREATE TABLESPACETest DATAFILE
2 ‘+DATA/anqing/datafile/test01.dbf’ SIZE 50M AUTOEXTEND ON NEXT 10MMAXSIZE 100M BLOCKSIZE 16K;
Tablespace created.
— 注意这里指定了Blocksize为16k,和我们之前创建的Cache 大小相对应。
–为了验证不指定cache报的错误,我们创建一个4k的tablespace
SYS@anqing1(rac1)> CREATE TABLESPACE TTDATAFILE ‘+DATA/anqing/datafile/TT01.dbf’ SIZE 50M AUTOEXTEND ON NEXT 10MMAXSIZE 100M BLOCKSIZE 4K;
CREATE TABLESPACE TT DATAFILE’+DATA/anqing/datafile/TT01.dbf’ SIZE 50M AUTOEXTEND ON NEXT 10M MAXSIZE 100MBLOCKSIZE 4K
*
ERROR at line 1:
ORA-29339: tablespaceblock size 4096 does not match configured block sizes
— 这里提示了我们:ORA-29339的错误,所以在创建Multiple Block Sizes 之前,必须指定对应的Cache buffer。
–创建一个测试表,放到16k的test 表空间
SYS@anqing1(rac1)> create table tt16k tablespace test as select * from dba_objects;
Table created.
–验证一下表tt16k的block 大小
SYS@anqing1(rac1)> selectsegment_name,blocks from dba_segments where segment_name=’TT16K’;
SEGMENT_NAME BLOCKS
————— ———-
TT16K 384
–当表的每个block越大时,那么它里面就能够存放更多的block
–我们使用8k的block 来创建一个相同的表,来查看它使用blocks,从而进行对比
SYS@anqing1(rac1)> create table tt8k as select * from dba_objects;
Table created.
SYS@anqing1(rac1)> select segment_name,blocks from dba_segments wheresegment_name=’TT8K’;
SEGMENT_NAME BLOCKS
————— ———-
TT8K 768
–看到,使用16k是384个blocks,使用8k是768个blocks。
— 将tt8kmove 到 test(16k)
SYS@anqing1(rac1)> alter table tt8k move tablespace test;
Table altered.
SYS@anqing1(rac1)>select segment_name,blocks from dba_segments wheresegment_name=’TT8K’;
SEGMENT_NAME BLOCKS
————— ———-
TT8K 384
使用的Blocks 就下降下来了。