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.
Support My Work
I offer SQL training, tuning and consulting. Buying my book “SQL Performance Explained” (from €9.95) also supports my work on this website.
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)