Re: Composite indices and skip scanning

  • From: "Jonathan Lewis" <jonathan@xxxxxxxxxxxxxxxxxx>
  • To: <oracle-l@xxxxxxxxxxxxx>
  • Date: Thu, 15 Apr 2004 14:37:41 +0100

It's a statistical thing.
A skip scan would be:
    For each value of pk_table_a
        find values for pk_table_b

It's likely to be cheaper than a tablescan
only if there are relatively few distinct values 
for the column pk_table_a.

If you're looking for ideas for minimising
I/O and improving performance - you 
could investigate defining the intersection
table as an IOT, with compression on the 
pk_table_a column; and then create a
compressed secondary index on pk_table_b.
In the right circumstances it might be the 
most efficient option.

Regards

Jonathan Lewis
http://www.jlcomp.demon.co.uk

The Co-operative Oracle Users' FAQ
http://www.jlcomp.demon.co.uk/faq/ind_faq.html

April 2004 Iceland  http://www.index.is/oracleday.php 
June  2004      UK - Optimising Oracle Seminar


----- Original Message ----- 
From: "Boyle, Christopher J." <Christopher.J.Boyle@xxxxxxxx>
To: <oracle-l@xxxxxxxxxxxxx>
Sent: Thursday, April 15, 2004 2:11 PM
Subject: Composite indices and skip scanning


Oracle 9.2.0.2.0=20

I have an intersection table composed of PK_TABLE_A, PK_TABLE_B which is
being used to handle a M:M relationship between A and B.  There is a
unique constraint on the combination of the two entries and a
corresponding index with A as the leading value.  When I was trying to
access table A using the PK from table B I expected it to use that index
because of the 9i skip scan feature that allows for a non leading index
member to still utilize the index.  What I got was a FTS until I added a
separate index on PK_TABLE_B only.  Is there something with a unique
index that prevents skip scanning? Or do I have too much blood in my
caffeine and am mis-rembering how the indices should work?

Thanks,
Chris =20


----------------------------------------------------------------
Please see the official ORACLE-L FAQ: http://www.orafaq.com
----------------------------------------------------------------
To unsubscribe send email to:  oracle-l-request@xxxxxxxxxxxxx
put 'unsubscribe' in the subject line.
--
Archives are at //www.freelists.org/archives/oracle-l/
FAQ is at //www.freelists.org/help/fom-serve/cache/1.html
-----------------------------------------------------------------

Other related posts: