Re: Query doesn't use index on hstore column

Поиск
Список
Период
Сортировка
От Tom Lane
Тема Re: Query doesn't use index on hstore column
Дата
Msg-id 20532.1417743170@sss.pgh.pa.us
обсуждение исходный текст
Ответ на Query doesn't use index on hstore column  (Michael Barker <mikeb01@gmail.com>)
Ответы Re: Query doesn't use index on hstore column
Список pgsql-performance
Michael Barker <mikeb01@gmail.com> writes:
> I'm currently experimenting with hstore on Posgtres 9.4rc1.  I've created a
> table with an hstore column, with and index on that column (tried both gin
> and btree indexes) and the explain plan says that the index is never used
> for the lookup and falls to a sequential scan every time (table has 1 000
> 000 rows).  The query plans and execution time for btree index, gin index
> and unindexed are the same.  Is there something I'm doing wrong or missing
> in order to get indexes to work on hstore columns?

Well, first off, a btree index is fairly useless for this query,
because btree has no concept that the hstore has any sub-structure.
A GIN index or GIST index could work though.  Secondly, you have to
remember that indexable WHERE conditions in Postgres are *always* of
the form "WHERE indexed_column indexable_operator some_comparison_value".
So the trick is to recast the condition you have into something that
looks like that.  Instead of

    WHERE attributes->'accountId' = '1879355460'

you could do

    WHERE attributes @> 'accountId=>1879355460'

(@> being the hstore containment operator, ie "does attributes contain
a pair that looks like this?") or equivalently but possibly easier to
generate,

    WHERE attributes @> hstore('accountId', '1879355460')

Another possibility if you're only concerned about indexing searches
for one or a few specific keys is to use expression indexes:

    CREATE INDEX ON audit ((attributes->'accountId'));

whereupon your original query works, since the left-hand side of
the '=' operator is now the indexed expression.  (Here, since you
are testing plain equality on the indexed value, a btree works fine.)

You might care to read
http://www.postgresql.org/docs/9.4/static/indexes.html
to get a better handle on what Postgres indexes can and can't do.

            regards, tom lane


В списке pgsql-performance по дате отправления:

Предыдущее
От: "ktm@rice.edu"
Дата:
Сообщение: Re: Query doesn't use index on hstore column
Следующее
От: Simon Riggs
Дата:
Сообщение: Re: Yet another abort-early plan disaster on 9.3