Chinaunix首页 | 论坛 | 博客
  • 博客访问: 457917
  • 博文数量: 711
  • 博客积分: 3000
  • 博客等级: 中校
  • 技术积分: 4200
  • 用 户 组: 普通用户
  • 注册时间: 2008-10-28 14:18
文章分类

全部博文(711)

文章存档

2011年(1)

2008年(710)

我的朋友

分类:

2008-10-28 14:18:45

今天开发人员让我优化一个sql:
Select Item.* From Item Item Where Item.Item_Id in (15056, 14697);

  这个item表很大,sql执行起来很慢。

Execution Plan ---------------------------------------------------------- 0 SELECT STATEMENT Optimizer=CHOOSE (Cost=12795 Card=2 Bytes=1 316) 1 0 TABLE ACCESS (FULL) OF 'ITEM' (Cost=12795 Card=2 Bytes=131 6) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 134234 consistent gets 26568 physical reads 2184 redo size 3336 bytes sent via SQL*Net to client 503 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 2 rows processed

  在这个例子中,item_id是item表的主键。这里慢的原因是in操作不能用到索引,做全表扫描,但为什么不能用索引呢?

  实际上,oracle在处理in的时候是转换成or进行处理的,如:

  a in (1,2)相当于 a=1 or a=2

  而对于b*tree索引来说,对于or操作是不会用到索引的。知道原因,下面就要找出解决方法了。

  方法一、从b*tree索引着手

  这种方法就是想办法让查询可以走b*tree索引。要走btree索引,就要去掉or操作,所以把查询改成一个等价的sql:

SQL> Select Item.* From Item Item Where Item.Item_Id in (14697) 2 union all 3 Select Item.* From Item Item Where Item.Item_Id in (15056); Execution Plan ---------------------------------------------------------- 0 SELECT STATEMENT Optimizer=CHOOSE (Cost=6 Card=2 Bytes=1316) 1 0 UNION-ALL 2 1 TABLE ACCESS (BY INDEX ROWID) OF 'ITEM' (Cost=3 Card=1 B ytes=658) 3 2 INDEX (UNIQUE SCAN) OF 'PK_ITEM' (UNIQUE) (Cost=2 Card =1) 4 1 TABLE ACCESS (BY INDEX ROWID) OF 'ITEM' (Cost=3 Card=1 B ytes=658) 5 4 INDEX (UNIQUE SCAN) OF 'PK_ITEM' (UNIQUE) (Cost=2 Card =1) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 8 consistent gets 0 physical reads 0 redo size 3334 bytes sent via SQL*Net to client 503 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 2 rows processed

  从输出结果可以看出,sql已经可以有索引了,效率也得到大幅提高。但这种办法有缺陷:
如果in list的个数不确定,且如果in list较多的话,拼sql都是一个问题。我这个应用就是这种情况。

  方法二、从位图方式着手

  我们知道,位图索引是可以被or操作使用的,我们可以根据这一特点先用btree索引查询数据,然后进行位图转换、联合。
oracle给我们提供了一个hint来解决这个问题:use_concat。原sql修改为:

SQL> Select /*+ use_concat */
Item.
* From Item Item Where Item.Item_Id in (15056,14697); Execution Plan ---------------------------------------------------------- 0 SELECT STATEMENT Optimizer=CHOOSE (Cost=6 Card=2 Bytes=1316) 1 0 TABLE ACCESS (BY INDEX ROWID) OF 'ITEM' (Cost=6 Card=2 Byt es=1316) 2 1 BITMAP CONVERSION (TO ROWIDS) 3 2 BITMAP OR 4 3 BITMAP CONVERSION (FROM ROWIDS) 5 4 INDEX (RANGE SCAN) OF 'PK_ITEM' (UNIQUE) (Cost=2) 6 3 BITMAP CONVERSION (FROM ROWIDS) 7 6 INDEX (RANGE SCAN) OF 'PK_ITEM' (UNIQUE) (Cost=2) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 8 consistent gets 0 physical reads 0 redo size 3336 bytes sent via SQL*Net to client 503 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 2 rows processed

  从结果可以看到,oracle先通过主键索引分别对两个id进行查询,然后转换成位图进行合并,这样效率就得到提供,对原sql的改动也很小,基本满足了要求。

  本文所有结果都是基于 as 3+ oracle9204平台。

  这个转换受_b_tree_bitmap_plans决定。如果该参数为true,则可进行转换,否则不进行转换。而8i里,该参数缺省为false,所以只有存在bitmap索引时才会考虑将B树索引转换为bitmap; 而到了9i里,该参数缺省为true了,则对任何索引都有可能进行bitmap转换。

  顺便提一下,今天在itpub有帖子讲到in能否用到btree索引问题,我这里总结一下:
  1、如果in list是具体的term,如id in (1,1,2)之类的话,是不会用到b*tree的
  2、如果in list是有一个子查询得到的,如id in (select id from t2),那么这个查询实际两表关联。那么能否用到id列的索引要受到很多因素的制约了。

【责编:Peng】

--------------------next---------------------
Execution Plan ---------------------------------------------------------- 0 SELECT STATEMENT Optimizer=CHOOSE (Cost=12795 Card=2 Bytes=1 316) 1 0 TABLE ACCESS (FULL) OF 'ITEM' (Cost=12795 Card=2 Bytes=131 6) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 134234 consistent gets 26568 physical reads 2184 redo size 3336 bytes sent via SQL*Net to client 503 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 2 rows processed

--------------------next---------------------
SQL> Select Item.* From Item Item Where Item.Item_Id in (14697) 2 union all 3 Select Item.* From Item Item Where Item.Item_Id in (15056); Execution Plan ---------------------------------------------------------- 0 SELECT STATEMENT Optimizer=CHOOSE (Cost=6 Card=2 Bytes=1316) 1 0 UNION-ALL 2 1 TABLE ACCESS (BY INDEX ROWID) OF 'ITEM' (Cost=3 Card=1 B ytes=658) 3 2 INDEX (UNIQUE SCAN) OF 'PK_ITEM' (UNIQUE) (Cost=2 Card =1) 4 1 TABLE ACCESS (BY INDEX ROWID) OF 'ITEM' (Cost=3 Card=1 B ytes=658) 5 4 INDEX (UNIQUE SCAN) OF 'PK_ITEM' (UNIQUE) (Cost=2 Card =1) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 8 consistent gets 0 physical reads 0 redo size 3334 bytes sent via SQL*Net to client 503 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 2 rows processed

--------------------next---------------------
SQL> Select /*+ use_concat */
Item.
* From Item Item Where Item.Item_Id in (15056,14697); Execution Plan ---------------------------------------------------------- 0 SELECT STATEMENT Optimizer=CHOOSE (Cost=6 Card=2 Bytes=1316) 1 0 TABLE ACCESS (BY INDEX ROWID) OF 'ITEM' (Cost=6 Card=2 Byt es=1316) 2 1 BITMAP CONVERSION (TO ROWIDS) 3 2 BITMAP OR 4 3 BITMAP CONVERSION (FROM ROWIDS) 5 4 INDEX (RANGE SCAN) OF 'PK_ITEM' (UNIQUE) (Cost=2) 6 3 BITMAP CONVERSION (FROM ROWIDS) 7 6 INDEX (RANGE SCAN) OF 'PK_ITEM' (UNIQUE) (Cost=2) Statistics ---------------------------------------------------------- 0 recursive calls 0 db block gets 8 consistent gets 0 physical reads 0 redo size 3336 bytes sent via SQL*Net to client 503 bytes received via SQL*Net from client 2 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 2 rows processed

--------------------next---------------------

阅读(447) | 评论(0) | 转发(0) |
给主人留下些什么吧!~~