Mohamed Houri’s Oracle Notes

March 5, 2011

On when the alphabetic order of index name matters for the Oracle Optimizer

Filed under: Index — hourim @ 7:07 am

Do you know that in the presence of, what I now take the habit to name redundant indexes, the Oracle optimizer will use the alphabetic chronological order applied to the names of those indexes in order to decide which of them it will choose to execute the query?

If no, then follow this simple demo:

sql.world> drop table table_a;

Table dropped.

sql.world> CREATE TABLE table_a (col1 NUMBER(10)
 2                          ,col2 NUMBER(10)
 3                          ,col3 NUMBER(10)
 4                          ,col4 NUMBER(10));

Table created.

sql.world> INSERT INTO table_a
 2     SELECT rownum
 3           ,lpad (mod (rownum, 5), 5, '0')
 4           ,lpad (mod (rownum, 5), 5, '0')+11
 5           ,lpad (mod (rownum, 5), 5, '0')+12
 6       FROM all_objects
 7      WHERE ROWNUM < 5000;

4999 rows created.

sql.world> CREATE INDEX a_i1 ON table_a (col1, col2);

Index created.

sql.world> BEGIN
 2     dbms_stats.gather_table_stats
 3                (ownname           => USER,
 4                 tabname           => 'table_a',
 5                 partname          => NULL,
 6                 estimate_percent => 100,
 7                 block_sample     => TRUE,
 8                 method_opt       => 'for all columns size 1'
 9                );
 10  END;
 11  /

PL/SQL procedure successfully completed.

sql.world> SELECT *
 2        FROM table_a
 3       WHERE col1 = 627;

 COL1       COL2       COL3       COL4
---------- ---------- ---------- ----------
 627          2         13         14

sql.world> select * from table(dbms_xplan.display_cursor);

PLAN_TABLE_OUTPUT
---------------------------------------------------------------------------------------
SQL_ID  0vt3kwzj1r6ku, child number 0
-------------------------------------
SELECT *       FROM table_a      WHERE col1 = 627

Plan hash value: 3359021421

---------------------------------------------------------------------------------------
| Id  | Operation                   | Name    | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |         |       |       |     3 (100)|          |
|   1 |  TABLE ACCESS BY INDEX ROWID| TABLE_A |     1 |    12 |     3   (0)| 00:00:01 |
|*  2 |   INDEX RANGE SCAN          | A_I1    |     1 |       |     2   (0)| 00:00:01 |
---------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

 2 - access("COL1"=627)

So, I have created a table, table_a, and an index a_i1 to cover my query. The explain plan shows that the index is used. Let’s now create an extra index b_i1 as follows:

sql.world> create index b_i1 on table_a (col1,col3);

Index created.

sql.world>> SELECT *
 2        FROM table_a
 3       WHERE col1 = 627;

 COL1       COL2       COL3       COL4
---------- ---------- ---------- ----------
 627          2         13         14

sql.world> select * from table(dbms_xplan.display_cursor);

PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------
SQL_ID  0vt3kwzj1r6ku, child number 0
-------------------------------------
SELECT *       FROM table_a      WHERE col1 = 627

Plan hash value: 3359021421

---------------------------------------------------------------------------------------
| Id  | Operation                   | Name    | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |         |       |       |     3 (100)|          |
|   1 |  TABLE ACCESS BY INDEX ROWID| TABLE_A |     1 |    12 |     3   (0)| 00:00:01 |
|*  2 |   INDEX RANGE SCAN          | A_I1    |     1 |       |     2   (0)| 00:00:01 |
---------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

 2 - access("COL1"=627)

We see that the index a_i1 is still used by our query. But, let’s now rename the index a_i1 so that its new name will start with a letter greater than b in the alphabetic order

sql.world> alter index a_i1 rename to c_i1;

Index altered.

sql.world>> SELECT *
 2        FROM table_a
 3       WHERE col1 = 627;

 COL1       COL2       COL3       COL4
---------- ---------- ---------- ----------
 627          2         13         14

sql.world> select * from table(dbms_xplan.display_cursor);

PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------
SQL_ID  0vt3kwzj1r6ku, child number 0
-------------------------------------
SELECT *       FROM table_a      WHERE col1 = 627

Plan hash value: 257447779

---------------------------------------------------------------------------------------
| Id  | Operation                   | Name    | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |         |       |       |     3 (100)|          |
|   1 |  TABLE ACCESS BY INDEX ROWID| TABLE_A |     1 |    12 |     3   (0)| 00:00:01 |
|*  2 |   INDEX RANGE SCAN          | B_I1    |     1 |       |     2   (0)| 00:00:01 |
---------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

 2 - access("COL1"=627)

19 rows selected.

Woo!! Our query now decided to choose the b_i1 index? why? because a_i1 and b_i1 indexes are considered by the Oracle Optimizer to be both valid to cover the query; and in this case, the Oracle optimizer will choose the index using the alphabetic order.

If I, again, rename the index b_i1 to be z_i1 for example, then the Oracle optimizer will be back to the oiginal  use of  c_i1 index (initially named a_i1)  as confirmed by the example shown here below:

sql.world> alter index b_i1 rename to z_i1;

Index altered.

sql.world>> SELECT *
 2        FROM table_a
 3       WHERE col1 = 627;

 COL1       COL2       COL3       COL4
---------- ---------- ---------- ----------
 627          2         13         14

sql.world> select * from table(dbms_xplan.display_cursor);

PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------
SQL_ID  0vt3kwzj1r6ku, child number 0
-------------------------------------
SELECT *       FROM table_a      WHERE col1 = 627

Plan hash value: 1414606619

---------------------------------------------------------------------------------------
| Id  | Operation                   | Name    | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |         |       |       |     3 (100)|          |
|   1 |  TABLE ACCESS BY INDEX ROWID| TABLE_A |     1 |    12 |     3   (0)| 00:00:01 |
|*  2 |   INDEX RANGE SCAN          | C_I1    |     1 |       |     2   (0)| 00:00:01 |
---------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

 2 - access("COL1"=627)

19 rows selected.

2 Comments »

  1. I want to thank the blogger very much not only for this post,but also for his all previous efforts.I found this Google search to be greatly interesting.I will be coming back to your site for more information. startIndex

    Comment by silver11001 — January 19, 2013 @ 3:13 am | Reply

  2. I want to thank the blogger very much not only for this post, but also for his all previous efforts. I found this Google search to be greatly interesting. I will be coming back to your site for more information. writing services

    Comment by silver11001 — February 23, 2013 @ 6:22 pm | Reply


RSS feed for comments on this post. TrackBack URI

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s

Create a free website or blog at WordPress.com.

Tony's Oracle Tips

Tony Hasler's light hearted approach to learning about Oracle

Richard Foote's Oracle Blog

Focusing Specifically On Oracle Indexes, Database Administration and Some Great Music

Hatem Mahmoud Oracle's blog

Just another Oracle blog : Database topics and techniques

Mohamed Houri’s Oracle Notes

Qui se conçoit bien s’énonce clairement

Oracle Diagnostician

Performance troubleshooting as exact science

Raheel's Blog

Things I have learnt as Oracle DBA

Coskan's Approach to Oracle

What I learned about Oracle

So Many Oracle Manuals, So Little Time

“Books to the ceiling, Books to the sky, My pile of books is a mile high. How I love them! How I need them! I'll have a long beard by the time I read them”—Lobel, Arnold. Whiskers and Rhymes. William Morrow & Co, 1988.

EU Careers info

Your career in the European Union

Carlos Sierra's Tools and Tips

Tools and Tips for Oracle Performance and SQL Tuning

Oracle Scratchpad

Just another Oracle weblog

OraStory

Dominic Brooks on Oracle Performance, Tuning, Data Quality & Sensible Design ... (Now with added Sets Appeal)

%d bloggers like this: