When i used scalar sub query instead of inner join its cost is low when compared with the other. By default scalar sub-queries are optimized for response time, where as join are optimized for throughput.
demo@ORA11G> set feedback off
demo@ORA11G> drop table t2 purge;
demo@ORA11G> drop table t1 purge;
demo@ORA11G>
demo@ORA11G> create table t2 as
2 select a.owner,a.table_name,a.column_name,a.data_type,
3 rpad('*',80,'*') as datas
4 from all_tab_columns a,
5 all_tables b
6 where a.table_name = b.table_name
7 and a.owner = b.owner;
demo@ORA11G>
demo@ORA11G> create table t1 as select * from all_tables ;
demo@ORA11G>
demo@ORA11G> alter table t1 add constraint t1_pk
2 primary key(owner,table_name);
demo@ORA11G>
demo@ORA11G> alter table t2 add constraint t2_fk
2 foreign key(owner,table_name)
3 references t1;
demo@ORA11G>
demo@ORA11G> create index t2_idx on t2(owner,table_name);
demo@ORA11G>
demo@ORA11G> begin
2 dbms_stats.gather_table_stats(user,'T1');
3 dbms_stats.gather_table_stats(user,'T2',
4 method_opt=>'for all indexed columns size 254',
5 cascade=>true);
6 end;
7 /
demo@ORA11G> set feedback on
demo@ORA11G>
demo@ORA11G> set autotrace traceonly explain
demo@ORA11G> select t1.owner,t1.table_name,max(t2.column_name) cname
2 from t1, t2
3 where t1.owner = t2.owner (+)
4 and t1.table_name = t2.table_name (+)
5 group by t1.owner,t1.table_name ;
Execution Plan
----------------------------------------------------------
Plan hash value: 3351207033
------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 146 | 9636 | 19 (6)| 00:00:01 |
| 1 | SORT GROUP BY NOSORT| | 146 | 9636 | 19 (6)| 00:00:01 |
| 2 | MERGE JOIN OUTER | | 1414 | 93324 | 19 (6)| 00:00:01 |
| 3 | INDEX FULL SCAN | T1_PK | 153 | 3672 | 1 (0)| 00:00:01 |
|* 4 | SORT JOIN | | 1414 | 59388 | 18 (6)| 00:00:01 |
| 5 | TABLE ACCESS FULL| T2 | 1414 | 59388 | 17 (0)| 00:00:01 |
------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
4 - access("T1"."OWNER"="T2"."OWNER"(+) AND
"T1"."TABLE_NAME"="T2"."TABLE_NAME"(+))
filter("T1"."TABLE_NAME"="T2"."TABLE_NAME"(+) AND
"T1"."OWNER"="T2"."OWNER"(+))
demo@ORA11G>
demo@ORA11G> select t1.owner,t1.table_name ,( select max(t2.column_name) from t2
2 where t1.owner = t2.owner
3 and t1.table_name = t2.table_name ) cname
4 from t1 ;
Execution Plan
----------------------------------------------------------
Plan hash value: 3479339389
---------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
---------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 153 | 3672 | 1 (0)| 00:00:01 |
| 1 | SORT AGGREGATE | | 1 | 42 | | |
| 2 | TABLE ACCESS BY INDEX ROWID| T2 | 1 | 42 | 2 (0)| 00:00:01 |
|* 3 | INDEX RANGE SCAN | T2_IDX | 1 | | 1 (0)| 00:00:01 |
| 4 | INDEX FULL SCAN | T1_PK | 153 | 3672 | 1 (0)| 00:00:01 |
---------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
3 - access("T2"."OWNER"=:B1 AND "T2"."TABLE_NAME"=:B2)
demo@ORA11G> set autotrace off
demo@ORA11G>
demo@ORA11G>
Tkprof shows this.
SELECT T1.OWNER,T1.TABLE_NAME,MAX(T2.COLUMN_NAME) CNAME
FROM
T1, T2 WHERE T1.OWNER = T2.OWNER (+) AND T1.TABLE_NAME = T2.TABLE_NAME (+)
GROUP BY T1.OWNER,T1.TABLE_NAME
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 2 0.00 0.00 0 30 0 153
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 4 0.00 0.00 0 30 0 153
Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 110 (recursive depth: 1)
Number of plan statistics captured: 1
Rows (1st) Rows (avg) Rows (max) Row Source Operation
---------- ---------- ---------- ---------------------------------------------------
153 153 153 SORT GROUP BY NOSORT (cr=30 pr=0 pw=0 time=3442 us cost=19 size=9636 card=146)
1421 1421 1421 MERGE JOIN OUTER (cr=30 pr=0 pw=0 time=4938 us cost=19 size=93324 card=1414)
153 153 153 INDEX FULL SCAN T1_PK (cr=2 pr=0 pw=0 time=177 us cost=1 size=3672 card=153)(object id 106714)
1414 1414 1414 SORT JOIN (cr=28 pr=0 pw=0 time=3369 us cost=18 size=59388 card=1414)
1414 1414 1414 TABLE ACCESS FULL T2 (cr=28 pr=0 pw=0 time=872 us cost=17 size=59388 card=1414)
SELECT T1.OWNER,T1.TABLE_NAME ,( SELECT MAX(T2.COLUMN_NAME)
FROM
T2 WHERE T1.OWNER = T2.OWNER AND T1.TABLE_NAME = T2.TABLE_NAME ) CNAME FROM
T1
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 2 0.01 0.00 0 172 0 153
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 4 0.01 0.00 0 172 0 153
Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 110 (recursive depth: 1)
Number of plan statistics captured: 1
Rows (1st) Rows (avg) Rows (max) Row Source Operation
---------- ---------- ---------- ---------------------------------------------------
153 153 153 SORT AGGREGATE (cr=170 pr=0 pw=0 time=3951 us)
1414 1414 1414 TABLE ACCESS BY INDEX ROWID T2 (cr=170 pr=0 pw=0 time=4116 us cost=2 size=42 card=1)
1414 1414 1414 INDEX RANGE SCAN T2_IDX (cr=47 pr=0 pw=0 time=1964 us cost=1 size=0 card=1)(object id 106715)
153 153 153 INDEX FULL SCAN T1_PK (cr=2 pr=0 pw=0 time=175 us cost=1 size=3672 card=153)(object id 106714)
But things got changed in 12c, Optimizer has the ability to transform the Scalar sub-queries into joins for Optimal performance.
running the above test in 12c (12.1.0.2) shows up this.
demo@ORA12C> set autotrace traceonly explain
demo@ORA12C> select t1.owner,t1.table_name,max(t2.column_name) cname
2 from t1, t2
3 where t1.owner = t2.owner (+)
4 and t1.table_name = t2.table_name (+)
5 group by t1.owner,t1.table_name ;
Execution Plan
----------------------------------------------------------
Plan hash value: 3351207033
------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 158 | 9322 | 14 (22)| 00:00:01 |
| 1 | SORT GROUP BY NOSORT| | 158 | 9322 | 14 (22)| 00:00:01 |
| 2 | MERGE JOIN OUTER | | 1492 | 88028 | 14 (22)| 00:00:01 |
| 3 | INDEX FULL SCAN | T1_PK | 162 | 3726 | 1 (0)| 00:00:01 |
|* 4 | SORT JOIN | | 1488 | 53568 | 13 (24)| 00:00:01 |
| 5 | TABLE ACCESS FULL| T2 | 1488 | 53568 | 11 (10)| 00:00:01 |
------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
4 - access("T1"."OWNER"="T2"."OWNER"(+) AND
"T1"."TABLE_NAME"="T2"."TABLE_NAME"(+))
filter("T1"."TABLE_NAME"="T2"."TABLE_NAME"(+) AND
"T1"."OWNER"="T2"."OWNER"(+))
demo@ORA12C>
demo@ORA12C> select t1.owner,t1.table_name ,( select max(t2.column_name) from t2
2 where t1.owner = t2.owner
3 and t1.table_name = t2.table_name ) cname
4 from t1 ;
Execution Plan
----------------------------------------------------------
Plan hash value: 1823981746
----------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
----------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 162 | 35802 | 16 (32)| 00:00:01 |
| 1 | MERGE JOIN OUTER | | 162 | 35802 | 16 (32)| 00:00:01 |
| 2 | INDEX FULL SCAN | T1_PK | 162 | 3726 | 1 (0)| 00:00:01 |
|* 3 | SORT JOIN | | 158 | 31284 | 15 (34)| 00:00:01 |
| 4 | VIEW | VW_SSQ_1 | 158 | 31284 | 13 (24)| 00:00:01 |
| 5 | HASH GROUP BY | | 158 | 5688 | 13 (24)| 00:00:01 |
| 6 | TABLE ACCESS FULL| T2 | 1488 | 53568 | 11 (10)| 00:00:01 |
----------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
3 - access("T1"."OWNER"="ITEM_1"(+) AND "T1"."TABLE_NAME"="ITEM_2"(+))
filter("T1"."TABLE_NAME"="ITEM_2"(+) AND "T1"."OWNER"="ITEM_1"(+))
demo@ORA12C> set autotrace off
demo@ORA12C>
Tkprof from 12c show this.
SELECT T1.OWNER,T1.TABLE_NAME,MAX(T2.COLUMN_NAME) CNAME
FROM
T1, T2 WHERE T1.OWNER = T2.OWNER (+) AND T1.TABLE_NAME = T2.TABLE_NAME (+)
GROUP BY T1.OWNER,T1.TABLE_NAME
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.01 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 2 0.00 0.04 0 32 0 162
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 4 0.01 0.04 0 32 0 162
Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 135 (recursive depth: 1)
Number of plan statistics captured: 1
Rows (1st) Rows (avg) Rows (max) Row Source Operation
---------- ---------- ---------- ---------------------------------------------------
162 162 162 SORT GROUP BY NOSORT (cr=32 pr=0 pw=0 time=1418 us cost=14 size=9322 card=158)
1492 1492 1492 MERGE JOIN OUTER (cr=32 pr=0 pw=0 time=1560 us cost=14 size=88028 card=1492)
162 162 162 INDEX FULL SCAN T1_PK (cr=2 pr=0 pw=0 time=11 us cost=1 size=3726 card=162)(object id 113001)
1488 1488 1488 SORT JOIN (cr=30 pr=0 pw=0 time=1297 us cost=13 size=53568 card=1488)
1488 1488 1488 TABLE ACCESS FULL T2 (cr=30 pr=0 pw=0 time=400 us cost=11 size=53568 card=1488)
SELECT T1.OWNER,T1.TABLE_NAME ,( SELECT MAX(T2.COLUMN_NAME)
FROM
T2 WHERE T1.OWNER = T2.OWNER AND T1.TABLE_NAME = T2.TABLE_NAME ) CNAME FROM
T1
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.01 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 2 0.00 0.01 0 32 0 162
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 4 0.01 0.02 0 32 0 162
Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 135 (recursive depth: 1)
Number of plan statistics captured: 1
Rows (1st) Rows (avg) Rows (max) Row Source Operation
---------- ---------- ---------- ---------------------------------------------------
162 162 162 MERGE JOIN OUTER (cr=32 pr=0 pw=0 time=15718 us cost=16 size=35802 card=162)
162 162 162 INDEX FULL SCAN T1_PK (cr=2 pr=0 pw=0 time=344 us cost=1 size=3726 card=162)(object id 113001)
158 158 158 SORT JOIN (cr=30 pr=0 pw=0 time=14480 us cost=15 size=31284 card=158)
158 158 158 VIEW VW_SSQ_1 (cr=30 pr=0 pw=0 time=14049 us cost=13 size=31284 card=158)
158 158 158 HASH GROUP BY (cr=30 pr=0 pw=0 time=13809 us cost=13 size=5688 card=158)
1488 1488 1488 TABLE ACCESS FULL T2 (cr=30 pr=0 pw=0 time=823 us cost=11 size=53568 card=1488)
looking into 10053 trace from 12c database for the Scalar sub-queries got transformed like this.
Final query after transformations:******* UNPARSED QUERY IS *******
SELECT "T1"."OWNER" "OWNER",
"T1"."TABLE_NAME" "TABLE_NAME",
"VW_SSQ_1"."MAX(T2.COLUMN_NAME)" "CNAME"
FROM
(SELECT MAX("T2"."COLUMN_NAME") "MAX(T2.COLUMN_NAME)",
"T2"."OWNER" "ITEM_1",
"T2"."TABLE_NAME" "ITEM_2"
FROM "DEMO"."T2" "T2"
GROUP BY "T2"."OWNER",
"T2"."TABLE_NAME"
) "VW_SSQ_1",
"DEMO"."T1" "T1"
WHERE "T1"."OWNER" ="VW_SSQ_1"."ITEM_1"(+)
AND "T1"."TABLE_NAME"="VW_SSQ_1"."ITEM_2"(+)
You could see the 12c optimizer has transformed the Scalar subquries into an equivalent joins.