mirror of
https://github.com/postgres/postgres.git
synced 2025-07-28 23:42:10 +03:00
Allow simplification of EXISTS() subqueries containing LIMIT.
The locution "EXISTS(SELECT ... LIMIT 1)" seems to be rather common among people who don't realize that the database already performs optimizations equivalent to putting LIMIT 1 in the sub-select. Unfortunately, this was actually making things worse, because it prevented us from optimizing such EXISTS clauses into semi or anti joins. Teach simplify_EXISTS_query() to suppress constant-positive LIMIT clauses. That fixes the semi/anti-join case, and may help marginally even for cases that have to be left as sub-SELECTs. Marti Raudsepp, reviewed by David Rowley
This commit is contained in:
@ -221,6 +221,46 @@ from int8_tbl group by q1 order by q1;
|
||||
4567890123456789 | 0.6
|
||||
(2 rows)
|
||||
|
||||
--
|
||||
-- Check EXISTS simplification with LIMIT
|
||||
--
|
||||
explain (costs off)
|
||||
select * from int4_tbl o where exists
|
||||
(select 1 from int4_tbl i where i.f1=o.f1 limit null);
|
||||
QUERY PLAN
|
||||
------------------------------------
|
||||
Hash Semi Join
|
||||
Hash Cond: (o.f1 = i.f1)
|
||||
-> Seq Scan on int4_tbl o
|
||||
-> Hash
|
||||
-> Seq Scan on int4_tbl i
|
||||
(5 rows)
|
||||
|
||||
explain (costs off)
|
||||
select * from int4_tbl o where not exists
|
||||
(select 1 from int4_tbl i where i.f1=o.f1 limit 1);
|
||||
QUERY PLAN
|
||||
------------------------------------
|
||||
Hash Anti Join
|
||||
Hash Cond: (o.f1 = i.f1)
|
||||
-> Seq Scan on int4_tbl o
|
||||
-> Hash
|
||||
-> Seq Scan on int4_tbl i
|
||||
(5 rows)
|
||||
|
||||
explain (costs off)
|
||||
select * from int4_tbl o where exists
|
||||
(select 1 from int4_tbl i where i.f1=o.f1 limit 0);
|
||||
QUERY PLAN
|
||||
--------------------------------------
|
||||
Seq Scan on int4_tbl o
|
||||
Filter: (SubPlan 1)
|
||||
SubPlan 1
|
||||
-> Limit
|
||||
-> Seq Scan on int4_tbl i
|
||||
Filter: (f1 = o.f1)
|
||||
(6 rows)
|
||||
|
||||
--
|
||||
-- Test cases to catch unpleasant interactions between IN-join processing
|
||||
-- and subquery pullup.
|
||||
|
@ -92,6 +92,19 @@ SELECT '' AS eight, ss.f1 AS "Correlated Field", ss.f3 AS "Second Field"
|
||||
select q1, float8(count(*)) / (select count(*) from int8_tbl)
|
||||
from int8_tbl group by q1 order by q1;
|
||||
|
||||
--
|
||||
-- Check EXISTS simplification with LIMIT
|
||||
--
|
||||
explain (costs off)
|
||||
select * from int4_tbl o where exists
|
||||
(select 1 from int4_tbl i where i.f1=o.f1 limit null);
|
||||
explain (costs off)
|
||||
select * from int4_tbl o where not exists
|
||||
(select 1 from int4_tbl i where i.f1=o.f1 limit 1);
|
||||
explain (costs off)
|
||||
select * from int4_tbl o where exists
|
||||
(select 1 from int4_tbl i where i.f1=o.f1 limit 0);
|
||||
|
||||
--
|
||||
-- Test cases to catch unpleasant interactions between IN-join processing
|
||||
-- and subquery pullup.
|
||||
|
Reference in New Issue
Block a user