您好,登錄后才能下訂單哦!
swap_join_inputs是針對哈希連接的hint,它的含義是讓優(yōu)化器交換原哈希連接的驅(qū)動表和被驅(qū)動表的順序,即在依然走哈希連接的情況下讓原哈希連接的驅(qū)動表變被驅(qū)動表,讓原哈希連接的被驅(qū)動表變?yōu)轵?qū)動表。
注意,在swap_join_inputs hint中指定的目標(biāo)表應(yīng)該是原哈希連接中的被驅(qū)動表,否則oracle會忽略該hint。
/*+ swap_join_inputs(原哈希連接的被驅(qū)動表) */
其使用范例如下:
select /*+ leading(dept) use_hash(emp) swap_join_intputs(emp) */ * from emp,dept where emp.deptno=dept.deptno
測試案例:
SCOTT@ORA12C> create table t1 as select * from dba_objects where rownum<2; Table created. SCOTT@ORA12C> create table t2 as select * from dba_objects where rownum<12; Table created. SCOTT@ORA12C> create table t3 as select * from dba_objects where rownum<22; Table created.
收集統(tǒng)計信息:
SCOTT@ORA12C> exec dbms_stats.gather_table_stats(ownname => 'SCOTT',tabname => 'T1',estimate_percent => 100,cascade => true,method_opt => 'for all columns size 1',no_invalidate => false); PL/SQL procedure successfully completed. SCOTT@ORA12C> exec dbms_stats.gather_table_stats(ownname => 'SCOTT',tabname => 'T2',estimate_percent => 100,cascade => true,method_opt => 'for all columns size 1',no_invalidate => false); PL/SQL procedure successfully completed. SCOTT@ORA12C> exec dbms_stats.gather_table_stats(ownname => 'SCOTT',tabname => 'T3',estimate_percent => 100,cascade => true,method_opt => 'for all columns size 1',no_invalidate => false); PL/SQL procedure successfully completed.
3個表的記錄如下:
SCOTT@ORA12C> select count(*) from t1; COUNT(*) ----------------- 1 1 row selected. SCOTT@ORA12C> select count(*) from t2; COUNT(*) ----------------- 11 1 row selected. SCOTT@ORA12C> select count(*) from t3; COUNT(*) ----------------- 21 1 row selected.
現(xiàn)在我們來讓表T2和T3做哈希連接,由于T3表的記錄數(shù)比T2表的記錄數(shù)多,所以這里指定T3為哈希連接的被驅(qū)動表:
select /*+ ordered use_hash(t3) */ t2.object_name,t3.object_type 2 from t2,t3 where t2.object_id=t3.object_id; Execution Plan ---------------------------------------------------------- Plan hash value: 1730954469 --------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | --------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 11 | 220 |6 (0)| 00:00:01 | |* 1 | HASH JOIN | | 11 | 220 |6 (0)| 00:00:01 | | 2 | TABLE ACCESS FULL| T2 | 11 | 110 |3 (0)| 00:00:01 | | 3 | TABLE ACCESS FULL| T3 | 21 | 210 |3 (0)| 00:00:01 | --------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 1 - access("T2"."OBJECT_ID"="T3"."OBJECT_ID")
可以看到,上述SQL的執(zhí)行計劃現(xiàn)在走的是哈希連接,并且被驅(qū)動表示表T3.
如果我們想讓哈希連接的被驅(qū)動表由T3變成T2,可以在上述sql加入swap_join_inputs hint:
select /*+ ordered use_hash(t3) swap_join_inputs(t3) */ t2.object_name,t3.object_type 2 from t2,t3 where t2.object_id=t3.object_id; Execution Plan ---------------------------------------------------------- Plan hash value: 1723280936 --------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | --------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 11 | 220 |6 (0)| 00:00:01 | |* 1 | HASH JOIN | | 11 | 220 |6 (0)| 00:00:01 | | 2 | TABLE ACCESS FULL| T3 | 21 | 210 |3 (0)| 00:00:01 | | 3 | TABLE ACCESS FULL| T2 | 11 | 110 |3 (0)| 00:00:01 | --------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 1 - access("T2"."OBJECT_ID"="T3"."OBJECT_ID")
用leading(t3) use_hash(t2)也可以同樣達到目的:
select /*+ leading(t3) use_hash(t2) */ t2.object_name,t3.object_type 2 from t2,t3 where t2.object_id=t3.object_id; Execution Plan ---------------------------------------------------------- Plan hash value: 1723280936 --------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | --------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 11 | 220 |6 (0)| 00:00:01 | |* 1 | HASH JOIN | | 11 | 220 |6 (0)| 00:00:01 | | 2 | TABLE ACCESS FULL| T3 | 21 | 210 |3 (0)| 00:00:01 | | 3 | TABLE ACCESS FULL| T2 | 11 | 110 |3 (0)| 00:00:01 | --------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 1 - access("T2"."OBJECT_ID"="T3"."OBJECT_ID")
由此可見在兩個表關(guān)聯(lián)的時候,可以用其他hint代替swap_join_inputs來達到相同的目的:
那么多表關(guān)聯(lián)呢:
select /*+ ordered use_hash(t3) */ t1.owner,t2.object_name,t3.object_type 2 from t2,t3,t1 where t2.object_id=t3.object_id and t1.object_type=t3.object_type; Execution Plan ---------------------------------------------------------- Plan hash value: 98820498 ---------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ---------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 4 | 120 | 9 (0)| 00:00:01 | |* 1 | HASH JOIN | | 4 | 120 | 9 (0)| 00:00:01 | |* 2 | HASH JOIN | |11 | 220 | 6 (0)| 00:00:01 | | 3 | TABLE ACCESS FULL| T2 |11 | 110 | 3 (0)| 00:00:01 | | 4 | TABLE ACCESS FULL| T3 |21 | 210 | 3 (0)| 00:00:01 | | 5 | TABLE ACCESS FULL | T1 | 1 |10 | 3 (0)| 00:00:01 | ---------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 1 - access("T1"."OBJECT_TYPE"="T3"."OBJECT_TYPE") 2 - access("T2"."OBJECT_ID"="T3"."OBJECT_ID"
可以看到,現(xiàn)在上述sql的執(zhí)行計劃是先由表T2和表T3做哈希連接,然后將他們做哈希連接的連接結(jié)果集再和表T1做一次哈希連接。
表T1的記錄數(shù)為1,表T2的記錄數(shù)為11,表T3的記錄數(shù)為21,所以當(dāng)表的T2和T3做哈希連接時,記錄數(shù)多的表T3應(yīng)該是被驅(qū)動表,這是因為我們在上述sql中使用了ordered hint和use_hash HINT指定表T3作為表T2和T3連接的時的被驅(qū)動表,所以oracle這里選擇了表T2和T3做哈希連接,并且選擇了表T3作為該哈希連接的被驅(qū)動表,這是沒有問題的,現(xiàn)在問題在于表T1的記錄數(shù)僅為1,所以當(dāng)表T2和T3做哈希連接的結(jié)果再和表T1做哈希連接時,表T1應(yīng)該是驅(qū)動表,而不是在上述執(zhí)行計劃里顯示的那樣作為第二個哈希連接的被驅(qū)動表。
使用下面HINT:
select /*+ ordered use_hash(t3) */ t1.owner,t2.object_name,t3.object_type 2 from t1,t2,t3 where t2.object_id=t3.object_id and t1.object_type=t3.object_type; Execution Plan ---------------------------------------------------------- Plan hash value: 38266800 ------------------------------------------------------------------------------ | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ------------------------------------------------------------------------------ | 0 | SELECT STATEMENT | | 4 | 120 | 9 (0)| 00:00:01 | |* 1 | HASH JOIN | | 4 | 120 | 9 (0)| 00:00:01 | | 2 | MERGE JOIN CARTESIAN| | 11 | 220 | 6 (0)| 00:00:01 | | 3 | TABLE ACCESS FULL | T1 | 1 | 10 | 3 (0)| 00:00:01 | | 4 | BUFFER SORT | | 11 | 110 | 3 (0)| 00:00:01 | | 5 | TABLE ACCESS FULL | T2 | 11 | 110 | 3 (0)| 00:00:01 | | 6 | TABLE ACCESS FULL | T3 | 21 | 210 | 3 (0)| 00:00:01 | ------------------------------------------------------------------------------ Predicate Information (identified by operation id): --------------------------------------------------- 1 - access("T2"."OBJECT_ID"="T3"."OBJECT_ID" AND "T1"."OBJECT_TYPE"="T3"."OBJECT_TYPE")
select /*+ leading(t1) use_hash(t3) */ t1.owner,t2.object_name,t3.object_type 2 from t1,t2,t3 where t2.object_id=t3.object_id and t1.object_type=t3.object_type; Execution Plan ---------------------------------------------------------- Plan hash value: 2308542799 ---------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ---------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 7 | 210 | 9 (0)| 00:00:01 | |* 1 | HASH JOIN | | 7 | 210 | 9 (0)| 00:00:01 | |* 2 | HASH JOIN | | 7 | 140 | 6 (0)| 00:00:01 | | 3 | TABLE ACCESS FULL| T1 | 1 |10 | 3 (0)| 00:00:01 | | 4 | TABLE ACCESS FULL| T3 |21 | 210 | 3 (0)| 00:00:01 | | 5 | TABLE ACCESS FULL | T2 |11 | 110 | 3 (0)| 00:00:01 | ---------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 1 - access("T2"."OBJECT_ID"="T3"."OBJECT_ID") 2 - access("T1"."OBJECT_TYPE"="T3"."OBJECT_TYPE")
加入以下hint,就解決:
SELECT /*+ ordered use_hash(t3) swap_join_inputs(t1) */ t1.owner, t2.object_name, t3.object_type FROM t2, t3, t1 WHERE t2.object_id = t3.object_id 5 AND t1.object_type = t3.object_type; Execution Plan ---------------------------------------------------------- Plan hash value: 3071514789 ---------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ---------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 4 | 120 | 9 (0)| 00:00:01 | |* 1 | HASH JOIN | | 4 | 120 | 9 (0)| 00:00:01 | | 2 | TABLE ACCESS FULL | T1 | 1 |10 | 3 (0)| 00:00:01 | |* 3 | HASH JOIN | |11 | 220 | 6 (0)| 00:00:01 | | 4 | TABLE ACCESS FULL| T2 |11 | 110 | 3 (0)| 00:00:01 | | 5 | TABLE ACCESS FULL| T3 |21 | 210 | 3 (0)| 00:00:01 | ---------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 1 - access("T1"."OBJECT_TYPE"="T3"."OBJECT_TYPE") 3 - access("T2"."OBJECT_ID"="T3"."OBJECT_ID")
免責(zé)聲明:本站發(fā)布的內(nèi)容(圖片、視頻和文字)以原創(chuàng)、轉(zhuǎn)載和分享為主,文章觀點不代表本網(wǎng)站立場,如果涉及侵權(quán)請聯(lián)系站長郵箱:is@yisu.com進行舉報,并提供相關(guān)證據(jù),一經(jīng)查實,將立刻刪除涉嫌侵權(quán)內(nèi)容。