Emulating Partial Indexes in the Oracle Database


The strange way the Oracle database handles NULL in indexes can be used to emulate partial indexes. For that, we just have to use NULL for rows that should not be indexed.

To demonstrate, we emulate the following partial index:

CREATE INDEX messages_todo
          ON messages (receiver)
       WHERE processed = 'N'

First, we need a function that returns the RECEIVER value only if the PROCESSED value is 'N'.

CREATE OR REPLACE
FUNCTION pi_processed(processed CHAR, receiver NUMBER)
RETURN NUMBER
DETERMINISTIC
AS BEGIN
   IF processed IN ('N') THEN
      RETURN receiver;
   ELSE
      RETURN NULL;
   END IF;
END;
/

The function must be deterministic so it can be used in an index definition.

There is something for everyone:
training, tuning and literature on SQL performance

Now we can create an index that contains only the rows having PROCESSED='N'.

CREATE INDEX messages_todo
          ON messages (pi_processed(processed, receiver));

To use the index, you must use the indexed expression in the query:

SELECT message
  FROM messages
 WHERE pi_processed(processed, receiver) = ?
???----------------------------------------------------------
|Id | Operation                   | Name          | Cost |
----------------------------------------------------------
| 0 | SELECT STATEMENT            |               | 5330 |
| 1 |  TABLE ACCESS BY INDEX ROWID| MESSAGES      | 5330 |
|*2 |   INDEX RANGE SCAN          | MESSAGES_TODO | 5303 |
----------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - access("PI_PROCESSED"("PROCESSED","RECEIVER")=:X)

Partial Indexes, Part II

As of release 11g, there is a second—equally scary—approach to emulating partial indexes in the Oracle database by using an intentionally broken index partition and the SKIP_UNUSABLE_INDEX parameter.

If you like my way of explaining things, you’ll love my book.

About the Author

As an author, trainer, and coach Markus Winand specializes in helping developers cope with SQL performance issues. He also published the book SQL Performance Explained and tweets his best performance tips via @SQLPerfTips.http://winand.at/

Recent Questions at Ask.Use-The-Index-Luke.com

0
votes
1
answer
58
views

We want to buy the book but I can't

Jul 18 at 21:36 Markus Winand ♦♦ 541
book
0
votes
2
answers
120
views
0
votes
0
answers
780
views

Performance very bad in Postgresql 9.3

Jul 08 at 11:54 Markus Winand ♦♦ 541
performance issue