Re: BUG #1470: Boolean expression index not used when it could be - Mailing list pgsql-bugs

From Tom Lane
Subject Re: BUG #1470: Boolean expression index not used when it could be
Date
Msg-id 20239.1107983238@sss.pgh.pa.us
Whole thread Raw
In response to BUG #1470: Boolean expression index not used when it could be  ("Sergey Koshcheyev" <sergey.p.k@hotmail.com>)
Responses Re: BUG #1470: Boolean expression index not used when it could be  (Sergey Koshcheyev <sergey.p.k@gmail.com>)
List pgsql-bugs
"Sergey Koshcheyev" <sergey.p.k@hotmail.com> writes:
> I'm trying to optimize "is null" queries, since PgSQL doesn't index null
> values. I have found that creating an expression index on (column is null)
> could work, but it doesn't get used unless the index expression is part of a
> comparison. Could this be improved, so that (a boolean expression) is taken
> as equivalent to (a boolean expression = true)?

You would be better off to use a partial index:

    create index tbl1_abc on tbl1 (somecol) where abc is null;

The advantage of this is that not only do you get the is-null filter,
but you may be able to filter on some other column(s) at the same time.
For instance if you commonly query

    select ... from tbl1 where abc is null and def > 42

then making "somecol" be "def" would be a winner.

            regards, tom lane

pgsql-bugs by date:

Previous
From: "Sergey Koshcheyev"
Date:
Subject: BUG #1471: Corrected e-mail address - bug 1470
Next
From: Bruce Momjian
Date:
Subject: Re: BUG #1468: psql_dump is not backward compatible