I would use 2 left joins and use the where condition to make sure one of them is true, such as:
select big_table.* from big_table left join little_table as l1 on big_table.y1=l1.y and l1.x=10 left join little_table as l2 on big_table.y2=l2.y and l1.x=10 where l1.p_key is not null and l2.p_key is not null I have never tried this in postgresql, but in my experience with various other DB engines it is a lot faster then using an or in the join and faster then a union. Thank You Sim Zacks IT Manager CompuLab 04-829-0145 - Office 04-832-5251 - Fax ________________________________________________________________________________ Hello. I have a query like: SELECT big_table.* FROM little_table, big_table WHERE little_table.x = 10 AND little_table.y IN (big_table.y1, big_table.y2); I have indexes on both big_table.y1 and big_table.y2 and on little_table.x and little_table.y. The result is a sequential scan of big_table. In order to prevent this, I've rewritten the query as: SELECT big_table.* FROM little_table, big_table WHERE little_table.x = 10 AND little_table.y = big_table.y1 UNION SELECT big_table.* FROM little_table, big_table WHERE little_table.x = 10 AND little_table.y = big_table.y2 which does allow an index scan, but suffers from two separate queries along with a unique sort, which, from the data, represents 90% of the tuples returned by both queries. Is there any way to write the first query such that indexes will be used? Mike Mascari ---------------------------(end of broadcast)--------------------------- TIP 3: if posting/reading through Usenet, please send an appropriate subscribe-nomail command to [EMAIL PROTECTED] so that your message can get through to the mailing list cleanly ---------------------------(end of broadcast)--------------------------- TIP 5: Have you checked our extensive FAQ? http://www.postgresql.org/docs/faqs/FAQ.html