Обсуждение: unexpected query failure: ERROR: GIN indexes do not support whole-index scans

Поиск
Список
Период
Сортировка

unexpected query failure: ERROR: GIN indexes do not support whole-index scans

От
Jon Nelson
Дата:
I have a table with an array column.
I added a GIN index to the array:

CREATE INDEX foo_idx ON t USING GIN (alternatecodes) WHERE
alternatecodes IS NOT NULL;

That's all well and good.
However, some queries started failing and I was able to reproduce the
behavior in psql!

SELECT * FROM t WHERE alternatecodes IS NOT NULL;
returns:
ERROR:  GIN indexes do not support whole-index scans

Whaaa?  Adding an *index* makes my /queries/ stop working? How can this be?
This really violated my principle of least surprise. If GIN indexes
don't support whole-index scans, fine, don't use them, but don't make
a perfectly valid query fail because of it.

This seems like a bug. Is it?

PostgreSQL version:

 PostgreSQL 8.4.5 on x86_64-redhat-linux-gnu, compiled by GCC gcc
(GCC) 4.1.2 20080704 (Red Hat 4.1.2-48), 64-bit


--
Jon

Re: unexpected query failure: ERROR: GIN indexes do not support whole-index scans

От
Tom Lane
Дата:
Jon Nelson <jnelson+pgsql@jamponi.net> writes:
> CREATE INDEX foo_idx ON t USING GIN (alternatecodes) WHERE
> alternatecodes IS NOT NULL;
> SELECT * FROM t WHERE alternatecodes IS NOT NULL;
> ERROR:  GIN indexes do not support whole-index scans

Yep, this is a known issue.  It's going to take major surgery on GIN to
fix it, so don't hold your breath.  In the particular case, what good do
you think the WHERE clause is doing anyway?  GIN won't index nulls at
all ... which indeed is an aspect of the underlying issue --- see recent
discussions, eg here:
http://archives.postgresql.org/pgsql-hackers/2010-10/msg00521.php

            regards, tom lane

Re: unexpected query failure: ERROR: GIN indexes do not support whole-index scans

От
Jon Nelson
Дата:
On Mon, Oct 18, 2010 at 6:01 PM, Tom Lane <tgl@sss.pgh.pa.us> wrote:
> Jon Nelson <jnelson+pgsql@jamponi.net> writes:
>> CREATE INDEX foo_idx ON t USING GIN (alternatecodes) WHERE
>> alternatecodes IS NOT NULL;
>> SELECT * FROM t WHERE alternatecodes IS NOT NULL;
>> ERROR:  GIN indexes do not support whole-index scans
>
> Yep, this is a known issue.  It's going to take major surgery on GIN to
> fix it, so don't hold your breath.  In the particular case, what good do
> you think the WHERE clause is doing anyway?  GIN won't index nulls at
> all ... which indeed is an aspect of the underlying issue --- see recent
> discussions, eg here:
> http://archives.postgresql.org/pgsql-hackers/2010-10/msg00521.php

OK, so GIN doesn't index NULLs. I guess the "IS NOT NULL" part comes
about as a habit - that particular column is fairly sparse. However,
I'm honestly quite surprised at two things:

1. if GIN indexes ignore NULLs, then either it should grump when one
specifics "WHERE ... IS NOT NULL" or it should be treated as a no-op

2. (and this is by far the more surprising) that the /presence/ of an
INDEX can *break* a SELECT. It's not that the engine ignores the index
- that would be reasonable - but that I can't issue a SELECT with a
WHERE statement that matches the same as the index.

However, I see that this also surprised Josh Berkus, and not that long
ago (11 days!), so I'll just shush.

Thanks!



--
Jon