Re: Query doesn't use index on hstore column

From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: Michael Barker <mikeb01(at)gmail(dot)com>
Cc: pgsql-performance <pgsql-performance(at)postgresql(dot)org>
Subject: Re: Query doesn't use index on hstore column
Date: 2014-12-05 01:32:50
Message-ID: 20532.1417743170@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-performance

Michael Barker <mikeb01(at)gmail(dot)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

In response to

Responses

Browse pgsql-performance by date

  From Date Subject
Next Message Simon Riggs 2014-12-05 06:46:15 Re: Yet another abort-early plan disaster on 9.3
Previous Message ktm@rice.edu 2014-12-04 21:46:25 Re: Query doesn't use index on hstore column