[EMAIL PROTECTED] wrote:
>
> Hi All,
> I've 3 tables table x,y,z
> pk of x is (col_1,col_2),pk of y is (col_1,col_2,col_4,col_5),pk of z is
> (col_1,col_2)
>
> where clause is :
>
> where x.col_1 = y.col_1
> and x.col_2 = y.col_2
> and x.col_1 = z.col_1
> and x.col_2 = z.col_2
> and y.col_1 = z.col_1
> and y.col_2 = z.col_2
> and x.col_3 in ('val1','val2','val3')
> and.....
> ..
>
> Explain plan shows that there is a FTS of table z .
> what can be the reason for this and how to prevent this.
>
> Thanks
> Manoj
>
> --
Manoj,
Look at the way you have written your conditions : you join x to z
and y to z too. A bit redundant since you also have the x to y join. Can
confuse Oracle. ASSUMING THAT THE CONDITION ON X.COL_3 IS SELECTIVE add
/*+ ORDERED */ after SELECT and list
from x, y, z
in this order. And remove the unnecessary join between x and z (just
keep x to y and y to z). As Dan remarked, don't forget that FTS are not
necessarily bad, and even are sometimes much more efficient than
something else (especially when used in a hash join, typically). The
proof of the pudding is in
SET TIMING ON
SET AUTOTRACE TRACEONLY
and compare the number of logical reads in both cases (and of course
elapsed time, but run each query twice to avoid measuring the effect of
parsing and bringing data into the cache)..
--
Regards,
Stephane Faroult
Oriole Software
--
Please see the official ORACLE-L FAQ: http://www.orafaq.net
--
Author: Stephane Faroult
INET: [EMAIL PROTECTED]
Fat City Network Services -- 858-538-5051 http://www.fatcity.com
San Diego, California -- Mailing list and web hosting services
---------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: [EMAIL PROTECTED] (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).