Like SQL语句的优化的一个小测试
1.尽量不要使用 like '%..%'
2.对于 like '..%..' (不以 % 开头),Oracle可以应用 colunm上的index
3.对于 like '%...' 的 (不以 % 结尾),可以利用reverse + function index 的形式,变化成 like '..%'
具体的测试流程: (测试工具:PLSQL Developer)
[1] '建测试表和Index,注意,重点在于带reverse的function index。同时,一定要使用CBO才行。
已连接到 Oracle Database 10g Enterprise Edition Release 10.2.0.1.0
已连接为 zxdbm_ismp
SQL> select reverse('123') from dual;
REVERSE('123')
--------------
321
SQL> create table test_like as select object_id,object_name from dba_objects;
Table created.
SQL> create index test_like_name on test_like(object_name);
Index created.
SQL> create index test_like_name_reverse on test_like(reverse(object_name)); --建反向索引
Index created.
SQL> analyze table test_like compute statistics for table for all indexes;
Table analyzed.
SQL> set autotrace trace exp
[2] '常量开头的like , 会利用index ,没问题…… '
SQL> select * from test_like where object_name like 'AS%';
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=2 Card=655 Bytes=15720)
1 0 TABLE ACCESS (BY INDEX ROWID) OF 'TEST_LIKE' (Cost=2 Card=655Bytes=15720)
2 1 INDEX (RANGE SCAN) OF 'TEST_LIKE__NAME' (NON-UNIQUE) (Cost=2 Card=118)
[3] '开头和结尾都是 % ,对不起,很难优化'
SQL> select * from test_like where object_name like '%%';
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=6 Card=655 Bytes=15720)
1 0 TABLE ACCESS (FULL) OF 'TEST_LIKE' (Cost=6 Card=655 ytes=15720)
[4] '以常量结束,直接写的时候是不能应用index的'
SQL> select * from test_like where object_name like '%S';
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=6 Card=655 Bytes=15720)
1 0 TABLE ACCESS (FULL) OF 'TEST_LIKE' (Cost=6 Card=655 Bytes=15720)
[5] '以常量结束的,加个reverse 函数,又可以用上index了'(需要反向索引的支持)
SQL> select * from test_like where reverse(object_name)like reverse('%AS');
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=2 Card=655 Bytes=15720)
1 0 TABLE ACCESS (BY INDEX ROWID) OF 'TEST_LIKE' (Cost=2 Card=655 Bytes=15720)
2 1 INDEX (RANGE SCAN) OF 'TEST_LIKE__NAME_REVERSE' (NON-UNIQUE) (Cost=2 Card=118)
转:http://rollingpig.itpub.net/category/81/30081
posted on 2008-01-23 15:58
cheng 阅读(4298)
评论(2) 编辑 收藏 所属分类:
Oracle