How to prevent Firebird from using an index in the query?
Although the query optimizer is doing its best to choose the appropriate indexes in queries, it may sometimes happen that you see an index in query plan that you think should not be used (because of low selectivity, etc.)
It might help to recalculate index statitics using SET STATISTICS command, but if you really just want to avoid using index, you can add +0 or ||'' to the integer or string column. Example:
SELECT * FROM EMPLOYEE where LAST_NAME = 'Nelson';
PLAN (EMPLOYEE INDEX (NAMEX))
To disable use of NAMEX index we use:
SELECT * FROM EMPLOYEE where LAST_NAME||'' = 'Nelson';
PLAN (EMPLOYEE NATURAL)
Here's an integer example also:
SELECT * FROM EMPLOYEE where EMP_NO > 2;
PLAN (EMPLOYEE INDEX (RDB$PRIMARY7))
SELECT * FROM EMPLOYEE where EMP_NO+0 > 2;
PLAN (EMPLOYEE NATURAL)
Another common practice is to add some expression that evaluates to false, for example 1 = 0. Example:
SELECT * FROM EMPLOYEE where EMP_NO > 2 OR 1 = 0;
PLAN (EMPLOYEE NATURAL)