hint指定index的深入理解
模拟环境
创建一个表,含有位图index和b-tree index
SQL> create table t_xifenfei as 2 select object_id,object_name from dba_objects; Table created. SQL> create index b_tree_t_xifenfei on t_xifenfei(object_id); Index created. SQL> CREATE BITMAP INDEX bitmap_t_xifenfei on t_xifenfei(object_name); Index created. SQL> BEGIN 2 dbms_stats.gather_table_stats(USER,\'T_XIFENFEI\',cascade => true); 3 END; 4 / PL/SQL procedure successfully completed.
无index hint
SQL> SET AUTOT TRACE EXPL STAT SQL> SELECT OBJECT_ID FROM t_xifenfei; 845708 rows selected. Execution Plan ---------------------------------------------------------- Plan hash value: 548923532 -------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | -------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 841K| 4109K| 886 (3)| 00:00:11 | | 1 | TABLE ACCESS FULL| T_XIFENFEI | 841K| 4109K| 886 (3)| 00:00:11 | -------------------------------------------------------------------------------- Statistics ---------------------------------------------------------- 1 recursive calls 0 db block gets 60525 consistent gets 0 physical reads 0 redo size 15543305 bytes sent via SQL*Net to client 620649 bytes received via SQL*Net from client 56382 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 845708 rows processed
这里因为object_id列可能有null值,所以不会使用b_tree_t_xifenfei索引,预料之中事件
index hint b_tree_t_xifenfei
SQL> SET LINESIZE 150 SQL> SELECT /*+ INDEX(T b_tree_t_xifenfei) */object_id from t_xifenfei t; 845708 rows selected. Execution Plan ---------------------------------------------------------- Plan hash value: 1935372603 -------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | -------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 841K| 4109K| 18940 (1)| 00:03:48 | | 1 | TABLE ACCESS BY INDEX ROWID | T_XIFENFEI | 841K| 4109K| 18940 (1)| 00:03:48 | | 2 | BITMAP CONVERSION TO ROWIDS| | | | | | | 3 | BITMAP INDEX FULL SCAN | BITMAP_T_XIFENFEI | | | | | -------------------------------------------------------------------------------------------------- Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 91537 consistent gets 0 physical reads 0 redo size 42362633 bytes sent via SQL*Net to client 620649 bytes received via SQL*Net from client 56382 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 845708 rows processed
这里因为object_id列可能有null值,所以不会使用b_tree_t_xifenfei索引,这里的疑惑是:
就算不会使用b_tree_t_xifenfei index也不应该会使用BITMAP_T_XIFENFEI index,因为使用这个的cost会大于全表扫描
index hint 一个无效index
SQL> SELECT /*+ INDEX(T abc) */object_id from t_xifenfei t; 845708 rows selected. Execution Plan ---------------------------------------------------------- Plan hash value: 1935372603 -------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | -------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 841K| 4109K| 18940 (1)| 00:03:48 | | 1 | TABLE ACCESS BY INDEX ROWID | T_XIFENFEI | 841K| 4109K| 18940 (1)| 00:03:48 | | 2 | BITMAP CONVERSION TO ROWIDS| | | | | | | 3 | BITMAP INDEX FULL SCAN | BITMAP_T_XIFENFEI | | | | | -------------------------------------------------------------------------------------------------- Statistics ---------------------------------------------------------- 1 recursive calls 0 db block gets 91537 consistent gets 0 physical reads 0 redo size 42362633 bytes sent via SQL*Net to client 620649 bytes received via SQL*Net from client 56382 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 845708 rows processed
这里使用了一个无效的index,也使用了BITMAP_T_XIFENFEI,让人更加的感觉奇怪
原因分析
If the INDEX hint specifies no indexes, then the optimizer considers the cost of a scan on each available index on the table and then performs the index scan with the lowest cost. The database can also choose to scan multiple indexes and merge the results, if such an access path has the lowest cost. The optimizer does not consider a full table scan.
如果我们使用hint指定了一个无效的index,优化器会扫描表中所有可以使用的index,然后选择cost最小的index或者index组合,而不会选择全表扫描。
因为我们hint指定b_tree_t_xifenfei index的时候,因为object_id可能有值为空(列没定义为not null),所以不能使用该index,从而也就是相当于一个无效的index,从而扫描该表的其他可以使用的index,导致使用了位图索引(该类型index不排除null),而不是全表扫描.
温馨提示:使用hint指定index的时候需要慎重,如果不合适或者无效,可能导致程序效率更低
建议继续学习:
扫一扫订阅我的微信号:IT技术博客大学习
- 作者:惜分飞 来源: 惜分飞
- 标签: hint
- 发布时间:2012-04-09 12:21:21
- [66] Oracle MTS模式下 进程地址与会话信
- [65] Go Reflect 性能
- [64] 如何拿下简短的域名
- [60] android 开发入门
- [59] 图书馆的世界纪录
- [59] 【社会化设计】自我(self)部分――欢迎区
- [58] IOS安全–浅谈关于IOS加固的几种方法
- [54] 视觉调整-设计师 vs. 逻辑
- [48] 界面设计速成
- [48] 读书笔记-壹百度:百度十年千倍的29条法则