| Oracle FAQ | Your Portal to the Oracle Knowledge Grid | |
|  |  | |||
Home -> Community -> Mailing Lists -> Oracle-L -> RE: USE_NL with or without ORDERED
Jonathan,
If you haven't droped your test tables yet could you try /*+ USE_NL(c e) */ Yeah, sounds strange, but...
SQL> select /*+ use_nl(c e) */
2 e.first_name 3 , e.last_name 4 , c.short_name
1018 rows selected.
Execution Plan
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=1022 Card=1018 Bytes
=31558)
1 0 NESTED LOOPS (Cost=1022 Card=1018 Bytes=31558)
2 1 TABLE ACCESS (FULL) OF 'COURSES' (Cost=4 Card=1018 Bytes
=14252)
3 1 TABLE ACCESS (BY INDEX ROWID) OF 'EMPLOYEES' (Cost=1 Car
d=15132 Bytes=257244)
4 3 INDEX (UNIQUE SCAN) OF 'EMP_PK' (UNIQUE) SQL> select /*+ use_nl(c e) */
2 e.first_name 3 , e.last_name 4 , c.short_name
1018 rows selected.
Execution Plan
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=1022 Card=1018 Bytes
=31558)
1 0 NESTED LOOPS (Cost=1022 Card=1018 Bytes=31558)
2 1 TABLE ACCESS (FULL) OF 'COURSES' (Cost=4 Card=1018 Bytes
=14252)
3 1 TABLE ACCESS (BY INDEX ROWID) OF 'EMPLOYEES' (Cost=1 Car
d=15132 Bytes=257244)
   4    3       INDEX (UNIQUE SCAN) OF 'EMP_PK' (UNIQUE)
Regards,
Ed
>  
>  
>  
>  Larry's answer is totally correct - 
>  
>  The SQL reads:
>      select /*+ use_nl(t2) *./
>              etc
>      from t1,t2
>      where t1.id = t2.id
>          etc
>  
>  But manages to hash from T1 to T2.
>  
>  (I had to play around a little bit to 
>  make the tables and rows the right 
>  size for this to happen).
>  
>  Looking at the 10053 trace, I got the lines:
>  (with lots of cuts and editing)
>  
>  General Join Order:
>  Join Order 1  T1  ->  T2
>          use_nl    
>              calculations - cost = 92
>          NO LINES for sort/merge
>          NO LINES for hash join
>              so the hint IS constraining Oracle to 
>              consider only NL when joining T2.
>  
>  Join Order 2  T2  ->  T1
>          Use_nl
>              calculations - cost = 127
>          sort/merge
>              calculations - cost =  64
>          hash join
>              calculations - cost = 47
>                      (sides swapped)
>  
>  So Oracle arrives at the best path by
>  considering the join order T2 -> T1,
>  which makes the hint ignorable, but
>  then swaps the table order at execution
>  time, to produce the apparent contradiction.
>  
-- Please see the official ORACLE-L FAQ: http://www.orafaq.com -- Author: Shevtsov, Eduard INET: EShevtsov_at_flagship.ru Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051 San Diego, California -- Public Internet access / Mailing Lists -------------------------------------------------------------------- To REMOVE yourself from this mailing list, send an E-Mail message to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from). You may also send the HELP command for other information (like subscribing).Received on Mon Sep 17 2001 - 04:38:35 CDT
|  |  |