Mohamed Houri’s Oracle Notes

July 3, 2011

Using Function Based index appropriately

Filed under: Index — hourim @ 11:48 am

Very often requests to enhance performance of queries resembling to the following one:

SELECT col1
,col2
,col3
FROM t
WHERE flag != 'N';

populate forums like OTN. Requesters have already created an index on the flag column  and are complaining about the query which is not performing well and which is not using the index they created to cover the  flag where clause column. The main problem here is the “!=” operator.  The Oracle Cost based Optimizer (CBO) is unable to use an index to handle this operator. Fortunately, there is a possibility to enhance this kind of queries by taking the advantage of using a function based index. And this is what I aim to explain here via this blog article:

mhouri.world > create table t as select * from all_objects;
Table created.

mhouri.world > select count(1) from t;
COUNT(1)
----------
39114

mhouri.world > SELECT /*+ gather_plan_statistics */
2         t.*
3    FROM t
4   WHERE status != 'VALID'
5  ;

30 rows selected.

mhouri.world > select * from table(dbms_xplan.display_cursor(null,null,'ALLSTATS LAST'));

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------------
SQL_ID  5xtutwubr5xqv, child number 0
-------------------------------------
SELECT /*+ gather_plan_statistics */        t.* FROM t WHERE status !=
'VALID'
Plan hash value: 2153619298
------------------------------------------------------------------------------------
| Id  | Operation         | Name | Starts | E-Rows | A-Rows |   A-Time   | Buffers |
------------------------------------------------------------------------------------
|*  1 |  TABLE ACCESS FULL| T    |      1 |      6 |     30 |00:00:00.01 |     551 |
------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter("STATUS"<>'VALID')
Note
-----
- dynamic sampling used for this statement

22 rows selected.

Let’s now create an index on the status column, compute statistics and repeat the same select

mhouri.world > create index ind_status on t (status);

Index created.

mhouri.world >BEGIN
2     DBMS_STATS.gather_table_stats (ownname          => USER,
3                                    tabname          =>'t1',
4                                    estimate_percent => 100,
5                                    method_opt       => 'FOR ALL COLUMNS SIZE 1'
6                                   );
7  END;
8  /

PL/SQL procedure successfully completed.

mhouri.world > SELECT /*+ gather_plan_statistics */
2     t.*
3  FROM t
4  WHERE status != 'VALID';

30 rows selected.

mhouri.world > select * from table(dbms_xplan.display_cursor(null,null,'ALLSTATS LAST'));

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------
SQL_ID  5xtutwubr5xqv, child number 0
-------------------------------------
SELECT /*+ gather_plan_statistics */        t.* FROM t WHERE status !=
'VALID'
Plan hash value: 2153619298
-----------------------------------------------------------------------------
| Id  | Operation         | Name | Starts | E-Rows | A-Rows |   A-Time   | Buffers |
------------------------------------------------------------------------------------
|*  1 |  TABLE ACCESS FULL| T    |      1 |      6 |     30 |00:00:00.01 |     551 |
------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter("STATUS"<>'VALID')

Note
-----
- dynamic sampling used for this statement
22 rows selected.

The newly created index has not been of any help. It hasn’t been used at all by the CBO. This is of course due to the “!=” operator. Let’s then, now, create a function based index and requery again.

mhouri.world > create index ind_fbi_status on t (case when status = 'VALID' then NULL else 'X' end );

Index created.

mhouri.world > SELECT /*+ gather_plan_statistics */
2     t.*
3  FROM t
4  WHERE status != 'VALID';

30 rows selected.

mhouri.world > select * from table(dbms_xplan.display_cursor(null,null,'ALLSTATS LAST'));

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------------
SQL_ID  5xtutwubr5xqv, child number 0
-------------------------------------
SELECT /*+ gather_plan_statistics */        t.* FROM t WHERE status !=
'VALID'
Plan hash value: 2153619298
------------------------------------------------------------------------------------
| Id  | Operation         | Name | Starts | E-Rows | A-Rows |   A-Time   | Buffers |
------------------------------------------------------------------------------------
|*  1 |  TABLE ACCESS FULL| T    |      1 |      6 |     30 |00:00:00.01 |     551 |
------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter("STATUS"<>'VALID')
Note
-----
- dynamic sampling used for this statement

22 rows selected.

Nothing noticeable happened; we are still full scanning our T table. You know why? This is because to take advantage of using the newly created function based (FBI) index, we have to rewrite the query to make the query and the index consistent with each other.

mhouri.world > SELECT /*+ gather_plan_statistics */
2         t.*
3    FROM t
4    WHERE CASE
5            WHEN status = 'VALID'
6               THEN NULL
7            ELSE 'X'
8         END = 'X';

30 rows selected.

mhouri.world > select * from table(dbms_xplan.display_cursor(null,null,'ALLSTATS LAST'));

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------------------------------
SQL_ID  32fcmm91ywcqf, child number 0
-------------------------------------
SELECT /*+ gather_plan_statistics */        t.*   FROM t  WHERE CASE           WHEN status =
'VALID'              THEN NULL           ELSE 'X'        END = 'X'
Plan hash value: 3817300654
--------------------------------------------------------------------------------------------------------
| Id  | Operation                   | Name           | Starts | E-Rows | A-Rows |   A-Time   | Buffers |
--------------------------------------------------------------------------------------------------------
|   1 |  TABLE ACCESS BY INDEX ROWID| T              |      1 |      6 |     30 |00:00:00.01 |      14 |
|*  2 |   INDEX RANGE SCAN          | IND_FBI_STATUS |      1 |    130 |     30 |00:00:00.01 |       3 |
--------------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - access("T"."SYS_NC00014$"='X')

Note
-----
- dynamic sampling used for this statement

23 rows selected.

And here we are. This is a perfect example of how to cover queries that are not very well performing because of “!=” operator which impeaches a normal index on the corresponding column to be used.

Warning: the above FBI index will not work correctly if the status column is allowed to be null.

mhouri.world> update t
2  set status = null
3  where status != 'VALID'
4  and rownum <= 4;

4 rows updated.

mhouri.world> commit;

Commit complete.

mhouri.world> SELECT count(1)
2    FROM t
3   WHERE status != 'VALID';

COUNT(1)
----------
26

mhouri.world>  SELECT count(1)
2       FROM t
3       WHERE CASE
4               WHEN status = 'VALID'
5                  THEN NULL
6               ELSE 'X'
7            END = 'X';

COUNT(1)
----------
30

The query using the FBI index is not returning the correct number of rows because, now, the status column has null values in it.  Both the query and the FBI index should be re-factored in order to take into account the NULL values of the status column:

mhouri.world> create index ind_fbi_status on t(case when nvl(status,'VALID') = 'VALID' then null else 'X' end);

Index created.

mhouri.world> select count(1)
2  from t
3  where case when nvl(status,'VALID') = 'VALID'
4                 then null
5             else 'X'
6             end = 'X';

COUNT(1)
----------
26

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

PLAN_TABLE_OUTPUT
-------------------------------------------------------------------------------------
SQL_ID  ffj2y4c2q8vup, child number 0
-------------------------------------
select count(1) from t where case when nvl(status,'VALID') = 'VALID'
then null            else 'X'            end = 'X'
Plan hash value: 3388779105
------------------------------------------------------------------------------------
| Id  | Operation         | Name           | Rows  | Bytes | Cost (%CPU)| Time     |
------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |                |       |       |     1 (100)|          |
|   1 |  SORT AGGREGATE   |                |     1 |     5 |            |          |
|*  2 |   INDEX RANGE SCAN| IND_FBI_STATUS |     6 |    30 |     1   (0)| 00:00:01 |
------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
2 - access("T"."SYS_NC00014$"='X')

Note
-----
- dynamic sampling used for this statement

To be followed.

Advertisements

2 Comments »

  1. Another thing I’ve done in cases like this is to replace it with (in terms of this query):
    (status ‘VALID’)

    If you get OR-expansion (you might need a USE_CONCAT hint), it can take advantage of the simple index with two range scans.

    For more complicated queries, the FBI approach might be better since it doesn’t require splitting the execution plan into two branches.

    Comment by Jason Bucata — September 16, 2012 @ 4:08 pm | Reply

  2. Jason,

    Thanks again for your comments.

    Coincidently, two days ago we have been discussing in a French forum (http://www.developpez.net/forums/d1261217/bases-donnees/oracle/utilisation-in-table-million-denregistrements/) about a query having a where clause like where status in (1,2) which starts not using the index range scan on the status column when the in-list contains more than 1 value. One of the solution was to use the hint /*+ use_concat */ in order for the CBO to use union all instead of disjunctive OR.

    Function based index can help a lot in many occasions.

    Comment by Houri — September 17, 2012 @ 7:33 am | 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

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: