s2下半年我在内部有一次部门级别的技术分享会,以本文内容分享为主。
其实有很多人问过我相同的问题,遇到需要改写的慢sql,不知道怎么改,改好了以后也不知道等不等价?不等价了也不知道错在哪?这个要怎么破?
其实都是因为绝大多数人没有做过开发,看不懂sql,不会写sql,没有sql思维,下面通过几个案例将sql思维给引出来。
这种排名的窗口函数(row_number()、rank()、dense_rank())据我所知,除了在oracle上大数据量执行性能表现得不错,其他各种数据库(包括列式存储的ap库),性能都表现都很一般。
所以如果在项目上遇到row_number() over() 性能不理想的情况下,可以尝试进行改写优化。
PS:当然可以通过加并行hint来提升效率,但是我们这篇文章主要是讲如何将数据库提供的逻辑通过另外一种方式来实现,提升自己sql代码思维。
-- student 数据量
obclient [YZJ]> select count(1) from student;
+----------+
| COUNT(1) |
+----------+
| 500001 |
+----------+
1 row in set (0.002 sec)
-- 案例sql
-- S.CLASS : 学科、包含null值
-- S.S_DATE: 入学时间
SELECT * FROM (
SELECT
S.*,
row_number() OVER(PARTITION BY S.CLASS ORDER BY S.S_DATE DESC) RN
FROM student S
) WHERE RN = 1;
27 rows in set (0.639 sec)
+---------------------------------------------------------------------------------------------------------------------------------------------------------------+
| Query Plan |
+---------------------------------------------------------------------------------------------------------------------------------------------------------------+
| ================================================================ |
| |ID|OPERATOR |NAME |EST.ROWS|EST.TIME(us)| |
| ---------------------------------------------------------------- |
| |0 |SUBPLAN SCAN |ANONYMOUS_VIEW1|4 |691395 | |
| |1 |└─WINDOW FUNCTION | |500001 |682867 | |
| |2 | └─PARTITION SORT | |500001 |249986 | |
| |3 | └─TABLE FULL SCAN|S |500001 |46352 | |
| ================================================================ |
| Outputs & filters: |
| ------------------------------------- |
| 0 - output([.ID], [.NAME], [.AGE], [.SEX], [.S_DATE], [.CLASS], [.RN]), filter([.RN = 1]), rowset=256 |
| access([.RN], [.ID], [.NAME], [.AGE], [.SEX], [.S_DATE], [.CLASS]) |
| 1 - output([S.ID], [S.NAME], [S.AGE], [S.SEX], [S.S_DATE], [S.CLASS], [T_WIN_FUN_ROW_NUMBER()]), filter(nil), rowset=256 |
| win_expr(T_WIN_FUN_ROW_NUMBER()), partition_by([S.CLASS]), order_by([S.S_DATE, DESC]), window_type(RANGE), upper(UNBOUNDED PRECEDING), lower(UNBOUNDED |
| FOLLOWING) |
| 2 - output([S.ID], [S.NAME], [S.AGE], [S.SEX], [S.S_DATE], [S.CLASS]), filter(nil), rowset=256 |
| sort_keys([HASH(S.CLASS), ASC], [S.CLASS, ASC], [S.S_DATE, DESC]) |
| 3 - output([S.ID], [S.NAME], [S.AGE], [S.SEX], [S.S_DATE], [S.CLASS]), filter(nil), rowset=256 |
| access([S.ID], [S.NAME], [S.AGE], [S.SEX], [S.S_DATE], [S.CLASS]), partitions(p0) |
| is_index_back=false, is_global_index=false, |
| range_key([S.ID]), range(MIN ; MAX)always true |
+---------------------------------------------------------------------------------------------------------------------------------------------------------------+
21 rows in set (0.004 sec)
改写窗口函数的逻辑,必须要将表关联2次或者2次+,需要将另外一张关联的表理解成一个“滑动”的窗口。
一般有两种改法:
SELECT s.* FROM student s -- 原表
INNER JOIN
(
SELECT
class,
max(s_date) max_date
FROM student
GROUP BY class
) s1 -- 滑动的窗口表
ON decode(s.class,NULL,'aab',s.class) = decode(s1.class,NULL,'aab',s1.class)
-- decode 处理 s表和s1窗口表的分组列class
AND s.s_date = s1.max_date
-- s表的s_date和窗口表s1的最大的日期去比较
WHERE exists(
SELECT 1 FROM student s2 where s1.max_date = s2.s_date GROUP BY s2.class having MAX(s2.ID) = S.ID
/* exists 这段比较抽象,我也是想了一会才实现逻辑。
实现 row_number() 唯一排名的数据
*/
);
27 rows in set (0.038 sec)
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| Query Plan |
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| ============================================================================================== |
| |ID|OPERATOR |NAME |EST.ROWS|EST.TIME(us)| |
| ---------------------------------------------------------------------------------------------- |
| |0 |SUBPLAN FILTER | |4 |28745 | |
| |1 |├─NESTED-LOOP JOIN | |8 |28555 | |
| |2 |│ ├─SUBPLAN SCAN |S1 |26 |27712 | |
| |3 |│ │ └─MERGE GROUP BY | |26 |27712 | |
| |4 |│ │ └─TABLE FULL SCAN |STUDENT(IDX_CLASS_SDATE_STUDENT)|500001 |14409 | |
| |5 |│ └─DISTRIBUTED TABLE RANGE SCAN |S(IDX_S_DATE_CALSS_ID) |1 |32 | |
| |6 |└─LIMIT | |1 |27 | |
| |7 | └─MERGE GROUP BY | |1 |27 | |
| |8 | └─DISTRIBUTED TABLE RANGE SCAN|S2(IDX_S_DATE_CALSS_ID) |56 |23 | |
| ============================================================================================== |
| Outputs & filters: |
| ------------------------------------- |
| 0 - output([S.ID], [S.NAME], [S.AGE], [S.SEX], [S.S_DATE], [S.CLASS]), filter([(T_OP_EXISTS, subquery(1))]), rowset=256 |
| exec_params_([S1.MAX_DATE(:0)], [S.ID(:1)]), onetime_exprs_(nil), init_plan_idxs_(nil), use_batch=false |
| 1 - output([S1.MAX_DATE], [S.ID], [S.NAME], [S.AGE], [S.SEX], [S.S_DATE], [S.CLASS]), filter(nil), rowset=256 |
| conds(nil), nl_params_([S1.CLASS(:4)], [S1.MAX_DATE(:5)]), use_batch=false |
| 2 - output([S1.CLASS], [S1.MAX_DATE]), filter(nil), rowset=256 |
| access([S1.CLASS], [S1.MAX_DATE]) |
| 3 - output([STUDENT.CLASS], [T_FUN_MAX(STUDENT.S_DATE)]), filter(nil), rowset=256 |
| group([STUDENT.CLASS]), agg_func([T_FUN_MAX(STUDENT.S_DATE)]) |
| 4 - output([STUDENT.CLASS], [STUDENT.S_DATE]), filter(nil), rowset=256 |
| access([STUDENT.CLASS], [STUDENT.S_DATE]), partitions(p0) |
| is_index_back=false, is_global_index=false, |
| range_key([STUDENT.CLASS], [STUDENT.S_DATE], [STUDENT.ID]), range(MIN,MIN,MIN ; MAX,MAX,MAX)always true |
| 5 - output([S.ID], [S.CLASS], [S.S_DATE], [S.NAME], [S.AGE], [S.SEX]), filter([ora_decode(cast(S.CLASS, VARCHAR2(1 BYTE)), cast(NULL, VARCHAR2(0 )), cast('aab', |
| VARCHAR2(3 BYTE)), cast(S.CLASS, VARCHAR2(3 BYTE))) = ora_decode(cast(:4, VARCHAR2(1 BYTE)), cast(NULL, VARCHAR2(0 )), cast('aab', VARCHAR2(3 BYTE)), cast(:4, |
| VARCHAR2(3 BYTE)))]), rowset=256 |
| access([S.ID], [S.CLASS], [S.S_DATE], [S.NAME], [S.AGE], [S.SEX]), partitions(p0) |
| is_index_back=true, is_global_index=false, filter_before_indexback[true], |
| range_key([S.S_DATE], [S.CLASS], [S.ID]), range(MIN ; MAX), |
| range_cond([S.S_DATE = :5]) |
| 6 - output([1]), filter(nil), rowset=256 |
| limit(1), offset(nil) |
| 7 - output(nil), filter([T_FUN_MAX(S2.ID) = :1]), rowset=256 |
| group([S2.CLASS]), agg_func([T_FUN_MAX(S2.ID)]) |
| 8 - output([S2.ID], [S2.CLASS]), filter(nil), rowset=256 |
| access([S2.ID], [S2.CLASS]), partitions(p0) |
| is_index_back=false, is_global_index=false, |
| range_key([S2.S_DATE], [S2.CLASS], [S2.ID]), range(MIN,MIN,MIN ; MAX,MAX,MAX)always true, |
| range_cond([:0 = S2.S_DATE]) |
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------+
43 rows in set (0.008 sec)
SELECT S1.*
FROM student S1
INNER JOIN
(
SELECT
decode(class,null,'aab',class) class,
MAX(S2.S_DATE) MAX_S_DATE,
MAX(ID) KEEP (DENSE_RANK LAST ORDER BY S_DATE) MAX_ID
FROM student S2
GROUP BY S2.CLASS
/*
改写逻辑:
1、decode(class,null,'aab',class) class, 提前处理null值。如果有其他案例谓词过滤条件要转换列名,
例如:upper(列名) = upper(:1) ,可以提前在先写个select括起来内表处理字段,弄个别名,然后外面再过滤。
select * from (
select upper(col) col1 from tb
) where col1 = upper(:1);
2、MAX(S2.S_DATE) MAX_S_DATE 不多说,找最大日期,等价 desc
3、MAX(ID) KEEP (DENSE_RANK LAST ORDER BY S_DATE) MAX_ID 等价于上个sql 的 exists逻辑,
利用keep 唯一的特性,取出不同组里面最大的 id + ORDER BY S_DATE LAST 最后的唯一数据。
相当于 MAX_S_DATE,和 MAX(id) keep 两个列的数据都是一条 ,相当于rn=1。
*/
) S2
ON decode(S1.CLASS,null,'aab',S1.CLASS) = S2.CLASS /* 处理关联列 */
AND S1.ID = S2.MAX_ID ;
-- AND S1.S_DATE = S2.MAX_S_DATE;
/* 其实用S1.ID = S2.MAX_ID 关联就行,
S1.S_DATE = S2.MAX_S_DATE 这个写不写都行,如果想逻辑更严谨点可以写上。
*/
27 rows in set (0.114 sec)
+------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| Query Plan |
+------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| ============================================================================== |
| |ID|OPERATOR |NAME |EST.ROWS|EST.TIME(us)| |
| ------------------------------------------------------------------------------ |
| |0 |NESTED-LOOP JOIN | |2 |44008 | |
| |1 |├─SUBPLAN SCAN |S2 |26 |43466 | |
| |2 |│ └─MERGE GROUP BY | |26 |43466 | |
| |3 |│ └─TABLE FULL SCAN |S2(IDX_CLASS_SDATE_STUDENT)|500001 |22423 | |
| |4 |└─DISTRIBUTED TABLE GET|S1 |1 |21 | |
| ============================================================================== |
| Outputs & filters: |
| ------------------------------------- |
| 0 - output([S1.ID], [S1.NAME], [S1.AGE], [S1.SEX], [S1.S_DATE], [S1.CLASS]), filter(nil), rowset=256 |
| conds(nil), nl_params_([S2.CLASS(:3)], [S2.MAX_S_DATE(:4)], [S2.MAX_ID(:5)]), use_batch=false |
| 1 - output([S2.CLASS], [S2.MAX_S_DATE], [S2.MAX_ID]), filter(nil), rowset=256 |
| access([S2.CLASS], [S2.MAX_S_DATE], [S2.MAX_ID]) |
| 2 - output([ora_decode(cast(S2.CLASS, VARCHAR2(1 BYTE)), cast(NULL, VARCHAR2(0 )), cast('aab', VARCHAR2(3 BYTE)), cast(S2.CLASS, VARCHAR2(3 BYTE)))], |
| [T_FUN_MAX(S2.S_DATE)], [T_FUN_KEEP_MAX(S2.ID) order_items(S2.S_DATE)]), filter(nil), rowset=256 |
| group([S2.CLASS]), agg_func([T_FUN_MAX(S2.S_DATE)], [T_FUN_KEEP_MAX(S2.ID) order_items(S2.S_DATE)]) |
| 3 - output([S2.ID], [S2.CLASS], [S2.S_DATE]), filter(nil), rowset=256 |
| access([S2.ID], [S2.CLASS], [S2.S_DATE]), partitions(p0) |
| is_index_back=false, is_global_index=false, |
| range_key([S2.CLASS], [S2.S_DATE], [S2.ID]), range(MIN,MIN,MIN ; MAX,MAX,MAX)always true |
| 4 - output([S1.ID], [S1.CLASS], [S1.S_DATE], [S1.NAME], [S1.AGE], [S1.SEX]), filter([S1.S_DATE = :4], [ora_decode(cast(S1.CLASS, VARCHAR2(1 BYTE)), cast(NULL, |
| VARCHAR2(0 )), cast('aab', VARCHAR2(3 BYTE)), cast(S1.CLASS, VARCHAR2(3 BYTE))) = :3]), rowset=256 |
| access([S1.ID], [S1.CLASS], [S1.S_DATE], [S1.NAME], [S1.AGE], [S1.SEX]), partitions(p0) |
| is_index_back=false, is_global_index=false, filter_before_indexback[false,false], |
| range_key([S1.ID]), range(MIN ; MAX), |
| range_cond([S1.ID = :5]) |
+------------------------------------------------------------------------------------------------------------------------------------------------------------------+
28 rows in set (0.011 sec)
row_number() over() 的逻辑还可以用表量子查询来实现,不过性能会更慢,实现起来很麻烦,就不在这里演示。
某些数据库可能不支持keep函数,或者keep函数的性能并不理想,我们也可以尝试通过另外一种方式来实现keep函数的逻辑。
SELECT
s1.class,
max(s1.s_date) MAX_S_DATE,
MAX(name) KEEP (DENSE_RANK LAST ORDER BY s1.s_date) max_name,
min(s1.s_date) MIN_S_DATE,
MIN(name) KEEP (DENSE_RANK FIRST ORDER BY s1.s_date) min_name
FROM student s1
GROUP BY
s1.class;
27 rows in set (0.495 sec)
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| Query Plan |
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| =================================================== |
| |ID|OPERATOR |NAME|EST.ROWS|EST.TIME(us)| |
| --------------------------------------------------- |
| |0 |MERGE GROUP BY | |26 |144304 | |
| |1 |└─PARTITION SORT | |500001 |107784 | |
| |2 | └─TABLE FULL SCAN|S1 |500001 |22309 | |
| =================================================== |
| Outputs & filters: |
| ------------------------------------- |
| 0 - output([S1.CLASS], [T_FUN_MAX(S1.S_DATE)], [T_FUN_KEEP_MAX(S1.NAME) order_items(S1.S_DATE)], [T_FUN_MIN(S1.S_DATE)], [T_FUN_KEEP_MIN(S1.NAME) order_items(S1.S_DATE)]), filter(nil), rowset=256 |
| group([S1.CLASS]), agg_func([T_FUN_MAX(S1.S_DATE)], [T_FUN_KEEP_MAX(S1.NAME) order_items(S1.S_DATE)], [T_FUN_MIN(S1.S_DATE)], [T_FUN_KEEP_MIN(S1.NAME) |
| order_items(S1.S_DATE)]) |
| 1 - output([S1.CLASS], [S1.S_DATE], [S1.NAME]), filter(nil), rowset=256 |
| sort_keys([HASH(S1.CLASS), ASC], [S1.CLASS, ASC]) |
| 2 - output([S1.CLASS], [S1.S_DATE], [S1.NAME]), filter(nil), rowset=256 |
| access([S1.CLASS], [S1.S_DATE], [S1.NAME]), partitions(p0) |
| is_index_back=false, is_global_index=false, |
| range_key([S1.ID]), range(MIN ; MAX)always true |
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
18 rows in set (0.004 sec)
改写逻辑很简单,先分组找出最大、最小的 日期,然后通过日期 + class 外部标量子查询找出最大、最小的name。
SELECT
CLASS,
MAX_S_DATE,
(SELECT max(NAME) FROM student s2 WHERE
decode(s1.CLASS,null,'bb',s1.CLASS) = decode(s2.CLASS,null,'bb',s2.CLASS) AND s2.S_DATE = s1.MAX_S_DATE) max_name,
MIN_S_DATE,
(SELECT min(NAME) FROM student s2 WHERE
decode(s1.CLASS,null,'bb',s1.CLASS) = decode(s2.CLASS,null,'bb',s2.CLASS) AND s2.S_DATE = s1.MIN_S_DATE) min_name
FROM (
SELECT
CLASS,
max(S_DATE) MAX_S_DATE,
min(S_DATE) MIN_S_DATE
FROM student
GROUP BY
CLASS
) s1 ;
27 rows in set (0.040 sec)
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| Query Plan |
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| ============================================================================================ |
| |ID|OPERATOR |NAME |EST.ROWS|EST.TIME(us)| |
| -------------------------------------------------------------------------------------------- |
| |0 |SUBPLAN FILTER | |26 |36802 | |
| |1 |├─MERGE GROUP BY | |26 |35450 | |
| |2 |│ └─TABLE FULL SCAN |STUDENT(IDX_CLASS_SDATE_STUDENT)|500001 |14409 | |
| |3 |├─SCALAR GROUP BY | |1 |26 | |
| |4 |│ └─DISTRIBUTED TABLE RANGE SCAN|S2(IDX_S_DATE_CALSS_ID) |1 |26 | |
| |5 |└─SCALAR GROUP BY | |1 |26 | |
| |6 | └─DISTRIBUTED TABLE RANGE SCAN|S2(IDX_S_DATE_CALSS_ID) |1 |26 | |
| ============================================================================================ |
| Outputs & filters: |
| ------------------------------------- |
| 0 - output([STUDENT.CLASS], [T_FUN_MAX(STUDENT.S_DATE)], [subquery(1)], [T_FUN_MIN(STUDENT.S_DATE)], [subquery(2)]), filter(nil), rowset=256 |
| exec_params_([STUDENT.CLASS(:0)], [T_FUN_MAX(STUDENT.S_DATE)(:1)], [STUDENT.CLASS(:2)], [T_FUN_MIN(STUDENT.S_DATE)(:3)]), onetime_exprs_(nil), init_plan_idxs_(nil), |
| use_batch=false |
| 1 - output([STUDENT.CLASS], [T_FUN_MAX(STUDENT.S_DATE)], [T_FUN_MIN(STUDENT.S_DATE)]), filter(nil), rowset=256 |
| group([STUDENT.CLASS]), agg_func([T_FUN_MAX(STUDENT.S_DATE)], [T_FUN_MIN(STUDENT.S_DATE)]) |
| 2 - output([STUDENT.CLASS], [STUDENT.S_DATE]), filter(nil), rowset=256 |
| access([STUDENT.CLASS], [STUDENT.S_DATE]), partitions(p0) |
| is_index_back=false, is_global_index=false, |
| range_key([STUDENT.CLASS], [STUDENT.S_DATE], [STUDENT.ID]), range(MIN,MIN,MIN ; MAX,MAX,MAX)always true |
| 3 - output([T_FUN_MAX(S2.NAME)]), filter(nil), rowset=256 |
| group(nil), agg_func([T_FUN_MAX(S2.NAME)]) |
| 4 - output([S2.NAME]), filter([ora_decode(cast(:0, VARCHAR2(1 BYTE)), cast(NULL, VARCHAR2(0 )), cast('bb', VARCHAR2(2 BYTE)), cast(:0, VARCHAR2(2 BYTE))) |
| = ora_decode(cast(S2.CLASS, VARCHAR2(1 BYTE)), cast(NULL, VARCHAR2(0 )), cast('bb', VARCHAR2(2 BYTE)), cast(S2.CLASS, VARCHAR2(2 BYTE)))]), rowset=256 |
| access([S2.ID], [S2.CLASS], [S2.NAME]), partitions(p0) |
| is_index_back=true, is_global_index=false, filter_before_indexback[true], |
| range_key([S2.S_DATE], [S2.CLASS], [S2.ID]), range(MIN,MIN,MIN ; MAX,MAX,MAX)always true, |
| range_cond([S2.S_DATE = :1]) |
| 5 - output([T_FUN_MIN(S2.NAME)]), filter(nil), rowset=256 |
| group(nil), agg_func([T_FUN_MIN(S2.NAME)]) |
| 6 - output([S2.NAME]), filter([ora_decode(cast(:2, VARCHAR2(1 BYTE)), cast(NULL, VARCHAR2(0 )), cast('bb', VARCHAR2(2 BYTE)), cast(:2, VARCHAR2(2 BYTE))) |
| = ora_decode(cast(S2.CLASS, VARCHAR2(1 BYTE)), cast(NULL, VARCHAR2(0 )), cast('bb', VARCHAR2(2 BYTE)), cast(S2.CLASS, VARCHAR2(2 BYTE)))]), rowset=256 |
| access([S2.ID], [S2.CLASS], [S2.NAME]), partitions(p0) |
| is_index_back=true, is_global_index=false, filter_before_indexback[true], |
| range_key([S2.S_DATE], [S2.CLASS], [S2.ID]), range(MIN,MIN,MIN ; MAX,MAX,MAX)always true, |
| range_cond([S2.S_DATE = :3]) |
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------+
38 rows in set (0.008 sec)
改成 left join 也是按照标量的逻辑,都比较简单。
SELECT s1.CLASS,
s1.MAX_S_DATE,
max(CASE WHEN s2.S_DATE = s1.MAX_S_DATE THEN s2.NAME END) max_name,
s1.MIN_S_DATE,
min(CASE WHEN s2.S_DATE = s1.MIN_S_DATE THEN s2.NAME END ) min_name
FROM (
SELECT
CLASS,
max(S_DATE) MAX_S_DATE,
min(S_DATE) MIN_S_DATE
FROM student
GROUP BY
CLASS
)s1 LEFT JOIN student s2 ON decode(s1.CLASS,null,'bb',s1.CLASS) = decode(s2.CLASS,null,'bb',s2.CLASS)
GROUP BY
s1.CLASS,
s1.MAX_S_DATE,
s1.MIN_S_DATE;
27 rows in set (0.213 sec)
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| Query Plan |
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| =================================================================================== |
| |ID|OPERATOR |NAME |EST.ROWS|EST.TIME(us)| |
| ----------------------------------------------------------------------------------- |
| |0 |HASH GROUP BY | |17 |200679 | |
| |1 |└─HASH OUTER JOIN | |65001 |193221 | |
| |2 | ├─SUBPLAN SCAN |S1 |26 |35450 | |
| |3 | │ └─MERGE GROUP BY | |26 |35450 | |
| |4 | │ └─TABLE FULL SCAN|STUDENT(IDX_CLASS_SDATE_STUDENT)|500001 |14409 | |
| |5 | └─TABLE FULL SCAN |S2 |500001 |22309 | |
| =================================================================================== |
| Outputs & filters: |
| ------------------------------------- |
| 0 - output([S1.CLASS], [S1.MAX_S_DATE], [T_FUN_MAX(CASE WHEN S2.S_DATE = S1.MAX_S_DATE THEN S2.NAME ELSE NULL END)], [S1.MIN_S_DATE], [T_FUN_MIN(CASE |
| WHEN S2.S_DATE = S1.MIN_S_DATE THEN S2.NAME ELSE NULL END)]), filter(nil), rowset=256 |
| group([S1.CLASS]), agg_func([T_FUN_MAX(CASE WHEN S2.S_DATE = S1.MAX_S_DATE THEN S2.NAME ELSE NULL END)], [T_FUN_MIN(CASE WHEN S2.S_DATE = S1.MIN_S_DATE |
| THEN S2.NAME ELSE NULL END)]) |
| 1 - output([S1.CLASS], [S2.S_DATE], [S2.NAME], [S1.MAX_S_DATE], [S1.MIN_S_DATE]), filter(nil), rowset=256 |
| equal_conds([ora_decode(cast(S1.CLASS, VARCHAR2(1 BYTE)), cast(NULL, VARCHAR2(0 )), cast('bb', VARCHAR2(2 BYTE)), cast(S1.CLASS, VARCHAR2(2 BYTE))) |
| = ora_decode(cast(S2.CLASS, VARCHAR2(1 BYTE)), cast(NULL, VARCHAR2(0 )), cast('bb', VARCHAR2(2 BYTE)), cast(S2.CLASS, VARCHAR2(2 BYTE)))]), other_conds(nil) |
| 2 - output([S1.CLASS], [S1.MAX_S_DATE], [S1.MIN_S_DATE]), filter(nil), rowset=256 |
| access([S1.CLASS], [S1.MAX_S_DATE], [S1.MIN_S_DATE]) |
| 3 - output([STUDENT.CLASS], [T_FUN_MAX(STUDENT.S_DATE)], [T_FUN_MIN(STUDENT.S_DATE)]), filter(nil), rowset=256 |
| group([STUDENT.CLASS]), agg_func([T_FUN_MAX(STUDENT.S_DATE)], [T_FUN_MIN(STUDENT.S_DATE)]) |
| 4 - output([STUDENT.CLASS], [STUDENT.S_DATE]), filter(nil), rowset=256 |
| access([STUDENT.CLASS], [STUDENT.S_DATE]), partitions(p0) |
| is_index_back=false, is_global_index=false, |
| range_key([STUDENT.CLASS], [STUDENT.S_DATE], [STUDENT.ID]), range(MIN,MIN,MIN ; MAX,MAX,MAX)always true |
| 5 - output([S2.CLASS], [S2.S_DATE], [S2.NAME]), filter(nil), rowset=256 |
| access([S2.CLASS], [S2.S_DATE], [S2.NAME]), partitions(p0) |
| is_index_back=false, is_global_index=false, |
| range_key([S2.ID]), range(MIN ; MAX)always true |
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------+
31 rows in set (0.005 sec)
SELECT
DEPARTMENT_ID,
HIRE_DATE,
MAX(FIRST_NAME) KEEP (DENSE_RANK LAST ORDER BY HIRE_DATE) over(PARTITION BY DEPARTMENT_ID) max_name,
MIN(FIRST_NAME) KEEP (DENSE_RANK FIRST ORDER BY HIRE_DATE) over(PARTITION BY DEPARTMENT_ID) min_name
FROM EMPLOYEES ;
107 rows in set (0.002 sec)
SELECT
e1.DEPARTMENT_ID,
e1.HIRE_DATE,
e2.max_name,
e2.min_name
FROM EMPLOYEES e1 LEFT JOIN (
SELECT DEPARTMENT_ID,
MAX(CASE WHEN max_rn = 1 THEN FIRST_NAME ELSE NULL END) max_name,
MIN(CASE WHEN min_rn = 1 THEN FIRST_NAME ELSE NULL END) min_name
FROM (
SELECT
FIRST_NAME,
HIRE_DATE,
DEPARTMENT_ID,
DENSE_RANK() OVER(PARTITION BY DEPARTMENT_ID ORDER BY HIRE_DATE DESC) max_rn,
DENSE_RANK() OVER(PARTITION BY DEPARTMENT_ID ORDER BY HIRE_DATE ) min_rn
FROM EMPLOYEES
)
GROUP BY DEPARTMENT_ID
) e2 ON // 最后关联
decode(e1.DEPARTMENT_ID, null, 'aaa', e1.DEPARTMENT_ID) =
decode(e2.DEPARTMENT_ID, null, 'aaa', e2.DEPARTMENT_ID);
107 rows in set (0.007 sec)
SELECT DEPARTMENT_ID,
HIRE_DATE,
(SELECT e2.max_name
FROM
(SELECT DEPARTMENT_ID,
max(FIRST_NAME) max_name
FROM
(SELECT x.*,
DENSE_RANK() OVER(PARTITION BY DEPARTMENT_ID
ORDER BY HIRE_DATE DESC) max_rn
FROM EMPLOYEES x )
WHERE max_rn = 1
GROUP BY DEPARTMENT_ID ) e2
WHERE decode(e1.department_id, null, 'aaa', e1.department_id) = decode(e2.department_id, null, 'aaa', e2.department_id) ) max_name,
(SELECT e2.min_name
FROM
(SELECT DEPARTMENT_ID,
min(FIRST_NAME) min_name
FROM
(SELECT x.*,
DENSE_RANK() OVER(PARTITION BY DEPARTMENT_ID
ORDER BY HIRE_DATE ) min_rn
FROM EMPLOYEES x )
WHERE min_rn = 1
GROUP BY DEPARTMENT_ID ) e2
WHERE decode(e1.department_id, null, 'aaa', e1.department_id) = decode(e2.department_id, null, 'aaa', e2.department_id) ) min_name
FROM EMPLOYEES e1;
107 rows in set (0.030 sec)
/* 改SQL 逻辑等价上面join sql, 如果会写join版本改成表量子查询是更简单的操作 */
rank() over() 函数会跳号,如果符合over()逻辑的数据有两条的话,那么这两条会并列第一,然后第二条数据会加二(即显示第三)。
这个函数在业务逻辑上比较少使用到,但是我们也可以尝试使用其他逻辑来实现rank() over() 函数的功能。
**** 注意:以下实现的rank() over() 逻辑的代码性能,会比原来rank() over() 的性能更差,这里只做功能实现,不考虑性能问题 ****
SELECT * FROM (
SELECT
FIRST_NAME,
DEPARTMENT_ID,
HIRE_DATE,
RANK() OVER(PARTITION BY DEPARTMENT_ID ORDER BY HIRE_DATE DESC) MAX_RN
FROM EMPLOYEES ) WHERE DEPARTMENT_ID = 80;
34 rows in set (0.004 sec)
+--------------------------------------------------------------------------------------------------------------------------------------------------------------+
| Query Plan |
+--------------------------------------------------------------------------------------------------------------------------------------------------------------+
| ======================================================== |
| |ID|OPERATOR |NAME |EST.ROWS|EST.TIME(us)| |
| -------------------------------------------------------- |
| |0 |WINDOW FUNCTION | |34 |42 | |
| |1 |└─SORT | |34 |16 | |
| |2 | └─TABLE FULL SCAN|EMPLOYEES|34 |10 | |
| ======================================================== |
| Outputs & filters: |
| ------------------------------------- |
| 0 - output([EMPLOYEES.FIRST_NAME], [EMPLOYEES.DEPARTMENT_ID], [EMPLOYEES.HIRE_DATE], [T_WIN_FUN_RANK()]), filter(nil), rowset=256 |
| win_expr(T_WIN_FUN_RANK()), partition_by(nil), order_by([EMPLOYEES.HIRE_DATE, DESC]), window_type(RANGE), upper(UNBOUNDED PRECEDING), lower(UNBOUNDED |
| FOLLOWING) |
| 1 - output([EMPLOYEES.FIRST_NAME], [EMPLOYEES.DEPARTMENT_ID], [EMPLOYEES.HIRE_DATE]), filter(nil), rowset=256 |
| sort_keys([EMPLOYEES.HIRE_DATE, DESC]) |
| 2 - output([EMPLOYEES.FIRST_NAME], [EMPLOYEES.DEPARTMENT_ID], [EMPLOYEES.HIRE_DATE]), filter([EMPLOYEES.DEPARTMENT_ID = 80]), rowset=256 |
| access([EMPLOYEES.FIRST_NAME], [EMPLOYEES.DEPARTMENT_ID], [EMPLOYEES.HIRE_DATE]), partitions(p0) |
| is_index_back=false, is_global_index=false, filter_before_indexback[false], |
| range_key([EMPLOYEES.EMPLOYEE_ID]), range(MIN ; MAX)always true |
+--------------------------------------------------------------------------------------------------------------------------------------------------------------+
18 rows in set (0.004 sec)
SELECT
e.FIRST_NAME,
e.DEPARTMENT_ID,
e.HIRE_DATE,
(
SELECT count(HIRE_DATE) + 1 FROM EMPLOYEES e1 WHERE
DECODE(e1.DEPARTMENT_ID,NULL,'8080',e1.DEPARTMENT_ID) = DECODE(e.DEPARTMENT_ID,NULL,'8080',e.DEPARTMENT_ID) AND
e1.HIRE_DATE > e.HIRE_DATE
) MAX_RN
FROM EMPLOYEES e WHERE e.DEPARTMENT_ID = 80;
/*
重点是在标量子查询内的 e1.HIRE_DATE > e.HIRE_DATE 逻辑,可以将 e1 表理解成一个滑动的窗口。
*/
34 rows in set (0.006 sec)
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| Query Plan |
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| ========================================================= |
| |ID|OPERATOR |NAME|EST.ROWS|EST.TIME(us)| |
| --------------------------------------------------------- |
| |0 |MERGE GROUP BY | |34 |29 | |
| |1 |└─NESTED-LOOP OUTER JOIN | |34 |22 | |
| |2 | ├─TABLE FULL SCAN |E |34 |11 | |
| |3 | └─MATERIAL | |1 |11 | |
| |4 | └─TABLE FULL SCAN |E1 |1 |11 | |
| ========================================================= |
| Outputs & filters: |
| ------------------------------------- |
| 0 - output([E.FIRST_NAME], [E.DEPARTMENT_ID], [E.HIRE_DATE], [T_FUN_COUNT(E1.HIRE_DATE) + 1]), filter(nil), rowset=256 |
| group([E.EMPLOYEE_ID]), agg_func([T_FUN_COUNT(E1.HIRE_DATE)]) |
| 1 - output([E.EMPLOYEE_ID], [E.FIRST_NAME], [E.DEPARTMENT_ID], [E.HIRE_DATE], [E1.HIRE_DATE]), filter(nil), rowset=256 |
| conds([E1.HIRE_DATE > E.HIRE_DATE]), nl_params_(nil), use_batch=false |
| 2 - output([E.EMPLOYEE_ID], [E.DEPARTMENT_ID], [E.FIRST_NAME], [E.HIRE_DATE]), filter([E.DEPARTMENT_ID = 80]), rowset=256 |
| access([E.EMPLOYEE_ID], [E.DEPARTMENT_ID], [E.FIRST_NAME], [E.HIRE_DATE]), partitions(p0) |
| is_index_back=false, is_global_index=false, filter_before_indexback[false], |
| range_key([E.EMPLOYEE_ID]), range(MIN ; MAX)always true |
| 3 - output([E1.HIRE_DATE]), filter(nil), rowset=256 |
| 4 - output([E1.HIRE_DATE]), filter([ora_decode(cast(E1.DEPARTMENT_ID, VARCHAR2(1048576 )), cast(NULL, VARCHAR2(0 )), cast('8080', VARCHAR2(40 BYTE)), |
| cast(E1.DEPARTMENT_ID, VARCHAR2(40 BYTE))) = ora_decode(cast(cast(80, NUMBER(4, 0)), VARCHAR2(1048576 )), cast(NULL, VARCHAR2(0 )), cast('8080', VARCHAR2(40 |
| BYTE)), cast(cast(80, NUMBER(4, 0)), VARCHAR2(40 BYTE)))]), rowset=256 |
| access([E1.DEPARTMENT_ID], [E1.HIRE_DATE]), partitions(p0) |
| is_index_back=false, is_global_index=false, filter_before_indexback[false], |
| range_key([E1.EMPLOYEE_ID]), range(MIN ; MAX)always true |
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------+
26 rows in set (0.006 sec)
会写标量子查询的情况下,改写成LEFT JOIN 是很简单的事,逻辑一样不再赘述。
SELECT
e.FIRST_NAME,
e.DEPARTMENT_ID,
e.HIRE_DATE,
count(e1.HIRE_DATE) + 1 MAX_RN
FROM EMPLOYEES e LEFT JOIN EMPLOYEES e1 ON (
DECODE(e1.DEPARTMENT_ID,NULL,'8080',e1.DEPARTMENT_ID) = DECODE(e.DEPARTMENT_ID,NULL,'8080',e.DEPARTMENT_ID) AND e1.HIRE_DATE > e.HIRE_DATE)
WHERE e.DEPARTMENT_ID = 80
GROUP BY
e.FIRST_NAME,
e.DEPARTMENT_ID,
e.HIRE_DATE;
34 rows in set (0.012 sec)
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| Query Plan |
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| ========================================================== |
| |ID|OPERATOR |NAME |EST.ROWS|EST.TIME(us)| |
| ---------------------------------------------------------- |
| |0 |HASH GROUP BY | |34 |49 | |
| |1 |└─NESTED-LOOP OUTER JOIN | |34 |33 | |
| |2 | ├─SUBPLAN SCAN |VIEW1|34 |22 | |
| |3 | │ └─HASH GROUP BY | |34 |22 | |
| |4 | │ └─TABLE FULL SCAN |E |34 |10 | |
| |5 | └─MATERIAL | |1 |11 | |
| |6 | └─SUBPLAN SCAN |VIEW2|1 |11 | |
| |7 | └─HASH GROUP BY | |1 |11 | |
| |8 | └─TABLE FULL SCAN|E1 |1 |11 | |
| ========================================================== |
| Outputs & filters: |
| ------------------------------------- |
| 0 - output([VIEW1.E.FIRST_NAME], [VIEW1.E.DEPARTMENT_ID], [VIEW1.E.HIRE_DATE], [T_FUN_COUNT_SUM(VIEW1.T_FUN_COUNT(*) * CASE WHEN VIEW2.T_FUN_COUNT(E1.HIRE_DATE) |
| IS NOT NULL THEN VIEW2.T_FUN_COUNT(E1.HIRE_DATE) ELSE 0 END) + 1]), filter(nil), rowset=256 |
| group([VIEW1.E.HIRE_DATE], [VIEW1.E.FIRST_NAME]), agg_func([T_FUN_COUNT_SUM(VIEW1.T_FUN_COUNT(*) * CASE WHEN VIEW2.T_FUN_COUNT(E1.HIRE_DATE) IS NOT |
| NULL THEN VIEW2.T_FUN_COUNT(E1.HIRE_DATE) ELSE 0 END)]) |
| 1 - output([VIEW1.E.HIRE_DATE], [VIEW1.E.FIRST_NAME], [VIEW1.E.DEPARTMENT_ID], [VIEW2.T_FUN_COUNT(E1.HIRE_DATE)], [VIEW1.T_FUN_COUNT(*)]), filter(nil), rowset=256 |
| conds([VIEW2.E1.HIRE_DATE > VIEW1.E.HIRE_DATE]), nl_params_(nil), use_batch=false |
| 2 - output([VIEW1.E.DEPARTMENT_ID], [VIEW1.E.HIRE_DATE], [VIEW1.E.FIRST_NAME], [VIEW1.T_FUN_COUNT(*)]), filter(nil), rowset=256 |
| access([VIEW1.E.DEPARTMENT_ID], [VIEW1.E.HIRE_DATE], [VIEW1.E.FIRST_NAME], [VIEW1.T_FUN_COUNT(*)]) |
| 3 - output([E.DEPARTMENT_ID], [E.HIRE_DATE], [E.FIRST_NAME], [T_FUN_COUNT(*)]), filter(nil), rowset=256 |
| group([E.HIRE_DATE], [E.FIRST_NAME]), agg_func([T_FUN_COUNT(*)]) |
| 4 - output([E.DEPARTMENT_ID], [E.HIRE_DATE], [E.FIRST_NAME]), filter([E.DEPARTMENT_ID = 80]), rowset=256 |
| access([E.DEPARTMENT_ID], [E.HIRE_DATE], [E.FIRST_NAME]), partitions(p0) |
| is_index_back=false, is_global_index=false, filter_before_indexback[false], |
| range_key([E.EMPLOYEE_ID]), range(MIN ; MAX)always true |
| 5 - output([VIEW2.T_FUN_COUNT(E1.HIRE_DATE)], [VIEW2.E1.HIRE_DATE]), filter(nil), rowset=256 |
| 6 - output([VIEW2.E1.HIRE_DATE], [VIEW2.T_FUN_COUNT(E1.HIRE_DATE)]), filter(nil), rowset=256 |
| access([VIEW2.E1.HIRE_DATE], [VIEW2.T_FUN_COUNT(E1.HIRE_DATE)]) |
| 7 - output([E1.HIRE_DATE], [T_FUN_COUNT(E1.HIRE_DATE)]), filter(nil), rowset=256 |
| group([E1.DEPARTMENT_ID], [E1.HIRE_DATE]), agg_func([T_FUN_COUNT(E1.HIRE_DATE)]) |
| 8 - output([E1.DEPARTMENT_ID], [E1.HIRE_DATE]), filter([ora_decode(cast(E1.DEPARTMENT_ID, VARCHAR2(1048576 )), cast(NULL, VARCHAR2(0 )), cast('8080', |
| VARCHAR2(40 BYTE)), cast(E1.DEPARTMENT_ID, VARCHAR2(40 BYTE))) = ora_decode(cast(cast(80, NUMBER(4, 0)), VARCHAR2(1048576 )), cast(NULL, VARCHAR2(0 )), |
| cast('8080', VARCHAR2(40 BYTE)), cast(cast(80, NUMBER(4, 0)), VARCHAR2(40 BYTE)))]), rowset=256 |
| access([E1.DEPARTMENT_ID], [E1.HIRE_DATE]), partitions(p0) |
| is_index_back=false, is_global_index=false, filter_before_indexback[false], |
| range_key([E1.EMPLOYEE_ID]), range(MIN ; MAX)always true |
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------+
40 rows in set (0.011 sec)
dense_rank() over() 函数不会跳号,如果符合over()逻辑的数据有两条的话,那么这两条会并列第一,然后第二条数据会递增加一(即显示第二)。
这个函数在业务逻辑上也比较少用到,但是比rank()用得多,但是我们也可以尝试使用其他逻辑来实现dense_rank() over() 函数的功能。
**** 注意:以下实现的dense_rank() over() 逻辑的代码性能,会比原来dense_rank() over() 的性能更差,这里只做功能实现,不考虑性能问题 ****
SELECT * FROM (
SELECT
FIRST_NAME,
DEPARTMENT_ID,
HIRE_DATE,
dense_rank() OVER(PARTITION BY DEPARTMENT_ID ORDER BY HIRE_DATE DESC) MAX_RN
FROM EMPLOYEES ) WHERE DEPARTMENT_ID = 80;
34 rows in set (0.001 sec)
+--------------------------------------------------------------------------------------------------------------------------------------------------------------+
| Query Plan |
+--------------------------------------------------------------------------------------------------------------------------------------------------------------+
| ======================================================== |
| |ID|OPERATOR |NAME |EST.ROWS|EST.TIME(us)| |
| -------------------------------------------------------- |
| |0 |WINDOW FUNCTION | |107 |115 | |
| |1 |└─PARTITION SORT | |107 |33 | |
| |2 | └─TABLE FULL SCAN|EMPLOYEES|107 |9 | |
| ======================================================== |
| Outputs & filters: |
| ------------------------------------- |
| 0 - output([EMPLOYEES.FIRST_NAME], [EMPLOYEES.DEPARTMENT_ID], [EMPLOYEES.HIRE_DATE], [T_WIN_FUN_DENSE_RANK()]), filter(nil), rowset=256 |
| win_expr(T_WIN_FUN_DENSE_RANK()), partition_by([EMPLOYEES.DEPARTMENT_ID]), order_by([EMPLOYEES.HIRE_DATE, DESC]), window_type(RANGE), upper(UNBOUNDED |
| PRECEDING), lower(UNBOUNDED FOLLOWING) |
| 1 - output([EMPLOYEES.FIRST_NAME], [EMPLOYEES.DEPARTMENT_ID], [EMPLOYEES.HIRE_DATE]), filter(nil), rowset=256 |
| sort_keys([HASH(EMPLOYEES.DEPARTMENT_ID), ASC], [EMPLOYEES.DEPARTMENT_ID, ASC], [EMPLOYEES.HIRE_DATE, DESC]) |
| 2 - output([EMPLOYEES.FIRST_NAME], [EMPLOYEES.DEPARTMENT_ID], [EMPLOYEES.HIRE_DATE]), filter(nil), rowset=256 |
| access([EMPLOYEES.FIRST_NAME], [EMPLOYEES.DEPARTMENT_ID], [EMPLOYEES.HIRE_DATE]), partitions(p0) |
| is_index_back=false, is_global_index=false, |
| range_key([EMPLOYEES.EMPLOYEE_ID]), range(MIN ; MAX)always true |
+--------------------------------------------------------------------------------------------------------------------------------------------------------------+
18 rows in set (0.004 sec)
SELECT
e.FIRST_NAME,
e.DEPARTMENT_ID,
e.HIRE_DATE,
(SELECT COUNT(DISTINCT HIRE_DATE) +1 FROM EMPLOYEES e1 WHERE DECODE(e1.DEPARTMENT_ID,NULL,'8080',e1.DEPARTMENT_ID) = DECODE(e.DEPARTMENT_ID,NULL,'8080',e.DEPARTMENT_ID) AND e1.HIRE_DATE > e.HIRE_DATE ) MAX_RN
FROM EMPLOYEES e WHERE DEPARTMENT_ID = 80 ;
/*
COUNT(DISTINCT HIRE_DATE) 逻辑是求 e1.HIRE_DATE > e.HIRE_DATE 符合这个逻辑的 e1表的 HIRE_DATE 数据,等价 dense_rank。
*/
34 rows in set (0.006 sec)
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| Query Plan |
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| ========================================================= |
| |ID|OPERATOR |NAME|EST.ROWS|EST.TIME(us)| |
| --------------------------------------------------------- |
| |0 |MERGE GROUP BY | |34 |29 | |
| |1 |└─NESTED-LOOP OUTER JOIN | |34 |22 | |
| |2 | ├─TABLE FULL SCAN |E |34 |11 | |
| |3 | └─MATERIAL | |1 |11 | |
| |4 | └─TABLE FULL SCAN |E1 |1 |11 | |
| ========================================================= |
| Outputs & filters: |
| ------------------------------------- |
| 0 - output([E.FIRST_NAME], [E.DEPARTMENT_ID], [E.HIRE_DATE], [T_FUN_COUNT(distinct E1.HIRE_DATE) + 1]), filter(nil), rowset=256 |
| group([E.EMPLOYEE_ID]), agg_func([T_FUN_COUNT(distinct E1.HIRE_DATE)]) |
| 1 - output([E.EMPLOYEE_ID], [E.FIRST_NAME], [E.DEPARTMENT_ID], [E.HIRE_DATE], [E1.HIRE_DATE]), filter(nil), rowset=256 |
| conds([E1.HIRE_DATE > E.HIRE_DATE]), nl_params_(nil), use_batch=false |
| 2 - output([E.EMPLOYEE_ID], [E.DEPARTMENT_ID], [E.FIRST_NAME], [E.HIRE_DATE]), filter([E.DEPARTMENT_ID = 80]), rowset=256 |
| access([E.EMPLOYEE_ID], [E.DEPARTMENT_ID], [E.FIRST_NAME], [E.HIRE_DATE]), partitions(p0) |
| is_index_back=false, is_global_index=false, filter_before_indexback[false], |
| range_key([E.EMPLOYEE_ID]), range(MIN ; MAX)always true |
| 3 - output([E1.HIRE_DATE]), filter(nil), rowset=256 |
| 4 - output([E1.HIRE_DATE]), filter([ora_decode(cast(E1.DEPARTMENT_ID, VARCHAR2(1048576 )), cast(NULL, VARCHAR2(0 )), cast('8080', VARCHAR2(40 BYTE)), |
| cast(E1.DEPARTMENT_ID, VARCHAR2(40 BYTE))) = ora_decode(cast(cast(80, NUMBER(4, 0)), VARCHAR2(1048576 )), cast(NULL, VARCHAR2(0 )), cast('8080', VARCHAR2(40 |
| BYTE)), cast(cast(80, NUMBER(4, 0)), VARCHAR2(40 BYTE)))]), rowset=256 |
| access([E1.DEPARTMENT_ID], [E1.HIRE_DATE]), partitions(p0) |
| is_index_back=false, is_global_index=false, filter_before_indexback[false], |
| range_key([E1.EMPLOYEE_ID]), range(MIN ; MAX)always true |
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------+
26 rows in set (0.006 sec)
会写标量子查询的情况下,改写成LEFT JOIN 是很简单的事,逻辑一样不再赘述。
SELECT
e.FIRST_NAME,
e.DEPARTMENT_ID,
e.HIRE_DATE,
count(DISTINCT e1.HIRE_DATE) + 1 MAX_RN
FROM EMPLOYEES e LEFT JOIN EMPLOYEES e1 ON (
DECODE(e1.DEPARTMENT_ID,NULL,'8080',e1.DEPARTMENT_ID) = DECODE(e.DEPARTMENT_ID,NULL,'8080',e.DEPARTMENT_ID) AND e1.HIRE_DATE > e.HIRE_DATE)
WHERE e.DEPARTMENT_ID = 80
GROUP BY
e.FIRST_NAME,
e.DEPARTMENT_ID,
e.HIRE_DATE;
34 rows in set (0.006 sec)
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| Query Plan |
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------+
| ===================================================== |
| |ID|OPERATOR |NAME|EST.ROWS|EST.TIME(us)| |
| ----------------------------------------------------- |
| |0 |MERGE GROUP BY | |34 |76 | |
| |1 |└─PARTITION SORT | |34 |70 | |
| |2 | └─HASH OUTER JOIN | |34 |62 | |
| |3 | ├─TABLE FULL SCAN|E |34 |10 | |
| |4 | └─TABLE FULL SCAN|E1 |107 |9 | |
| ===================================================== |
| Outputs & filters: |
| ------------------------------------- |
| 0 - output([E.FIRST_NAME], [E.DEPARTMENT_ID], [E.HIRE_DATE], [T_FUN_COUNT(distinct E1.HIRE_DATE) + 1]), filter(nil), rowset=256 |
| group([E.FIRST_NAME], [E.HIRE_DATE]), agg_func([T_FUN_COUNT(distinct E1.HIRE_DATE)]) |
| 1 - output([E.FIRST_NAME], [E.HIRE_DATE], [E.DEPARTMENT_ID], [E1.HIRE_DATE]), filter(nil), rowset=256 |
| sort_keys([HASH(E.FIRST_NAME, E.HIRE_DATE), ASC], [E.FIRST_NAME, ASC], [E.HIRE_DATE, ASC]) |
| 2 - output([E.FIRST_NAME], [E.HIRE_DATE], [E.DEPARTMENT_ID], [E1.HIRE_DATE]), filter(nil), rowset=256 |
| equal_conds([ora_decode(cast(E1.DEPARTMENT_ID, VARCHAR2(1048576 )), cast(NULL, VARCHAR2(0 )), cast('8080', VARCHAR2(40 BYTE)), cast(E1.DEPARTMENT_ID, |
| VARCHAR2(40 BYTE))) = ora_decode(cast(E.DEPARTMENT_ID, VARCHAR2(1048576 )), cast(NULL, VARCHAR2(0 )), cast('8080', VARCHAR2(40 BYTE)), cast(E.DEPARTMENT_ID, |
| VARCHAR2(40 BYTE)))]), other_conds([E1.HIRE_DATE > E.HIRE_DATE]) |
| 3 - output([E.DEPARTMENT_ID], [E.HIRE_DATE], [E.FIRST_NAME]), filter([E.DEPARTMENT_ID = 80]), rowset=256 |
| access([E.DEPARTMENT_ID], [E.HIRE_DATE], [E.FIRST_NAME]), partitions(p0) |
| is_index_back=false, is_global_index=false, filter_before_indexback[false], |
| range_key([E.EMPLOYEE_ID]), range(MIN ; MAX)always true |
| 4 - output([E1.DEPARTMENT_ID], [E1.HIRE_DATE]), filter(nil), rowset=256 |
| access([E1.DEPARTMENT_ID], [E1.HIRE_DATE]), partitions(p0) |
| is_index_back=false, is_global_index=false, |
| range_key([E1.EMPLOYEE_ID]), range(MIN ; MAX)always true |
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------+
27 rows in set (0.005 sec)
SQL语句虽然很简单,但是要培养出SQL思维可不是一件容易的事,还是得多看,多写,多思考。
这个是要通过不同的开发需求日积月累形成的思维逻辑,而不是一蹴而就。