半联结:是在两个数据集之间的联结,其中第一个数据庥中的数据行在决定是否返回时会根据在别一个数据集中出现或不出现至少一个相匹配的数据行来确定。
标准的内联结与半联结之间最主要的区别在于在半联结中,第1个数据集中的每一条记录只返回一次,而不管在第2个数据集中有几条匹配数据。这个定义表明这个查询的实际处理过程可以通过在找到第一个匹配以后马上停止处理该查询来进行优化。这种联结技术在oracle基于成本的优化器中当查询中又包含在in或exists子句中(或者包含在很少使用的与in同义的=any子句中)的子查询时是一种可选方案。
--in半联结
SELECT /* using in */ dept.department_name FROM hr.departments dept
WHERE dept.department_id IN (SELECT emp.department_id FROM hr.employees emp)
--exists半联结
SELECT /* using exists */ dept.department_name FROM hr.departments dept
WHERE EXISTS (SELECT NULL FROM hr.employees emp WHERE emp.department_id=dept.department_id);
这两个查询在功能上是等价的,也就是说如果输入相同,它们总是返回同样的数据集。
--exists和in的可替换语法--inner join
SELECT /* inner join */ dept.department_name
FROM hr.departments dept, hr.employees emp
WHERE dept.department_id=emp.department_id;
显示内联结在功能上与半联结并不是等价的,因为返回的行数不同。这里有很多重复的值,可以用distinct去重。
--exists和in的可替换语法--具有distinct的inner join
SELECT /* inner join with distinct */ DISTINCT dept.department_name
FROM hr.departments dept, hr.employees emp
WHERE dept.department_id=emp.department_id;
--exists和in的可替换语法--丑陋的交集
SELECT /* ugly intersect */ dept.department_name
FROM hr.departments dept,
(
SELECT department_id FROM hr.departments
INTERSECT
SELECT department_id FROM hr.employees
) b
WHERE b.department_id=dept.department_id;
--exists和in的可替换语法--any 子查询
SELECT /* any subquery */ dept.department_name
FROM hr.departments dept
WHERE dept.department_id = ANY (SELECT department_id FROM hr.employees emp);
关于any的版本,它就是in的一个可替换写法。
--半联结与distinct是不同的
SELECT /* SEMI using IN */ e.department_id
FROM hr.employees e
WHERE e.department_id IN (SELECT department_id FROM hr.departments);
SELECT /* inner join with distinct */ DISTINCT e.department_id
FROM hr.departments dept,hr.employees e
WHERE e.department_id=dept.department_id;
半联结与带distinct的内联结是不等价的。in/exists方式取出第一个集合中的每条记录,如果在第2个集合中至少有一条记录与之相匹配,则返回这个记录。因此,假设查询1返回的结果中有重复的值,结果集中就有可能会有重复值。distinct方式取出所有数据行,进行排序,然后将重复行舍弃掉。由此可以知道,distinct版本最终可能会多做很多工作,因为它没有机会提前从子查询中跳出。
使用exists语法还有另一个有必要提及的常见错误。如果使用exists,要确定子查询与外层查询是相关的。如果子查询没有涉及外层查询则是无意义的。
--使用exists常见错误--不相关查询
SELECT /* corrected */ e.department_id
FROM hr.employees e
WHERE EXISTS (SELECT dept.department_id FROM hr.departments dept
WHERE e.department_id=dept.department_id
);
SELECT /* not corrected */ e.department_id
FROM hr.employees e
WHERE EXISTS (SELECT dept.department_id FROM hr.departments dept);
SELECT /* non-correclated totally unrelated */ dept.department_id
FROM hr.departments dept
WHERE EXISTS(SELECT NULL FROM dual);
SELECT /* non-correclated empty subquery */ dept.department_id
FROM hr.departments dept
WHERE EXISTS(SELECT 'anything' FROM dual WHERE 1=2);
可见相关查询得到了我们想要的记录(也就是说,只有在第2个查询中有匹配行的数据)。显然,不相关子查询没有得到想要的结果。它们返回了第1个表中所有的记录,如果你直接写针对第1个表的查询也会得到这样的结果。从倒数第2个例子,具有对dual非相关的子查询,可以看出,不管子查询是什么,第一个表中的所有记录都会返回。最后一个例子说明当子查询没有任何记录返回时会发生什么,这种情况不会返回任何记录。
半联结的执行计划
Oracle中最常用的3种联结方法是嵌套循环,散列联结和合并联结。
SQL> set autotrace traceonly
SQL> --半联结的执行计划
SQL> SELECT dept.department_name
2 FROM hr.departments dept
3 WHERE dept.department_id IN (SELECT e.department_id FROM hr.employees e);
已选择11行。
执行计划
----------------------------------------------------------
Plan hash value: 2605691773
----------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
----------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 10 | 190 | 3 (0)| 00:00:01 |
| 1 | NESTED LOOPS SEMI | | 10 | 190 | 3 (0)| 00:00:01 |
| 2 | TABLE ACCESS FULL| DEPARTMENTS | 27 | 432 | 3 (0)| 00:00:01 |
|* 3 | INDEX RANGE SCAN | EMP_DEPARTMENT_IX | 41 | 123 | 0 (0)| 00:00:01 |
----------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
3 - access("DEPT"."DEPARTMENT_ID"="E"."DEPARTMENT_ID")
统计信息
----------------------------------------------------------
1 recursive calls
0 db block gets
11 consistent gets
0 physical reads
0 redo size
743 bytes sent via SQL*Net to client
520 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
11 rows processed
SQL> SELECT /* exists */ dept.department_name
2 FROM hr.departments dept
3 WHERE EXISTS(SELECT NULL FROM hr.employees emp WHERE emp.department_id=dept.department_id);
已选择11行。
执行计划
----------------------------------------------------------
Plan hash value: 2605691773
----------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
----------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 10 | 190 | 3 (0)| 00:00:01 |
| 1 | NESTED LOOPS SEMI | | 10 | 190 | 3 (0)| 00:00:01 |
| 2 | TABLE ACCESS FULL| DEPARTMENTS | 27 | 432 | 3 (0)| 00:00:01 |
|* 3 | INDEX RANGE SCAN | EMP_DEPARTMENT_IX | 41 | 123 | 0 (0)| 00:00:01 |
----------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
3 - access("EMP"."DEPARTMENT_ID"="DEPT"."DEPARTMENT_ID")
统计信息
----------------------------------------------------------
1 recursive calls
0 db block gets
11 consistent gets
0 physical reads
0 redo size
743 bytes sent via SQL*Net to client
520 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
11 rows processed
上面两个语句的确是用同样的方法来处理的执行计划是一致的,统计信息也是一致的。优化器能够并且将这两种形式的查询转换成同样的语句。
使用提示控制半联结执行计划
* semijon进行半联结,优化器选择使用哪种类型
* no_semijon不进行半联结
* nl_sj进行嵌套半联结,10起被弃用
* hash_sj进行散列半联结,10起被弃用
* merge_sg进行合并半联结,10起被弃用
--使用no_semijon提示的exists语句
SELECT /* exists no_semijoin */ dept.department_name
FROM hr.departments dept
WHERE EXISTS(SELECT /*+ no_semijoin */ NULL FROM hr.employees emp WHERE emp.department_id=dept.department_id);
set autotrace trace;
执行计划
----------------------------------------------------------
Plan hash value: 440241596
----------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
----------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 16 | 17 (0)| 00:00:01 |
|* 1 | FILTER | | | | | |
| 2 | TABLE ACCESS FULL| DEPARTMENTS | 27 | 432 | 3 (0)| 00:00:01 |
|* 3 | INDEX RANGE SCAN | EMP_DEPARTMENT_IX | 2 | 6 | 1 (0)| 00:00:01 |
----------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter( EXISTS (SELECT 0 FROM "HR"."EMPLOYEES" "EMP" WHERE
"EMP"."DEPARTMENT_ID"=:B1))
3 - access("EMP"."DEPARTMENT_ID"=:B1)
使用no_semijoin提示禁止优化器使用半联结,如期望那样,查询不再进行半联结,而是使用filter运算将两个行数据源结合起来。
实验级控制半联结执行计划
默认值为choose,允许优化器对所有半联结方法进行评估并选择它认为是最高效的方法。将参数设置为hash,merge或nested_loops就将优化器的选择限定为指定的联结方法。
--_always_semi_join的有效值
SELECT name_kspvld_values name,value_kspvld_values value FROM x$kspvld_values
WHERE name_kspvld_values LIKE NVL('&name',name_kspvld_values);
--输入_always_semi_join
SQL> --使用_always_semi_join将执行计划改变为nested_loops半联结
SQL> ALTER SESSION SET "_always_semi_join"=merge;
会话已更改。
SQL> SELECT /* using in */ dept.department_name
2 FROM hr.departments dept
3 WHERE dept.department_id IN (SELECT department_id FROM hr.employees emp);
已选择11行。
执行计划
----------------------------------------------------------
Plan hash value: 954076352
--------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost(%CPU)| Time |
--------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 10 | 190 | 4 (25)| 00:00:01 |
| 1 | MERGE JOIN SEMI | | 10 | 190 | 4 (25)| 00:00:01 |
| 2 | TABLE ACCESS BY INDEX ROWID| DEPARTMENTS | 27 | 432 | 2 (0)| 00:00:01 |
| 3 | INDEX FULL SCAN | DEPT_ID_PK | 27 | | 1 (0)| 00:00:01 |
|* 4 | SORT UNIQUE | | 107 | 321 | 2 (50)| 00:00:01 |
| 5 | INDEX FULL SCAN | EMP_DEPARTMENT_IX | 107 | 321 | 1 (0)| 00:00:01 |
--------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
4 - access("DEPT"."DEPARTMENT_ID"="DEPARTMENT_ID")
filter("DEPT"."DEPARTMENT_ID"="DEPARTMENT_ID")
SQL> ALTER SESSION SET "_always_semi_join"=nested_loops;
SQL> SELECT /* using in */ dept.department_name
2 FROM hr.departments dept
3 WHERE dept.department_id IN (SELECT department_id FROM hr.employees emp);
已选择11行。
执行计划
----------------------------------------------------------
Plan hash value: 2605691773
----------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
----------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 10 | 190 | 3 (0)| 00:00:01 |
| 1 | NESTED LOOPS SEMI | | 10 | 190 | 3 (0)| 00:00:01 |
| 2 | TABLE ACCESS FULL| DEPARTMENTS | 27 | 432 | 3 (0)| 00:00:01 |
|* 3 | INDEX RANGE SCAN | EMP_DEPARTMENT_IX | 41 | 123 | 0 (0)| 00:00:01 |
----------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
3 - access("DEPT"."DEPARTMENT_ID"="DEPARTMENT_ID")
关联结的限制条件
对于优化器选择使用半联结文档中,只说明了一个主要限制条件,11gR2中。优化器不会为任何包含or分支中的子查询选择半联结。在之前的oracle版本中,包含distinct关键字时也会禁用半联结,但现在己经没有这个限制了。
--在oracle 11gR2中禁用or分支中的半联结
SELECT /* exists with or */ dept.department_name
FROM hr.departments dept
WHERE 1=2 OR EXISTS (SELECT NULL FROM hr.employees emp WHERE emp.department_id=dept.department_id);
半联结的必要条件
半联结是一种可以极大提升某些查询性能的优化方法。基于成器的优化器决定选用半联结的必要条件:
- 语句必须使用关键字in(=ANY)或exists
- 语句必须在in或exists子句中有子查询
- 如果语句使用exists语法,则必须使用相关子查询
- in和exists子句不能包含在or分支中
反联结
反联结返回谓语左侧的数据行,如果在谓语右侧没有对应的数据行存在的话,它返回在右侧的子查询中没有匹配的数据行。
--反联结
SELECT * FROM hr.employees WHERE department_id NOT IN
(SELECT department_id FROM hr.departments WHERE location_id=170)
ORDER BY last_name;
--标准的not in和not exists
SELECT /* not in */ department_name
FROM hr.departments dept
WHERE department_id NOT IN (SELECT department_id FROM hr.employees emp);
SELECT /* not exist */ department_name
FROM hr.departments dept
WHERE NOT EXISTS (SELECT NULL FROM hr.employees emp WHERE dept.department_id=emp.department_id);
如果向not in运算符返回了一个空值,则整个查询不会返回任何记录。not in运算符就是!=ANY。
假设你的需求是即使子查询返回空值也返回相应记录,可以有下面的这些选择。
- 在子查询所返回的列上应用一个nvl函数
- 在子查询中加上is not null谓语
- 实现not null约束
- 不使用not in(使用不需要关心空值的not exists形式)
--避免not in中的空值
SELECT /* in with nvl */ department_name
FROM hr.departments dept
WHERE department_id NOT IN (SELECT nvl(department_id,-1) FROM hr.employees emp);
SELECT /* in with not null */ department_name
FROM hr.departments dept
WHERE department_id NOT IN (SELECT department_id FROM hr.employees emp WHERE department_id IS NOT NULL);
--not in和not exists的替代写法
SELECT /* minus */ department_name
FROM hr.departments
WHERE department_id IN (
SELECT department_id FROM hr.departments
MINUS
SELECT department_id FROM hr.employees
);
SELECT /* left outer */ department_name
FROM hr.departments dept LEFT OUTER JOIN
hr.employees emp ON dept.department_id=emp.department_id
WHERE emp.department_id IS NULL;
SELECT /* left outer old (+) */ department_name
FROM hr.departments dept, hr.employees emp
WHERE dept.department_id=emp.department_id(+)
AND emp.department_id IS NULL;
反联结执行计划
与半联结一样,反联结也是一种可以应用到嵌套循环联结,散列联结或合并联结的优化方法。同时还要记信它是一种允许当子查询中找到第一条匹配记录时停止处理的优化方法。
SQL> --反联结执行计划
SQL> SELECT /* not in */ department_name
2 FROM hr.departments dept
3 WHERE dept.department_id NOT IN (SELECT department_id FROM hr.employees emp);
未选定行
执行计划
----------------------------------------------------------
Plan hash value: 4201340344
---------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
---------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 17 | 323 | 6 (17)| 00:00:01 |
| 1 | MERGE JOIN ANTI NA | | 17 | 323 | 6 (17)| 00:00:01 |
| 2 | SORT JOIN | | 27 | 432 | 2 (0)| 00:00:01 |
| 3 | TABLE ACCESS BY INDEX ROWID| DEPARTMENTS | 27 | 432 | 2 (0)| 00:00:01 |
| 4 | INDEX FULL SCAN | DEPT_ID_PK | 27 | | 1 (0)| 00:00:01 |
|* 5 | SORT UNIQUE | | 107 | 321 | 4 (25)| 00:00:01 |
| 6 | TABLE ACCESS FULL | EMPLOYEES | 107 | 321 | 3 (0)| 00:00:01 |
SQL> SELECT /* not exists */ department_name
2 FROM hr.departments dept
3 WHERE NOT EXISTS (SELECT NULL FROM hr.employees emp WHERE emp.department_id=dept.department_id);
已选择16行。
执行计划
----------------------------------------------------------
Plan hash value: 3082375452
----------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
----------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 17 | 323 | 3 (0)| 00:00:01 |
| 1 | NESTED LOOPS ANTI | | 17 | 323 | 3 (0)| 00:00:01 |
| 2 | TABLE ACCESS FULL| DEPARTMENTS | 27 | 432 | 3 (0)| 00:00:01 |
|* 3 | INDEX RANGE SCAN | EMP_DEPARTMENT_IX | 41 | 123 | 0 (0)| 00:00:01 |
注意,NOT EXISTS语句生成了嵌套循环反联结(NESTED LOOPS ANTI)执行计划而not in 语句生成了合并反联结(MERGE JOIN ANTI NA)执行联结。
SQL> set echo on
SQL> @F:\bjc-study\sql\flush_pool
alter system flush shared_pool;
SQL> @F:\bjc-study\sql\anti_ex2
set echo on
SELECT /* in */ dept.department_name
FROM hr.departments dept
WHERE dept.department_id IN (SELECT e.department_id FROM hr.employees e);
DEPARTMENT_NAME
------------------------------
Administration
Marketing
Purchasing
Human Resources
Shipping
IT
Public Relations
Sales
Executive
Finance
Accounting
11 rows selected
SELECT /* in with nvl */ department_name
FROM hr.departments dept
WHERE department_id NOT IN (SELECT nvl(department_id,-1) FROM hr.employees emp);
DEPARTMENT_NAME
------------------------------
Treasury
Corporate Tax
Control And Credit
Shareholder Services
Benefits
Manufacturing
Construction
Contracting
Operations
IT Support
NOC
IT Helpdesk
Government Sales
Retail Sales
Recruiting
Payroll
16 rows selected
SELECT /* in with not null */ department_name
FROM hr.departments dept
WHERE department_id NOT IN (SELECT department_id FROM hr.employees emp WHERE department_id IS NOT NULL);
DEPARTMENT_NAME
------------------------------
Treasury
Corporate Tax
Control And Credit
Shareholder Services
Benefits
Manufacturing
Construction
Contracting
Operations
IT Support
NOC
IT Helpdesk
Government Sales
Retail Sales
Recruiting
Payroll
16 rows selected
SELECT /* exists */ dept.department_name
FROM hr.departments dept
WHERE EXISTS(SELECT NULL FROM hr.employees emp WHERE emp.department_id=dept.department_id);
DEPARTMENT_NAME
------------------------------
Administration
Marketing
Purchasing
Human Resources
Shipping
IT
Public Relations
Sales
Executive
Finance
Accounting
11 rows selected
SQL> set echo off
SQL> set echo on
SQL> @F:\bjc-study\sql\fsp
SELECT DISTINCT s.SQL_ID,
s.CHILD_NUMBER,
s.PLAN_HASH_VALUE plan_hash,
sql_text,--p.OPTIONS,
--DECODE(p.OPTIONS,'SEMI',p.OPERATION||' '||p.OPTIONS,NULL) JOIN
CASE WHEN p.OPTIONS LIKE '%SEMI%' OR p.OPTIONS LIKE '%ANTI%' THEN
p.OPERATION||' '||p.OPTIONS
END JOIN
FROM v$sql s,v$sql_plan p
WHERE s.sql_id=p.sql_id
AND s.CHILD_NUMBER=p.CHILD_NUMBER
AND UPPER(s.SQL_TEXT) LIKE UPPER(NVL('&sql_text','%department%'))
AND s.SQL_TEXT NOT LIKE '%FROM v$sql s%'
AND s.SQL_ID LIKE NVL('&sql_id',s.SQL_ID)
ORDER BY 1,2,3;
SQL_ID CHILD_NUMBER PLAN_HASH SQL_TEXT JOIN
------------- ------------ ---------- -------------------------------------------------------------------------------- --------------------------------------------------------------------------------
38t336psnuanq 0 3082375452 SELECT /* in with not null */ department_name FROM hr.departments dept WHERE dep NESTED LOOPS ANTI
38t336psnuanq 0 3082375452 SELECT /* in with not null */ department_name FROM hr.departments dept WHERE dep
4kwptwjxt4dr1 0 2605691773 SELECT /* exists */ dept.department_name FROM hr.departments dept WHERE EXISTS(S NESTED LOOPS SEMI
4kwptwjxt4dr1 0 2605691773 SELECT /* exists */ dept.department_name FROM hr.departments dept WHERE EXISTS(S
6gw559yrvghu2 0 2605691773 SELECT /* in */ dept.department_name FROM hr.departments dept WHERE dept.departm NESTED LOOPS SEMI
6gw559yrvghu2 0 2605691773 SELECT /* in */ dept.department_name FROM hr.departments dept WHERE dept.departm
93sq6g19gj5ax 0 3822487693 SELECT /* in with nvl */ department_name FROM hr.departments dept WHERE departme MERGE JOIN ANTI
93sq6g19gj5ax 0 3822487693 SELECT /* in with nvl */ department_name FROM hr.departments dept WHERE departme
8 rows selected
SQL> @F:\bjc-study\sql\anti_ex3
SELECT /* not exists */ dept.department_name
FROM hr.departments dept
WHERE NOT EXISTS (SELECT NULL FROM hr.employees emp WHERE emp.department_id=dept.department_id);
DEPARTMENT_NAME
------------------------------
Treasury
Corporate Tax
Control And Credit
Shareholder Services
Benefits
Manufacturing
Construction
Contracting
Operations
IT Support
NOC
IT Helpdesk
Government Sales
Retail Sales
Recruiting
Payroll
16 rows selected
SELECT /* not in not null */ dept.department_name
FROM hr.departments dept
WHERE dept.department_id NOT IN (SELECT emp.department_id FROM hr.employees emp WHERE emp.department_id IS NOT NULL);
DEPARTMENT_NAME
------------------------------
Treasury
Corporate Tax
Control And Credit
Shareholder Services
Benefits
Manufacturing
Construction
Contracting
Operations
IT Support
NOC
IT Helpdesk
Government Sales
Retail Sales
Recruiting
Payroll
16 rows selected
SELECT /* left outer */ dept.department_name
FROM hr.departments dept LEFT OUTER JOIN
hr.employees emp ON dept.department_id=emp.department_id
WHERE emp.department_id IS NULL;
DEPARTMENT_NAME
------------------------------
Treasury
Corporate Tax
Control And Credit
Shareholder Services
Benefits
Manufacturing
Construction
Contracting
Operations
IT Support
NOC
IT Helpdesk
Government Sales
Retail Sales
Recruiting
Payroll
16 rows selected
SELECT /* left outer old (+) */ dept.department_name
FROM hr.departments dept ,
hr.employees emp WHERE dept.department_id=emp.department_id(+)
AND emp.department_id IS NULL;
DEPARTMENT_NAME
------------------------------
Treasury
Corporate Tax
Control And Credit
Shareholder Services
Benefits
Manufacturing
Construction
Contracting
Operations
IT Support
NOC
IT Helpdesk
Government Sales
Retail Sales
Recruiting
Payroll
16 rows selected
SELECT /* minus */ dept.department_name
FROM hr.departments dept WHERE dept.department_id IN
(
SELECT dept.department_id FROM hr.departments dept
MINUS
SELECT emp.department_id FROM hr.employees emp
);
DEPARTMENT_NAME
------------------------------
Treasury
Corporate Tax
Control And Credit
Shareholder Services
Benefits
Manufacturing
Construction
Contracting
Operations
IT Support
NOC
IT Helpdesk
Government Sales
Retail Sales
Recruiting
Payroll
16 rows selected
SQL> @F:\bjc-study\sql\fsp
SELECT DISTINCT s.SQL_ID,
s.CHILD_NUMBER,
s.PLAN_HASH_VALUE plan_hash,
sql_text,--p.OPTIONS,
--DECODE(p.OPTIONS,'SEMI',p.OPERATION||' '||p.OPTIONS,NULL) JOIN
CASE WHEN p.OPTIONS LIKE '%SEMI%' OR p.OPTIONS LIKE '%ANTI%' THEN
p.OPERATION||' '||p.OPTIONS
END JOIN
FROM v$sql s,v$sql_plan p
WHERE s.sql_id=p.sql_id
AND s.CHILD_NUMBER=p.CHILD_NUMBER
AND UPPER(s.SQL_TEXT) LIKE UPPER(NVL('&sql_text','%department%'))
AND s.SQL_TEXT NOT LIKE '%FROM v$sql s%'
AND s.SQL_ID LIKE NVL('&sql_id',s.SQL_ID)
ORDER BY 1,2,3;
SQL_ID CHILD_NUMBER PLAN_HASH SQL_TEXT JOIN
------------- ------------ ---------- -------------------------------------------------------------------------------- --------------------------------------------------------------------------------
1suh9p55gtnz0 0 3082375452 SELECT /* not exists */ dept.department_name FROM hr.departments dept WHERE NOT NESTED LOOPS ANTI
1suh9p55gtnz0 0 3082375452 SELECT /* not exists */ dept.department_name FROM hr.departments dept WHERE NOT
5k7wv14nwckcu 0 3082375452 SELECT /* left outer */ dept.department_name FROM hr.departments dept LEFT OUTER NESTED LOOPS ANTI
5k7wv14nwckcu 0 3082375452 SELECT /* left outer */ dept.department_name FROM hr.departments dept LEFT OUTER
9t89ttfggqtyb 0 3082375452 SELECT /* not in not null */ dept.department_name FROM hr.departments dept WHERE NESTED LOOPS ANTI
9t89ttfggqtyb 0 3082375452 SELECT /* not in not null */ dept.department_name FROM hr.departments dept WHERE
b5fas38b76scf 0 2972564128 SELECT /* minus */ dept.department_name FROM hr.departments dept WHERE dept.depa
cfgsmt66bfskj 0 3082375452 SELECT /* left outer old (+) */ dept.department_name FROM hr.departments dept , NESTED LOOPS ANTI
cfgsmt66bfskj 0 3082375452 SELECT /* left outer old (+) */ dept.department_name FROM hr.departments dept ,
9 rows selected
控制反联结的执行计划
有以下几个提示可用:
- antijoin--进行反联结,优化器来决定具体类型
- use_anti--antijoin提示的旧版本
- nl_aj--进行嵌套循环反联结(自10g起被弃用)
- hash_aj--进行散列反联结(自10g起被弃用)
- merge_aj--进行合并反联结(自10g起被弃用)
SQL> set autotrace traceonly exp
SQL> @F:\bjc-study\sql\anti_ex4.sql
SQL> SELECT /* in */ dept.department_name
2 FROM hr.departments dept
3 WHERE dept.department_id NOT IN (SELECT /*+ nl_aj */ e.department_id FROM hr.employees e);
执行计划
----------------------------------------------------------
Plan hash value: 4201340344
---------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
---------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 17 | 323 | 6 (17)| 00:00:01 |
| 1 | MERGE JOIN ANTI NA | | 17 | 323 | 6 (17)| 00:00:01 |
| 2 | SORT JOIN | | 27 | 432 | 2 (0)| 00:00:01 |
| 3 | TABLE ACCESS BY INDEX ROWID| DEPARTMENTS | 27 | 432 | 2 (0)| 00:00:01 |
| 4 | INDEX FULL SCAN | DEPT_ID_PK | 27 | | 1 (0)| 00:00:01 |
|* 5 | SORT UNIQUE | | 107 | 321 | 4 (25)| 00:00:01 |
| 6 | TABLE ACCESS FULL | EMPLOYEES | 107 | 321 | 3 (0)| 00:00:01 |
---------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
5 - access("DEPT"."DEPARTMENT_ID"="E"."DEPARTMENT_ID")
filter("DEPT"."DEPARTMENT_ID"="E"."DEPARTMENT_ID")
SQL>
SQL> SELECT /* exists */ dept.department_name
2 FROM hr.departments dept
3 WHERE NOT EXISTS(SELECT /*+ nl_aj */ NULL FROM hr.employees emp WHERE emp.department_id=dept.department_id);
执行计划
----------------------------------------------------------
Plan hash value: 3082375452
----------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
----------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 17 | 323 | 3 (0)| 00:00:01 |
| 1 | NESTED LOOPS ANTI | | 17 | 323 | 3 (0)| 00:00:01 |
| 2 | TABLE ACCESS FULL| DEPARTMENTS | 27 | 432 | 3 (0)| 00:00:01 |
|* 3 | INDEX RANGE SCAN | EMP_DEPARTMENT_IX | 41 | 123 | 0 (0)| 00:00:01 |
----------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
3 - access("EMP"."DEPARTMENT_ID"="DEPT"."DEPARTMENT_ID")
在实例级控制反联结执行计划
还有一些参数会影响优化器对于反联结的选择
- _always_anti_join
- _gs_anti_semi_join_allowed
- _optimizer_null_aware_antijoin
- _optimizer_outer_to_anti_enabled
最主要的需要关注的参数是_always_anti_join,其行为与_always_semi_join相同。
SQL> @F:\bjc-study\sql\flush_pool
alter system flush shared_pool;
System altered
SQL> @F:\bjc-study\sql\anti_ex5.sql
SELECT /* exists */ dept.department_name
FROM hr.departments dept
WHERE NOT EXISTS(SELECT NULL FROM hr.employees emp WHERE emp.department_id=dept.department_id);
DEPARTMENT_NAME
------------------------------
Treasury
Corporate Tax
Control And Credit
Shareholder Services
Benefits
Manufacturing
Construction
Contracting
Operations
IT Support
NOC
IT Helpdesk
Government Sales
Retail Sales
Recruiting
Payroll
16 rows selected
SELECT /* exists with hint */ dept.department_name
FROM hr.departments dept
WHERE NOT EXISTS(SELECT /*+ hash_aj */ NULL FROM hr.employees emp WHERE emp.department_id=dept.department_id);
DEPARTMENT_NAME
------------------------------
NOC
Manufacturing
Government Sales
IT Support
Benefits
Shareholder Services
Retail Sales
Control And Credit
Recruiting
Operations
Treasury
Payroll
Corporate Tax
Construction
Contracting
IT Helpdesk
16 rows selected
SELECT /* in */ dept.department_name
FROM hr.departments dept
WHERE dept.department_id NOT IN (SELECT e.department_id FROM hr.employees e);
DEPARTMENT_NAME
------------------------------
SELECT /* in */ dept.department_name
FROM hr.departments dept
WHERE dept.department_id NOT IN (SELECT e.department_id FROM hr.employees e);
DEPARTMENT_NAME
------------------------------
SQL> alter session set "_optimizer_null_aware_antijoin"=false;
Session altered
SQL>
SQL> SELECT /* in with AAJ=OFF */ department_name
SELECT /* in with AAJ=OFF */ department_name
2 FROM hr.departments dept
FROM hr.departments dept
3 WHERE dept.department_id NOT IN (SELECT department_id FROM hr.employees emp);
WHERE dept.department_id NOT IN (SELECT department_id FROM hr.employees emp);
DEPARTMENT_NAME
------------------------------
SQL> alter session set "_optimizer_null_aware_antijoin"=true;
Session altered
SQL> set echo off
SQL> @F:\bjc-study\sql\fsp
SQL_ID CHILD_NUMBER PLAN_HASH SQL_TEXT JOIN
------------- ------------ ---------- -------------------------------------------------------------------------------- --------------------------------------------------------------------------------
3hnu1rv8r2nt9 0 3082375452 SELECT /* exists */ dept.department_name FROM hr.departments dept WHERE NOT EXIS NESTED LOOPS ANTI
3hnu1rv8r2nt9 0 3082375452 SELECT /* exists */ dept.department_name FROM hr.departments dept WHERE NOT EXIS
3rv1dbdvj3cjb 0 3587451639 SELECT /* exists with hint */ dept.department_name FROM hr.departments dept WHER HASH JOIN ANTI
3rv1dbdvj3cjb 0 3587451639 SELECT /* exists with hint */ dept.department_name FROM hr.departments dept WHER
f5yk002qrxs94 0 4201340344 SELECT /* in */ dept.department_name FROM hr.departments dept WHERE dept.departm MERGE JOIN ANTI NA
f5yk002qrxs94 0 4201340344 SELECT /* in */ dept.department_name FROM hr.departments dept WHERE dept.departm
fyjby9za2gxqz 0 3416340233 SELECT /* in with AAJ=OFF */ department_name FROM hr.departments dept WHERE dept
7 rows selected
反联结限制条件
与半联结一样,如果子查询是在where子句的or分支中则不能进行反联结转换。
SQL> @F:\bjc-study\sql\anti_ex6.sql
SQL> SET autotrace TRACE EXP;
SQL>
SQL> SELECT /* not in */ department_name
2 FROM hr.departments dept
3 WHERE dept.department_id NOT IN (SELECT department_id FROM hr.employees emp);
执行计划
----------------------------------------------------------
Plan hash value: 4201340344
---------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU
)| Time |
---------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 17 | 323 | 6 (17)| 00:00:01 |
| 1 | MERGE JOIN ANTI NA | | 17 | 323 | 6 (17)| 00:00:01 |
| 2 | SORT JOIN | | 27 | 432 | 2 (0)| 00:00:01 |
| 3 | TABLE ACCESS BY INDEX ROWID| DEPARTMENTS | 27 | 432 | 2 (0)| 00:00:01 |
| 4 | INDEX FULL SCAN | DEPT_ID_PK | 27 | | 1 (0)| 00:00:01 |
|* 5 | SORT UNIQUE | | 107 | 321 | 4 (25)| 00:00:01 |
| 6 | TABLE ACCESS FULL | EMPLOYEES | 107 | 321 | 3 (0)| 00:00:01 |
---------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
5 - access("DEPT"."DEPARTMENT_ID"="DEPARTMENT_ID")
filter("DEPT"."DEPARTMENT_ID"="DEPARTMENT_ID")
SQL>
SQL> SELECT /* nvl */ department_name
2 FROM hr.departments dept
3 WHERE department_id NOT IN (SELECT nvl(department_id,'-10') FROM hr.employees emp);
执行计划
----------------------------------------------------------
Plan hash value: 3822487693
--------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 17 | 323 | 6 (17)| 00:00:01 |
| 1 | MERGE JOIN ANTI | | 17 | 323 | 6 (17)| 00:00:01 |
| 2 | TABLE ACCESS BY INDEX ROWID| DEPARTMENTS | 27 | 432 | 2 (0)| 00:00:01 |
| 3 | INDEX FULL SCAN | DEPT_ID_PK | 27 | | 1 (0)| 00:00:01 |
|* 4 | SORT UNIQUE | | 107 | 321 | 4 (25)| 00:00:01 |
| 5 | TABLE ACCESS FULL | EMPLOYEES | 107 | 321 | 3 (0)| 00:00:01 |
--------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
4 - access("DEPARTMENT_ID"=NVL("DEPARTMENT_ID",(-10)))
filter("DEPARTMENT_ID"=NVL("DEPARTMENT_ID",(-10)))
反联结的必要条件
这些必要条件是oracle产生反联结的最可能的方法:
- 语句必须使用not in(!= all)或not exists
- 语句必须在not in或not exists子句中有一个子查询
- not in或not exists子句不能包含在or分支中
- not exists子句中的子查询必须与外层查询相关
小结:半联结和反联结是优化器可以应用到许多常见联结方法中的选项。这两个优化选项的基本思想就是将正常的散列,合并或嵌套循环联结的处理过程变短。在一些情况下,半联结和反联结可能极大地提高性能。在很多种构建SQL语句的方法可以使得优化器使用这些选项。最常见的是使用in和exists关键字。’