一、实验说明:
操作系统:rhel 5.4 x86
数据库:Oracle 11g R2
二、操作步骤:
首先创建一张t_btree表,并建立B-Tree索引,索引键是status:
1 SQL> create table t_btree as select * from dba_objects;2 3 Table created.4 5 SQL> create index status_btree on t_btree(status);6 7 Index created.
执行两次下面的查询语句,并显示执行计划:
1 SQL> set autotrace traceonly; 2 SQL> select count(*) from t_btree where status='VALID'; 3 4 5 Execution Plan 6 ---------------------------------------------------------- 7 Plan hash value: 2400455617 8 9 --------------------------------------------------------------------------------------10 | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |11 --------------------------------------------------------------------------------------12 | 0 | SELECT STATEMENT | | 1 | 5 | 49 (0)| 00:00:01 |13 | 1 | SORT AGGREGATE | | 1 | 5 | | |14 |* 2 | INDEX FAST FULL SCAN| STATUS_BTREE | 74307 | 362K| 49 (0)| 00:00:01 |15 --------------------------------------------------------------------------------------16 17 Predicate Information (identified by operation id):18 ---------------------------------------------------19 20 2 - filter("STATUS"='VALID')21 22 Note23 -----24 - dynamic sampling used for this statement (level=2)25 26 27 Statistics28 ----------------------------------------------------------29 32 recursive calls30 0 db block gets31 261 consistent gets32 458 physical reads33 0 redo size34 424 bytes sent via SQL*Net to client35 419 bytes received via SQL*Net from client36 2 SQL*Net roundtrips to/from client37 0 sorts (memory)38 0 sorts (disk)39 1 rows processed40 41 SQL> select count(*) from t_btree where status='VALID';42 43 44 Execution Plan45 ----------------------------------------------------------46 Plan hash value: 240045561747 48 --------------------------------------------------------------------------------------49 | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |50 --------------------------------------------------------------------------------------51 | 0 | SELECT STATEMENT | | 1 | 5 | 49 (0)| 00:00:01 |52 | 1 | SORT AGGREGATE | | 1 | 5 | | |53 |* 2 | INDEX FAST FULL SCAN| STATUS_BTREE | 74307 | 362K| 49 (0)| 00:00:01 |54 --------------------------------------------------------------------------------------55 56 Predicate Information (identified by operation id):57 ---------------------------------------------------58 59 2 - filter("STATUS"='VALID')60 61 Note62 -----63 - dynamic sampling used for this statement (level=2)64 65 66 Statistics67 ----------------------------------------------------------68 0 recursive calls69 0 db block gets70 180 consistent gets71 0 physical reads72 0 redo size73 424 bytes sent via SQL*Net to client74 419 bytes received via SQL*Net from client75 2 SQL*Net roundtrips to/from client76 0 sorts (memory)77 0 sorts (disk)78 1 rows processed
接着创建跟t_btree一样的表t_bmap,并创建BitMap索引。
1 SQL> create table t_bmap as select * from dba_objects;2 3 Table created.4 5 SQL> create bitmap index status_bmap on t_bmap(status);6 7 Index created.
同样执行之前的语句两次:
1 SQL> select count(*) from t_bmap where status='VALID'; 2 3 4 Execution Plan 5 ---------------------------------------------------------- 6 Plan hash value: 516980546 7 8 --------------------------------------------------------------------------------------------- 9 | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |10 ---------------------------------------------------------------------------------------------11 | 0 | SELECT STATEMENT | | 1 | 5 | 3 (0)| 00:00:01 |12 | 1 | SORT AGGREGATE | | 1 | 5 | | |13 | 2 | BITMAP CONVERSION COUNT | | 62928 | 307K| 3 (0)| 00:00:01 |14 |* 3 | BITMAP INDEX FAST FULL SCAN| STATUS_BMAP | | | | |15 ---------------------------------------------------------------------------------------------16 17 Predicate Information (identified by operation id):18 ---------------------------------------------------19 20 3 - filter("STATUS"='VALID')21 22 Note23 -----24 - dynamic sampling used for this statement (level=2)25 26 27 Statistics28 ----------------------------------------------------------29 32 recursive calls30 0 db block gets31 72 consistent gets32 266 physical reads33 0 redo size34 424 bytes sent via SQL*Net to client35 419 bytes received via SQL*Net from client36 2 SQL*Net roundtrips to/from client37 0 sorts (memory)38 0 sorts (disk)39 1 rows processed40 41 SQL> select count(*) from t_bmap where status='VALID';42 43 44 Execution Plan45 ----------------------------------------------------------46 Plan hash value: 51698054647 48 ---------------------------------------------------------------------------------------------49 | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |50 ---------------------------------------------------------------------------------------------51 | 0 | SELECT STATEMENT | | 1 | 5 | 3 (0)| 00:00:01 |52 | 1 | SORT AGGREGATE | | 1 | 5 | | |53 | 2 | BITMAP CONVERSION COUNT | | 62928 | 307K| 3 (0)| 00:00:01 |54 |* 3 | BITMAP INDEX FAST FULL SCAN| STATUS_BMAP | | | | |55 ---------------------------------------------------------------------------------------------56 57 Predicate Information (identified by operation id):58 ---------------------------------------------------59 60 3 - filter("STATUS"='VALID')61 62 Note63 -----64 - dynamic sampling used for this statement (level=2)65 66 67 Statistics68 ----------------------------------------------------------69 0 recursive calls70 0 db block gets71 6 consistent gets72 0 physical reads73 0 redo size74 424 bytes sent via SQL*Net to client75 419 bytes received via SQL*Net from client76 2 SQL*Net roundtrips to/from client77 0 sorts (memory)78 0 sorts (disk)79 1 rows processed
从上面的查询中,我们可以得到,分别给两张内容一样的表做查询的时候,在执行第二次的时候是属于软解析:
从一致性读上比较,B-Tree索引的consistent gets是180,BitMap的是6;
从Cost的消耗上看,B-Tree索引的COST是49,而BitMap的是3。
在索引键是高重复率键值(status)的时候情况下BitMap索引的效率要优于B-Tree索引。