eygle.com   eygle.com
eygle.com eygle
eygle.com  
 

« Oracle中临时表产生过量Redo的说明 | Blog首页 | Nologging到底何时才能生效? »

使用or展开进行sql调整
modb.pro

使用or展开进行sql调整

 

作者: Eygle


itpub link:

http://www.itpub.net/showthread.php?threadid=239335


 

问题:

这样一条sql应该怎么优化?

select * from sys_user 
where user_code = 'zhangyong' 
or user_code in 
(select grp_code 
from sys_grp 
where sys_grp.user_code = 'zhangyong')


Execution Plan
----------------------------------------------------------
0  SELECT STATEMENT Optimizer=RULE
1  0   FILTER
2  1     TABLE ACCESS (FULL) OF 'SYS_USER'
3  1     INDEX (UNIQUE SCAN) OF 'PK_SYS_GRP' (UNIQUE)


Statistics
----------------------------------------------------------
14  recursive calls
4  db block gets
30590 consistent gets
0  physical reads
0  redo size
1723  bytes sent via SQL*Net to client
425  bytes received via SQL*Net from client
2  SQL*Net roundtrips to/from client
0  sorts (memory)
0  sorts (disk)
3  rows processed

里面的查询返回的记录数一般只有一两条,但sys_user表的数据很多,怎么样才能让这条sql以sys_grp为驱动表
表中记录情况如下:

 

SQL> select count(*) from sys_grp;
COUNT(*)
----------
25130

SQL> select count(*) from sys_user;
COUNT(*) ---------- 15190

 

优化:

降低逻辑读是优化SQL的基本原则之一

我们尝试通过降低逻辑读来加快SQL的执行.

这里我们使用or展开来改写SQL查询:

 

select * from sys_user where user_code = 'zhangyong' 
union all
select * from sys_user where user_code <> 'zhangyong' 
and user_code in (select grp_code from sys_grp where sys_grp.user_code = 'zhangyong')

Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
         130 consistent gets
          0  physical reads
          0  redo size
       1723  bytes sent via SQL*Net to client
        425  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          1  sorts (memory)
          0  sorts (disk)
          3  rows processed

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=RULE
   1    0   UNION-ALL
   2    1     TABLE ACCESS (BY INDEX ROWID) OF 'SYS_USER'
   3    2       INDEX (UNIQUE SCAN) OF 'PK_SYS_USER' (UNIQUE)
   4    1     NESTED LOOPS
   5    4       VIEW OF 'VW_NSO_1'
   6    5         SORT (UNIQUE)
   7    6           TABLE ACCESS (BY INDEX ROWID) OF 'SYS_GRP'
   8    7             INDEX (RANGE SCAN) OF 'FK_SYS_USER_CODE' (NON-UNIQUE)
   9    4       TABLE ACCESS (BY INDEX ROWID) OF 'SYS_USER'
  10    9         INDEX (UNIQUE SCAN) OF 'PK_SYS_USER' (UNIQUE)  
  

我们注意到,通过改写,逻辑读减少到130,从30590130这是一个巨大的提高,减少逻辑读最终会减少资源消耗,提高SQL的执行效率.

这个改写把Filter改为了Nest LOOP,索引得以充分利用.从而大大提高了性能.

我们同时注意到,这里引入了一个排序

排序来自于这一步:

-----------------------------------------------------------------------------------------
6 5 SORT (UNIQUE) 7 6 TABLE ACCESS (BY INDEX ROWID) OF 'SYS_GRP' 8 7 INDEX (RANGE SCAN) OF 'FK_SYS_USER_CODE' (NON-UNIQUE)

------------------------------------------------------------------------------------------

在'SYS_GRP'表中,user_code 是非唯一键值
在in值判断里,要做sort unique排序,去除重复值

这里的union all是不需要排序的

 


历史上的今天...
    >> 2020-07-09文章:
    >> 2010-07-09文章:
    >> 2009-07-09文章:
    >> 2007-07-09文章:

By eygle on 2004-07-09 09:25 | Comments (0) | SQL.PLSQL | 37 |


CopyRight © 2004~2020 云和恩墨,成就未来!, All rights reserved.
数据恢复·紧急救援·性能优化 云和恩墨 24x7 热线电话:400-600-8755 业务咨询:010-59007017-7040 or 7037 业务合作: marketing@enmotech.com