On Sun, Jan 27, 2013 at 3:09 AM, Paul Norman <penorman@xxxxxxx> wrote: > I am in a situation where I have two tables, a and b, each with a hstore > column called tags. Both tags columns have a GIN index on them. I want to > find rows of a and b where the both have a particular hstore key and that > key is the same. > > One way to do this would be SELECT * FROM a JOIN b ON a.tags -> 'foo' = > b.tags -> 'foo'; This would not use the indexes. > > I would like some way that makes use of the two indexes. ON a.tags @> > hstore('foo', b.tags -> 'foo') would be better, making use of the a.tags > index, but not the b.tags one. Is there any way to use both? ON a.tags @> hstore('foo', b.tags -> 'foo') does not do what you want, because if there is an a.tags of hstore('foo',NULL), then it will match every row of b whose tags does not contain the 'foo' key. You need to protect that by first checking for existence of the key: ON b.tags ? 'foo' and a.tags @> hstore('foo', b.tags -> 'foo') Which will also allow the 2nd index to be used. Cheers, Jeff -- Sent via pgsql-general mailing list (pgsql-general@xxxxxxxxxxxxxx) To make changes to your subscription: http://www.postgresql.org/mailpref/pgsql-general