[20170601]distinct的优化.txt

简介: [20170601]distinct的优化.txt 1.环境: SCOTT@book> @ &r/ver1 PORT_STRING          VERSION    BANNER -------------------- ---------- ...

[20170601]distinct的优化.txt

1.环境:
SCOTT@book> @ &r/ver1
PORT_STRING          VERSION    BANNER
-------------------- ---------- --------------------------------------------------------------------------------
x86_64/Linux 2.4.xx  11.2.0.4.0 Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production

create table t as select * from all_objects;
create index t_idx on t(owner,object_id);

--//分析表略.method_opt=>'for all columns size 1'.
 
select index_name,blevel,leaf_blocks,
    distinct_keys,num_rows,
    avg_leaf_blocks_per_key lf_per_key,
    avg_data_blocks_per_key blks_per_key
from user_indexes
where index_name ='T_IDX';

INDEX_NAME BLEVEL LEAF_BLOCKS DISTINCT_KEYS   NUM_ROWS LF_PER_KEY BLKS_PER_KEY
---------- ------ ----------- ------------- ---------- ---------- ------------
T_IDX           1         256         84774      84774          1            1

--//注意T表 owner is not null.
--//当我们执行select distinct owner from t;时正常情况下选择的执行计划如下:

alter session set statistics_level=all;

SCOTT@book> column owner format a30
SCOTT@book> select distinct owner from t;
OWNER
------------------------------
OWBSYS_AUDIT
MDSYS
CTXSYS
FLOWS_FILES
HR
OLAPSYS
OUTLN
OWBSYS
PUBLIC
APEX_030200
EXFSYS
ORACLE_OCM
SCOTT
SYSTEM
DBSNMP
OE
ORDPLUGINS
ORDSYS
PM
SH
SYSMAN
APPQOSSYS
BI
IX
ORDDATA
XDB
SI_INFORMTN_SCHEMA
SYS
WMSYS
29 rows selected.

SCOTT@book> @ &r/dpc '' ''
PLAN_TABLE_OUTPUT
-------------------------------------
SQL_ID  g3ywa5u5raj7d, child number 0
-------------------------------------
select distinct owner from t
Plan hash value: 1741570181
----------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation             | Name  | Starts | E-Rows |E-Bytes| Cost (%CPU)| E-Time   | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
----------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT      |       |      1 |        |       |    74 (100)|          |     29 |00:00:00.04 |     263 |       |       |          |
|   1 |  HASH UNIQUE          |       |      1 |     29 |   174 |    74   (5)| 00:00:01 |     29 |00:00:00.04 |     263 |  5686K|  1858K| 2222K (0)|
|   2 |   INDEX FAST FULL SCAN| T_IDX |      1 |  84774 |   496K|    71   (0)| 00:00:01 |  84774 |00:00:00.01 |     263 |       |       |          |
----------------------------------------------------------------------------------------------------------------------------------------------------
Query Block Name / Object Alias (identified by operation id):
-------------------------------------------------------------
   1 - SEL$1
   2 - SEL$1 / T@SEL$1

--//这样相当于把索引当作表做快速扫描,然后使用HASH UNIQUE过滤需要的结果.主要成本消耗就是扫描整个索引的成本.
--//而我们可以想象还有1个更佳的算法,就是通过递规每次查询owner的最小值,而查询最小值的逻辑读是很小的.

with ownerlist(x) as
(  
   select min(owner) from t
   union all
   select (select min(owner) from t where t.owner > ownerlist.x ) from ownerlist where x is not null
) select * from ownerlist where x is not null ;

--//注意一定要加一个条件where x is not null,不然变成死循环.后面也要加where x is not null ;,不然记录会多1条null值.

SCOTT@book> @ &r/dpc '' ''
PLAN_TABLE_OUTPUT
-------------------------------------
SQL_ID  frvat47pq8f2x, child number 0
-------------------------------------
with ownerlist(x) as (    select min(owner) from t    union all
select (select min(owner) from t where t.owner > ownerlist.x ) from
ownerlist where x is not null ) select * from ownerlist where x is not
null

Plan hash value: 946542369
---------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                 | Name  | Starts | E-Rows |E-Bytes| Cost (%CPU)| E-Time   | A-Rows |   A-Time   | Buffers |
---------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                          |       |      1 |        |       |     4 (100)|          |     29 |00:00:00.01 |      33 |
|*  1 |  VIEW                                     |       |      1 |      2 |    34 |     4   (0)| 00:00:01 |     29 |00:00:00.01 |      33 |
|   2 |   UNION ALL (RECURSIVE WITH) BREADTH FIRST|       |      1 |        |       |            |          |     30 |00:00:00.01 |      33 |
|   3 |    SORT AGGREGATE                         |       |      1 |      1 |     6 |            |          |      1 |00:00:00.01 |       2 |
|   4 |     INDEX FULL SCAN (MIN/MAX)             | T_IDX |      1 |      1 |     6 |     2   (0)| 00:00:01 |      1 |00:00:00.01 |       2 |
|   5 |    SORT AGGREGATE                         |       |     29 |      1 |     6 |            |          |     29 |00:00:00.01 |      31 |
|   6 |     FIRST ROW                             |       |     29 |      1 |     6 |     2   (0)| 00:00:01 |     28 |00:00:00.01 |      31 |
|*  7 |      INDEX RANGE SCAN (MIN/MAX)           | T_IDX |     29 |      1 |     6 |     2   (0)| 00:00:01 |     28 |00:00:00.01 |      31 |
|   8 |    RECURSIVE WITH PUMP                    |       |     30 |        |       |            |          |     29 |00:00:00.01 |       0 |
---------------------------------------------------------------------------------------------------------------------------------------------
Query Block Name / Object Alias (identified by operation id):
-------------------------------------------------------------
   1 - SET$1 / OWNERLIST@SEL$4
   2 - SET$1
   3 - SEL$1
   4 - SEL$1 / T@SEL$1
   5 - SEL$3
   7 - SEL$3 / T@SEL$3
   8 - SEL$2

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter("X" IS NOT NULL)
   7 - access("T"."OWNER">:B1)

--//执行计划看起来很复杂,实际上理解了逻辑还是很简单的.逻辑读=33,明显比前面少许多,比较适合重复值很多的distinct.

--//想要说明一点,实际上算法很重要,许多开发正是丢掉这些最基本的东西,写出来的sql语句就像中学生写的家庭作业.

目录
相关文章
|
SQL 关系型数据库 索引
|
SQL 关系型数据库 PostgreSQL
distinct xx和count(distinct xx)的变态递归优化方法
今天要说的这个优化是从前面一篇讲解《performance tuning case :use cursor or trigger replace group by and order by》http://blog.163.com/digoal@126/blog/static/16387704020.
11041 0
|
关系型数据库 数据库
[20180625]10g下查询条件rownum = 0.txt
[20180625]10g下查询条件rownum = 0.txt SCOTT@test> @ &r/ver1 PORT_STRING                    VERSION        BANNER --------------------...
1174 0
|
SQL 测试技术 索引
[20180509]函数索引问题.txt
[20180509]函数索引问题.txt https://jonathanlewis.wordpress.com/2018/05/07/fbis-dont-exist/ --//重复测试: 1.
1127 0
|
关系型数据库 Linux 索引
[20180212]函数索引问题.txt
[20180212]函数索引问题.txt --//11g下,如果函数索引,字段出现重复,出现ORA-54015: Duplicate column expression was specified.
998 0
|
Oracle 关系型数据库 Linux
[20170816]Join Elimination Bug.txt
[20170816]Join Elimination Bug.txt https://jonathanlewis.wordpress.com/2017/08/14/join-elimination-bug/ --//自己重复测试1次.
845 0
|
Java
[20170703]pivot与order by字段.txt
[20170703]pivot与order by字段.txt --//11G开始支持pivot,上午写一个脚本,来自链接http://blog.itpub.net/267265/viewspace-1063539/ --//做了一点点改写.
955 0
[20170525]分析函数first_value.txt
[20170525]分析函数first_value.txt --//昨天看sql语句,发现居然分析函数first_value.我一直认为开发如果要做一些报表需要了解学习一些oracle分析函数的知识,我发现许 --//多开发这方面一篇空白.
823 0
|
关系型数据库 Oracle Linux
[20170503]]函数COALESCE优于NVL 2.txt
[20170503]]函数COALESCE优于NVL 2.txt http://blog.itpub.net/267265/viewspace-2137853/ --//上面的链接提示COALESCE具有短路的功能,能很快获得结果,我上次测试采用自定义函数,演示这个功能,实际上的应用不会是变量,可能 --//是常数.
936 0
[20170424]函数COALESCE优于NVL.txt
[20170424]函数COALESCE优于NVL.txt --//以前如果某个字段为NULL,在一些运算要给它赋值,比如0,实际上开发(包括自己更喜欢使用nvl),实际上COALESCE更加优于nvl, --//参考链接做一个例子: http://nimishgarg.
1083 0