扫一扫
分享文章到微信
扫一扫
关注官方公众号
至顶头条
在本页阅读全文(共2页)
扫描成本和OPTIMIZER_INDEX_COST_ADJ
我们知道,在CBO模式下,Oracle会计算各个访问路径的代价,采用最小代价的访问路径作为语句的执行计划。而对于索引的访问代价的计算,需要根据一个系统参数OPTIMIZER_INDEX_COST_ADJ来转换为与全表扫描代价等价的一个值。这是什么意思呢?我们先稍微解释一下这个参数:OPTIMIZER_INDEX_COST_ADJ。它的值是一个百分比,默认是100,取值范围是1~10000。当估算索引扫描代价时,会将索引的原始代价值乘以这个百分比,将换算后的值作为与全表扫描代价比较的值。也就是说,当这个值为100时,计算出的索引扫描代价就是它的原始代价:
COST_COM = COST_ORG * OPTIMIZER_INDEX_COST_ADJ/100 |
看以下例子:
SQL> create table T_PEEKING (a NUMBER, b char(1), c char(2000)); Table created. SQL> SQL> create index T_PEEKING_IDX1 on T_PEEKING(b); Index created. SQL> begin 2 for i in 1..1000 loop 3 insert into T_PEEKING values (i, 'A', i); 4 end loop; 5 6 insert into T_PEEKING values (1001, 'B', 1001); 7 insert into T_PEEKING values (1002, 'B', 1002); 8 insert into T_PEEKING values (1003, 'C', 1003); 9 10 commit; 11 end; 12 / PL/SQL procedure successfully completed. |
注意,我们给索引字段B插入的值中只有3个distinct值,记录数是1003,它的集的势很高(1003/3)=334。
SQL> SQL> analyze table T_PEEKING compute statistics for table for all indexes for all indexed columns; Table analyzed. SQL> |
我们看下索引扫描的代价是多少:
SQL> show parameter OPTIMIZER_INDEX_COST_ADJ NAME TYPE VALUE ------------------------------------ ----------- ------ optimizer_index_cost_adj integer 100 SQL> delete from plan_table; 0 rows deleted. SQL> SQL> explain plan for select /*+index(a T_PEEKING_IDX1)*/ * from T_PEEKING a where b = :V; Explained. SQL> select lpad(' ', 2*(level-1))||operation||' '||options||' '|| 2 object_name||' '||decode(id, 0, 'Cost='||position) "Query 3 Plan_Table" 4 from plan_table 5 start with id = 0 6 connect by prior id = parent_id 7 ; Query Plan_Table ----------------------------------------------------- SELECT STATEMENT Cost=113 TABLE ACCESS BY INDEX ROWID T_PEEKING INDEX RANGE SCAN T_PEEKING_IDX1 SQL> |
再看全表扫描的代价是多少:
SQL> delete from plan_table; 3 rows deleted. SQL> SQL> explain plan for select /*+full(a)*/ * from T_PEEKING a where b = :V; Explained. SQL> SQL> select lpad(' ', 2*(level-1))||operation||' '||options||' '|| 2 object_name||' '||decode(id, 0, 'Cost='||position) "Query 3 Plan_Table" 4 from plan_table 5 start with id = 0 6 connect by prior id = parent_id 7 ; Query Plan_Table ---------------------------------------------------- SELECT STATEMENT Cost=75 TABLE ACCESS FULL T_PEEKING SQL> |
这时,我们可以计算得出让优化器使用索引(无提示强制)的OPTIMIZER_INDEX_COST_ADJ值应该< ROUND(COST_FTS/COST_IDX*100) = ROUND(75/113*100) = 66,而大于66则会使用全表扫描:
SQL> alter system set OPTIMIZER_INDEX_COST_ADJ=67; System altered. SQL> SQL> delete from plan_table; 2 rows deleted. SQL> SQL> explain plan for select * from T_PEEKING a where b = :V; Explained. SQL> SQL> select lpad(' ', 2*(level-1))||operation||' '||options||' '|| 2 object_name||' '||decode(id, 0, 'Cost='||position) "Query 3 Plan_Table" 4 from plan_table 5 start with id = 0 6 connect by prior id = parent_id; Query Plan_Table ----------------------------------------------------------------- SELECT STATEMENT Cost=75 TABLE ACCESS FULL T_PEEKING SQL> SQL> SQL> alter system set OPTIMIZER_INDEX_COST_ADJ=66; System altered. SQL> SQL> delete from plan_table; 2 rows deleted. SQL> SQL> explain plan for select * from T_PEEKING a where b = :V; Explained. SQL> SQL> select lpad(' ', 2*(level-1))||operation||' '||options||' '|| 2 object_name||' '||decode(id, 0, 'Cost='||position) "Query 3 Plan_Table" 4 from plan_table 5 start with id = 0 6 connect by prior id = parent_id; Query Plan_Table --------------------------------------------------------- SELECT STATEMENT Cost=75 TABLE ACCESS BY INDEX ROWID T_PEEKING INDEX RANGE SCAN T_PEEKING_IDX1 |
可以看出,在使用绑定变量时,参数OPTIMIZER_INDEX_COST_ADJ对于是否选择索引会有重要的影响。
如果您非常迫切的想了解IT领域最新产品与技术信息,那么订阅至顶网技术邮件将是您的最佳途径之一。
现场直击|2021世界人工智能大会
直击5G创新地带,就在2021MWC上海
5G已至 转型当时——服务提供商如何把握转型的绝佳时机
寻找自己的Flag
华为开发者大会2020(Cloud)- 科技行者