Re: Multiple-Table-Spanning Joins with ORs in WHERE Clause - Mailing list pgsql-performance

From Igor Neyman
Subject Re: Multiple-Table-Spanning Joins with ORs in WHERE Clause
Date
Msg-id CY4PR07MB2872B533247E5C8753E11956DAC90@CY4PR07MB2872.namprd07.prod.outlook.com
Whole thread Raw
In response to Multiple-Table-Spanning Joins with ORs in WHERE Clause  ("Sven R. Kunze" <srkunze@mail.de>)
List pgsql-performance
-----Original Message-----
From: pgsql-performance-owner@postgresql.org [mailto:pgsql-performance-owner@postgresql.org] On Behalf Of Sven R.
Kunze
Sent: Thursday, September 22, 2016 9:25 AM
To: pgsql-performance@postgresql.org
Subject: [PERFORM] Multiple-Table-Spanning Joins with ORs in WHERE Clause

Hi pgsql-performance list,


what is the recommended way of doing **multiple-table-spanning joins with ORs in the WHERE-clause**?


Until now, we've used the LEFT OUTER JOIN to filter big_table like so:


SELECT DISTINCT <fields of big_table>
FROM
     "big_table"
     LEFT OUTER JOIN "table_a" ON ("big_table"."id" = 
"table_a"."big_table_id")
     LEFT OUTER JOIN "table_b" ON ("big_table"."id" = 
"table_b"."big_table_id")
WHERE
     "table_a"."item_id" IN (<handful of items>)
     OR
     "table_b"."item_id" IN (<handful of items>);


However, this results in an awful slow plan (requiring to scan the 
complete big_table which obviously isn't optimal).
So, we decided (at least for now) to split up the query into two 
separate ones and merge/de-duplicate the result with application logic:


SELECT <fields of big_table>
FROM
     "big_table" INNER JOIN "table_a" ON ("big_table"."id" = 
"table_a"."big_table_id")
WHERE
     "table_a"."item_id" IN (<handful of items>);


SELECT <fields of big_table>
FROM
     "big_table" INNER JOIN "table_b" ON ("big_table"."id" = 
"table_b"."big_table_id")
WHERE
     "table_b"."item_id" IN (<handful of items>);


As you can imagine we would be very glad to solve this issue with a 
single query and without having to re-code existing logic of PostgreSQL. 
But how?


Best,
Sven


PS: if you require EXPLAIN ANALYZE, I can post them as well.

______________________________________________________________________________________________

What about:

SELECT <fields of big_table>
FROM
     "big_table" INNER JOIN "table_a" ON ("big_table"."id" = 
"table_a"."big_table_id")
WHERE
     "table_a"."item_id" IN (<handful of items>)
UNION
SELECT <fields of big_table>
FROM
     "big_table" INNER JOIN "table_b" ON ("big_table"."id" = 
"table_b"."big_table_id")
WHERE
     "table_b"."item_id" IN (<handful of items>);


Regards,
Igor Neyman


pgsql-performance by date:

Previous
From: Igor Neyman
Date:
Subject: Re: Problem with performance using query with unnest after migrating from V9.1 to V9.2 and higher
Next
From: Tom Lane
Date:
Subject: Re: Problem with performance using query with unnest after migrating from V9.1 to V9.2 and higher