"Martijn van Oosterhout" <kleptog@xxxxxxxxx> writes: > On Fri, Nov 30, 2007 at 08:21:18AM -0500, Josh Harrison wrote: >> > > *Query1* >> > > SELECT person_id FROM person WHERE (column1=1 AND column2='62') >> > > INTERSECT >> > > SELECT person_id FROM person WHERE (column1=1 AND column2='189') > >> I get the same plan(see below) with 'sort' for 'intersect all' operation >> too. Why is intersect not an effecient way? Is there any other way this >> query/index can be written/created so that I can get the intersect results >> in an efficient way? > > Set operations are rather inefficient. To find the intersection of two > arbitrary sets you need to sort them and compare. I think all the set operations are implemented this way. It's actually a pretty clever plan if you're processing two large lists without indexes but, it would be nice to support a fuller set of plans like we do for other kinds of queries. For INTERSECT star-schema joins might actually be best. > A query like you write would be better expressed as a join, something like: > > SELECT a.person_id > FROM (SELECT person_id FROM person WHERE (column1=1 AND column2='62') a, > (SELECT person_id FROM person WHERE (column1=1 AND column2='189') b > WHERE a.person_id = b.person_id; > > or perhaps: > > SELECT a.person_id > FROM person a, person b > WHERE a.column1=1 AND a.column2='62' > AND b.column1=1 AND b.column2='189' > AND a.person_id = b.person_id; Or using an IN or EXISTS query: SELECT person_id FROM person WHERE column1=1 AND column2='62' AND person_id IN ( SELECT person_id FROM person WHERE column1=1 AND column2='189' ) or SELECT person_id FROM person AS parent WHERE column1=1 AND column2='62' AND EXISTS ( SELECT 1 FROM person WHERE parent.person_id = person_id AND column1=1 AND column2='189' ) -- Gregory Stark EnterpriseDB http://www.enterprisedb.com Ask me about EnterpriseDB's 24x7 Postgres support! ---------------------------(end of broadcast)--------------------------- TIP 3: Have you checked our extensive FAQ? http://www.postgresql.org/docs/faq