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: RE: Index behavior

RE: RE: Index behavior

From: <Jared.Still_at_radisys.com>
Date: Thu, 06 Nov 2003 10:29:49 -0800
Message-ID: <F001.005D5D9E.20031106102949@fatcity.com>


The threshold has to be somewhere, and you found it.

Try building your own histogram on the data if you really want to dig into it, it may become obvious.

That's not an *oracle* histogram, but a curious DBA histgram that may help you understand why the threshold is there.

Think excel spreadsheet. At least, that's what I would do to try and understand it .

Jared

"Henry Poras" <hporas_at_etal.uri.edu>
Sent by: ml-errors_at_fatcity.com
 11/06/2003 08:39 AM
 Please respond to ORACLE-L  

        To:     Multiple recipients of list ORACLE-L <ORACLE-L_at_fatcity.com>
        cc: 
        Subject:        RE: RE: Index behavior


OK, I can follow that, but why the change between ABC% and AB% ?

Henry

-----Original Message-----
Wolfgang Breitling
Sent: Thursday, November 06, 2003 10:19 AM To: Multiple recipients of list ORACLE-L

Actually, it has nothing to do with any of the table or index statistics. OK, almost nothing. I suppose if Jonathan (Lewis) can get the optimizer to do a FTS on an umpteen billion row table to retrieve a single row by its prime key, one can concoct a scenario of statistics values, aided by init or session parameters, that would cause the CBO to use a full table scan to
resolve "where name like 'AB%".
Back to the topic. I did a test and the situation is easily reproduceable. What happens is that as the like comparison string gets short, the selectivity of the predicate decreases ( if you look at the 10053 trace, the TBSEL value increases but that is the same paradoxon as with performance: if something gets faster, did its performance decrease? ) as one would expect. The TBSEL selectivity value and the rate of its increase depends on the length of the like comparison string and the average column length. When it gets down to the transition from ABC% to AB%, that trend breaks sharply and suddenly the selectivity increases by orders of magnitude ( TBSEL decreases by a huge factor ). for "like A%" it decreases again, but is still lower (depends on avg col length) than the selectivity of "like ABC%".
You can see that in the following test. The cardinality reflects the changes in the tbsel value (cardinality = tbsel * num_rows, which was 10,000 for the test).

select id from sam where name like 'ABCDEFGHI%';   card operation

----- ----------------------------------
     1 SELECT STATEMENT
     1   TABLE ACCESS BY INDEX ROWID SAM
     1     INDEX RANGE SCAN SAM_IX

select id from sam where name like 'ABCDEFGH%';   card operation

----- -----------------------------------
     1 SELECT STATEMENT
     1   TABLE ACCESS BY INDEX ROWID SAM
     1     INDEX RANGE SCAN SAM_IX

select id from sam where name like 'ABCDEFG%';   card operation

----- -----------------------------------

    57 SELECT STATEMENT
    57 TABLE ACCESS FULL SAM select id from sam where name like 'ABCDEF%';   card operation

----- -----------------------------------

   100 SELECT STATEMENT
   100 TABLE ACCESS FULL SAM select id from sam where name like 'ABCDE%';   card operation

----- -----------------------------------

   178 SELECT STATEMENT
   178 TABLE ACCESS FULL SAM select id from sam where name like 'ABCD%';   card operation

----- -----------------------------------

   317 SELECT STATEMENT
   317 TABLE ACCESS FULL SAM select id from sam where name like 'ABC%';   card operation

----- -----------------------------------

   563 SELECT STATEMENT
   563 TABLE ACCESS FULL SAM select id from sam where name like 'AB%';   card operation

----- -----------------------------------
     2 SELECT STATEMENT
     2   TABLE ACCESS BY INDEX ROWID SAM
     2     INDEX RANGE SCAN SAM_IX

select id from sam where name like 'A%';   card operation

----- -----------------------------------

   297 SELECT STATEMENT
   297 TABLE ACCESS FULL SAM At 04:29 PM 11/5/2003, you wrote:
>Hi Goulet,
>
>The clustering factor on the index=37930
>number of distinct keys=38357
>number of leaf blocks=1075

Wolfgang Breitling
Oracle7, 8, 8i, 9i OCP DBA
Centrex Consulting Corporation
http://www.centrexcc.com

--
Please see the official ORACLE-L FAQ: http://www.orafaq.net
--
Author: Wolfgang Breitling
  INET: breitliw_at_centrexcc.com

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: 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).

-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: Henry Poras
  INET: hporas_at_etal.uri.edu

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: 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).



-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: 
  INET: Jared.Still_at_radisys.com

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: 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 Thu Nov 06 2003 - 12:29:49 CST

Original text of this message

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