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.

About our book “SQL Performance Explained”
An indispensable manual for anyone, DBA, developer or system administrator
Luigi Zambetti on Amazon.co.uk (5 stars)

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) = ?
Try online at SQL Fiddle----------------------------------------------------------
|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

Photo of Markus Winand
Markus Winand tunes developers for high SQL performance. He also published the book SQL Performance Explained and offers in-house training as well as remote coaching at http://winand.at/

?Recent questions at
Ask.Use-The-Index-Luke.com

0
votes
0
answers
46
views

PostgreSQL Bitmap Heap Scan on index is very slow but Index Only Scan is fast

11 mins ago user1337 1
index postgresql postgres sql
3
votes
2
answers
353
views

pagination with nulls

yesterday Rocky 46
pagination
0
votes
2
answers
63
views