Oracle FAQ Your Portal to the Oracle Knowledge Grid
HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US
 

Home -> Community -> Mailing Lists -> Oracle-L -> Re: does oracle us both block and row level nested loop joins?

Re: does oracle us both block and row level nested loop joins?

From: Tanel Põder <tanel.poder.003_at_mail.ee>
Date: Fri, 30 Jul 2004 19:04:11 +0300
Message-ID: <07f701c4764e$da945f60$36ae9fd9@porgand>


> I'm fairly certain that Oracle uses row level nested loop joins when
tables are indexes.
> However, does it do 'block' level nested loop joins to improve performance
when
> tables are not indexed. I do not know how to test for this.

Try this test:

create table t1(a, b) as select rownum, cast('x' as char(1000)) from sys.obj$ where rownum <=50;
create table t2(a, b) as select rownum, cast('x' as char(1000)) from sys.obj$ where rownum <=500;

--create index i1 on t1(a);
--create index i2 on t2(a);

analyze table t1 compute statistics;
analyze table t2 compute statistics;

select table_name, blocks from user_tables where table_name in ('T1', 'T2');

set autot trace exp stat

select /*+ USE_NL(t1, t2) */ t1.*, t2.* from t1, t2 where t1.a = t2.a;

set autot off

You see from consistent gets that all of the blocks in T2 are opened 50 times (total LIOs = the amount of rows in T1 * blocks in T2 + some overhead).

At least this experiment shows that there is no block prefetching or row caching used and all joining is done row-by-row. About indexed NL joins and prefetching, uncomment the above create index clauses one by one and see the results then (there was a quite interesting thread about index prefetching in NL joins couple of months ago here..)

Tanel.



Please see the official ORACLE-L FAQ: http://www.orafaq.com

To unsubscribe send email to: oracle-l-request_at_freelists.org put 'unsubscribe' in the subject line.
--
Archives are at http://www.freelists.org/archives/oracle-l/
FAQ is at http://www.freelists.org/help/fom-serve/cache/1.html
-----------------------------------------------------------------
Received on Fri Jul 30 2004 - 11:01:35 CDT

Original text of this message

HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US