Re: Strategies for dealing with (NOT EQUAL) conditions and indexes

From: Sidney Chen <huanshengchen_at_gmail.com>
Date: Thu, 17 Nov 2011 20:53:08 +0800
Message-ID: <CAM_ddu9=qqKwj_L7HpL_t1w3pigfmTimFFCY=31xtP4O9F19-g_at_mail.gmail.com>



it's all about cost, the index is not used because the Optimizer think it's cheaper(lower cost) to do a full table scan, not because it can't do a index scan for an not equal predicate.
just as Mark said, if you make val1 popular enough, the index will be used. I remove the primary key to make sure around 90% var1 = 12. this tick to show how index scan can happen for not equal predicate.

oe_at_CS10G> select count(*)
  2 from test1
  3 where val1 
  4 and val2 = 'A12E'
  5 /

  COUNT(*)


     90094

1 row selected.

oe_at_CS10G> explain plan for
  2 select /*+ dynamic_sampling(4)*/ val2, val3, val4, val5   3 from test1
  4 where val1 = 12
  5 and val2 = 'A12E'
  6 /

Explained.

oe_at_CS10G> @x typical
oe_at_CS10G> select * from table(dbms_xplan.display('plan_table',null,'&1'));

PLAN_TABLE_OUTPUT



Plan hash value: 1966964964

| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |

| 0 | SELECT STATEMENT | | 90087 | 1847K| 99 (0)| 00:00:02 | |* 1 | TABLE ACCESS BY INDEX ROWID| TEST1 | 90087 | 1847K| 99 (0)| 00:00:02 |
|* 2 | INDEX RANGE SCAN | TEST1_IDX01 | 1000 | | 3 (0)| 00:00:01 |

Predicate Information (identified by operation id):


   1 - filter("VAL2"='A12E')
   2 - access("VAL1")

Note


  • dynamic sampling used for this statement

19 rows selected.

oe_at_CS10G> explain plan for
  2 select /*+ dynamic_sampling(4)*/val2, val3, val4, val5   3 from test1
  4 where val1 != 12
  5 and val2 = 'A12E'
  6 /

Explained.

oe_at_CS10G> @x typical
oe_at_CS10G> select * from table(dbms_xplan.display('plan_table',null,'&1'));

PLAN_TABLE_OUTPUT



Plan hash value: 2016337987

| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |

| 0 | SELECT STATEMENT | | 10 | 210 | 100 (0)| 00:00:02 | |* 1 | TABLE ACCESS BY INDEX ROWID| TEST1 | 10 | 210 | 100 (0)| 00:00:02 |
|* 2 | INDEX RANGE SCAN | TEST1_IDX02 | 1000 | | 4 (0)| 00:00:01 |

Predicate Information (identified by operation id):


   1 - filter("VAL1"<>12)
   2 - access("VAL2"='A12E')

Note


  • dynamic sampling used for this statement

19 rows selected.

--update created table scripts
---create table and load with data----
drop table test1
/

/* Let us create a wider table */

create table test1
(val1 number(3) not null,
val2 varchar2(8) not null,
val3 number(3) not null,

val4 varchar2(5) not null,
val5 varchar2(5) not null,
val6 varchar2(5) not null,
val7 varchar2(5),
val8 varchar2(5)

)
/

/* Now let us add a primary key like might exist */

--alter table test1 add constraint test1_pk primary key (val1, val2, val3) --using index

/* Now let us add some additional indexes like might exist */

create index test1_idx01 on test1 (val1) /
create index test1_idx02 on test1 (val2) /
create index test1_idx03 on test1 (val3) /
create index test1_idx04 on test1 (val1, val3) /
create index test1_idx05 on test1 (val2, val3) /
create index test1_idx06 on test1 (val1, val2, val4) /
create index test1_idx07 on test1 (val1, val3, val4) /
create index test1_idx08 on test1 (val1, val2, val3, val4) /
create index test1_idx09 on test1 (val1, val2, val3, val5) /
create index test1_idx10 on test1 (val1, val2, val3, val6) /

/* Now let us add some data */

insert into test1
with generator as
(select
*case when mod(rownum,10) < 9 then 12 else round(dbms_random.value(1,100)) end n1,*
round(dbms_random.value(1,100)) n2
from dual connect by level < 100000
)
select
n1,
'A'||n1||'E',
n2,

'B'||n1||'D',
'C'||n2||'C',
'D'||n2||'B',
'E'||n2||'A',

null
from generator;

begin
dbms_Stats.gather_table_stats(ownname=>'',tabname=>'TEST1',estimate_percent=>100,cascade=>TRUE, method_opt=>'FOR ALL COLUMNS SIZE AUTO', granularity=>'ALL', block_sample=>TRUE);
end;
/

-- 
Regards
Sidney Chen

--
http://www.freelists.org/webpage/oracle-l
Received on Thu Nov 17 2011 - 06:53:08 CST

Original text of this message