mirror of
https://github.com/postgres/postgres.git
synced 2025-07-28 23:42:10 +03:00
In the planner, replace an empty FROM clause with a dummy RTE.
The fact that "SELECT expression" has no base relations has long been a thorn in the side of the planner. It makes it hard to flatten a sub-query that looks like that, or is a trivial VALUES() item, because the planner generally uses relid sets to identify sub-relations, and such a sub-query would have an empty relid set if we flattened it. prepjointree.c contains some baroque logic that works around this in certain special cases --- but there is a much better answer. We can replace an empty FROM clause with a dummy RTE that acts like a table of one row and no columns, and then there are no such corner cases to worry about. Instead we need some logic to get rid of useless dummy RTEs, but that's simpler and covers more cases than what was there before. For really trivial cases, where the query is just "SELECT expression" and nothing else, there's a hazard that adding the extra RTE makes for a noticeable slowdown; even though it's not much processing, there's not that much for the planner to do overall. However testing says that the penalty is very small, close to the noise level. In more complex queries, this is able to find optimizations that we could not find before. The new RTE type is called RTE_RESULT, since the "scan" plan type it gives rise to is a Result node (the same plan we produced for a "SELECT expression" query before). To avoid confusion, rename the old ResultPath path type to GroupResultPath, reflecting that it's only used in degenerate grouping cases where we know the query produces just one grouped row. (It wouldn't work to unify the two cases, because there are different rules about where the associated quals live during query_planner.) Note: although this touches readfuncs.c, I don't think a catversion bump is required, because the added case can't occur in stored rules, only plans. Patch by me, reviewed by David Rowley and Mark Dilger Discussion: https://postgr.es/m/15944.1521127664@sss.pgh.pa.us
This commit is contained in:
@ -239,9 +239,9 @@ id value
|
||||
starting permutation: wrjt selectjoinforupdate c2 c1
|
||||
step wrjt: UPDATE jointest SET data = 42 WHERE id = 7;
|
||||
step selectjoinforupdate:
|
||||
set enable_nestloop to 0;
|
||||
set enable_hashjoin to 0;
|
||||
set enable_seqscan to 0;
|
||||
set local enable_nestloop to 0;
|
||||
set local enable_hashjoin to 0;
|
||||
set local enable_seqscan to 0;
|
||||
explain (costs off)
|
||||
select * from jointest a join jointest b on a.id=b.id for update;
|
||||
select * from jointest a join jointest b on a.id=b.id for update;
|
||||
@ -269,6 +269,45 @@ id data id data
|
||||
10 0 10 0
|
||||
step c1: COMMIT;
|
||||
|
||||
starting permutation: wrjt selectresultforupdate c2 c1
|
||||
step wrjt: UPDATE jointest SET data = 42 WHERE id = 7;
|
||||
step selectresultforupdate:
|
||||
select * from (select 1 as x) ss1 join (select 7 as y) ss2 on true
|
||||
left join table_a a on a.id = x, jointest jt
|
||||
where jt.id = y;
|
||||
explain (verbose, costs off)
|
||||
select * from (select 1 as x) ss1 join (select 7 as y) ss2 on true
|
||||
left join table_a a on a.id = x, jointest jt
|
||||
where jt.id = y for update of jt, ss1, ss2;
|
||||
select * from (select 1 as x) ss1 join (select 7 as y) ss2 on true
|
||||
left join table_a a on a.id = x, jointest jt
|
||||
where jt.id = y for update of jt, ss1, ss2;
|
||||
<waiting ...>
|
||||
step c2: COMMIT;
|
||||
step selectresultforupdate: <... completed>
|
||||
x y id value id data
|
||||
|
||||
1 7 1 tableAValue 7 0
|
||||
QUERY PLAN
|
||||
|
||||
LockRows
|
||||
Output: 1, 7, a.id, a.value, jt.id, jt.data, jt.ctid, a.ctid
|
||||
-> Nested Loop Left Join
|
||||
Output: 1, 7, a.id, a.value, jt.id, jt.data, jt.ctid, a.ctid
|
||||
-> Nested Loop
|
||||
Output: jt.id, jt.data, jt.ctid
|
||||
-> Seq Scan on public.jointest jt
|
||||
Output: jt.id, jt.data, jt.ctid
|
||||
Filter: (jt.id = 7)
|
||||
-> Result
|
||||
-> Seq Scan on public.table_a a
|
||||
Output: a.id, a.value, a.ctid
|
||||
Filter: (a.id = 1)
|
||||
x y id value id data
|
||||
|
||||
1 7 1 tableAValue 7 42
|
||||
step c1: COMMIT;
|
||||
|
||||
starting permutation: wrtwcte multireadwcte c1 c2
|
||||
step wrtwcte: UPDATE table_a SET value = 'tableAValue2' WHERE id = 1;
|
||||
step multireadwcte:
|
||||
|
@ -102,14 +102,29 @@ step "updateforcip" {
|
||||
# these tests exercise mark/restore during EPQ recheck, cf bug #15032
|
||||
|
||||
step "selectjoinforupdate" {
|
||||
set enable_nestloop to 0;
|
||||
set enable_hashjoin to 0;
|
||||
set enable_seqscan to 0;
|
||||
set local enable_nestloop to 0;
|
||||
set local enable_hashjoin to 0;
|
||||
set local enable_seqscan to 0;
|
||||
explain (costs off)
|
||||
select * from jointest a join jointest b on a.id=b.id for update;
|
||||
select * from jointest a join jointest b on a.id=b.id for update;
|
||||
}
|
||||
|
||||
# these tests exercise Result plan nodes participating in EPQ
|
||||
|
||||
step "selectresultforupdate" {
|
||||
select * from (select 1 as x) ss1 join (select 7 as y) ss2 on true
|
||||
left join table_a a on a.id = x, jointest jt
|
||||
where jt.id = y;
|
||||
explain (verbose, costs off)
|
||||
select * from (select 1 as x) ss1 join (select 7 as y) ss2 on true
|
||||
left join table_a a on a.id = x, jointest jt
|
||||
where jt.id = y for update of jt, ss1, ss2;
|
||||
select * from (select 1 as x) ss1 join (select 7 as y) ss2 on true
|
||||
left join table_a a on a.id = x, jointest jt
|
||||
where jt.id = y for update of jt, ss1, ss2;
|
||||
}
|
||||
|
||||
|
||||
session "s2"
|
||||
setup { BEGIN ISOLATION LEVEL READ COMMITTED; }
|
||||
@ -190,4 +205,5 @@ permutation "updateforcip" "updateforcip2" "c1" "c2" "read_a"
|
||||
permutation "updateforcip" "updateforcip3" "c1" "c2" "read_a"
|
||||
permutation "wrtwcte" "readwcte" "c1" "c2"
|
||||
permutation "wrjt" "selectjoinforupdate" "c2" "c1"
|
||||
permutation "wrjt" "selectresultforupdate" "c2" "c1"
|
||||
permutation "wrtwcte" "multireadwcte" "c1" "c2"
|
||||
|
@ -31,6 +31,10 @@ INSERT INTO J2_TBL VALUES (5, -5);
|
||||
INSERT INTO J2_TBL VALUES (0, NULL);
|
||||
INSERT INTO J2_TBL VALUES (NULL, NULL);
|
||||
INSERT INTO J2_TBL VALUES (NULL, 0);
|
||||
-- useful in some tests below
|
||||
create temp table onerow();
|
||||
insert into onerow default values;
|
||||
analyze onerow;
|
||||
--
|
||||
-- CORRELATION NAMES
|
||||
-- Make sure that table/column aliases are supported
|
||||
@ -2227,20 +2231,17 @@ explain (costs off)
|
||||
select * from int8_tbl i1 left join (int8_tbl i2 join
|
||||
(select 123 as x) ss on i2.q1 = x) on i1.q2 = i2.q2
|
||||
order by 1, 2;
|
||||
QUERY PLAN
|
||||
-------------------------------------------------
|
||||
QUERY PLAN
|
||||
-------------------------------------------
|
||||
Sort
|
||||
Sort Key: i1.q1, i1.q2
|
||||
-> Hash Left Join
|
||||
Hash Cond: (i1.q2 = i2.q2)
|
||||
-> Seq Scan on int8_tbl i1
|
||||
-> Hash
|
||||
-> Hash Join
|
||||
Hash Cond: (i2.q1 = (123))
|
||||
-> Seq Scan on int8_tbl i2
|
||||
-> Hash
|
||||
-> Result
|
||||
(11 rows)
|
||||
-> Seq Scan on int8_tbl i2
|
||||
Filter: (q1 = 123)
|
||||
(8 rows)
|
||||
|
||||
select * from int8_tbl i1 left join (int8_tbl i2 join
|
||||
(select 123 as x) ss on i2.q1 = x) on i1.q2 = i2.q2
|
||||
@ -3133,8 +3134,8 @@ select t1.unique2, t1.stringu1, t2.unique1, t2.stringu2 from
|
||||
tenk1 t1
|
||||
inner join int4_tbl i1
|
||||
left join (select v1.x2, v2.y1, 11 AS d1
|
||||
from (values(1,0)) v1(x1,x2)
|
||||
left join (values(3,1)) v2(y1,y2)
|
||||
from (select 1,0 from onerow) v1(x1,x2)
|
||||
left join (select 3,1 from onerow) v2(y1,y2)
|
||||
on v1.x1 = v2.y2) subq1
|
||||
on (i1.f1 = subq1.x2)
|
||||
on (t1.unique2 = subq1.d1)
|
||||
@ -3144,27 +3145,26 @@ where t1.unique2 < 42 and t1.stringu1 > t2.stringu2;
|
||||
QUERY PLAN
|
||||
-----------------------------------------------------------------------
|
||||
Nested Loop
|
||||
Join Filter: (t1.stringu1 > t2.stringu2)
|
||||
-> Nested Loop
|
||||
Join Filter: ((0) = i1.f1)
|
||||
Join Filter: (t1.stringu1 > t2.stringu2)
|
||||
-> Nested Loop
|
||||
-> Nested Loop
|
||||
Join Filter: ((1) = (1))
|
||||
-> Result
|
||||
-> Result
|
||||
-> Seq Scan on onerow
|
||||
-> Seq Scan on onerow onerow_1
|
||||
-> Index Scan using tenk1_unique2 on tenk1 t1
|
||||
Index Cond: ((unique2 = (11)) AND (unique2 < 42))
|
||||
-> Seq Scan on int4_tbl i1
|
||||
-> Index Scan using tenk1_unique1 on tenk1 t2
|
||||
Index Cond: (unique1 = (3))
|
||||
(14 rows)
|
||||
-> Index Scan using tenk1_unique1 on tenk1 t2
|
||||
Index Cond: (unique1 = (3))
|
||||
-> Seq Scan on int4_tbl i1
|
||||
Filter: (f1 = 0)
|
||||
(13 rows)
|
||||
|
||||
select t1.unique2, t1.stringu1, t2.unique1, t2.stringu2 from
|
||||
tenk1 t1
|
||||
inner join int4_tbl i1
|
||||
left join (select v1.x2, v2.y1, 11 AS d1
|
||||
from (values(1,0)) v1(x1,x2)
|
||||
left join (values(3,1)) v2(y1,y2)
|
||||
from (select 1,0 from onerow) v1(x1,x2)
|
||||
left join (select 3,1 from onerow) v2(y1,y2)
|
||||
on v1.x1 = v2.y2) subq1
|
||||
on (i1.f1 = subq1.x2)
|
||||
on (t1.unique2 = subq1.d1)
|
||||
@ -3196,6 +3196,50 @@ where t1.unique1 < i4.f1;
|
||||
----
|
||||
(0 rows)
|
||||
|
||||
-- this variant is foldable by the remove-useless-RESULT-RTEs code
|
||||
explain (costs off)
|
||||
select t1.unique2, t1.stringu1, t2.unique1, t2.stringu2 from
|
||||
tenk1 t1
|
||||
inner join int4_tbl i1
|
||||
left join (select v1.x2, v2.y1, 11 AS d1
|
||||
from (values(1,0)) v1(x1,x2)
|
||||
left join (values(3,1)) v2(y1,y2)
|
||||
on v1.x1 = v2.y2) subq1
|
||||
on (i1.f1 = subq1.x2)
|
||||
on (t1.unique2 = subq1.d1)
|
||||
left join tenk1 t2
|
||||
on (subq1.y1 = t2.unique1)
|
||||
where t1.unique2 < 42 and t1.stringu1 > t2.stringu2;
|
||||
QUERY PLAN
|
||||
-----------------------------------------------------------------
|
||||
Nested Loop
|
||||
Join Filter: (t1.stringu1 > t2.stringu2)
|
||||
-> Nested Loop
|
||||
-> Seq Scan on int4_tbl i1
|
||||
Filter: (f1 = 0)
|
||||
-> Index Scan using tenk1_unique2 on tenk1 t1
|
||||
Index Cond: ((unique2 = (11)) AND (unique2 < 42))
|
||||
-> Index Scan using tenk1_unique1 on tenk1 t2
|
||||
Index Cond: (unique1 = (3))
|
||||
(9 rows)
|
||||
|
||||
select t1.unique2, t1.stringu1, t2.unique1, t2.stringu2 from
|
||||
tenk1 t1
|
||||
inner join int4_tbl i1
|
||||
left join (select v1.x2, v2.y1, 11 AS d1
|
||||
from (values(1,0)) v1(x1,x2)
|
||||
left join (values(3,1)) v2(y1,y2)
|
||||
on v1.x1 = v2.y2) subq1
|
||||
on (i1.f1 = subq1.x2)
|
||||
on (t1.unique2 = subq1.d1)
|
||||
left join tenk1 t2
|
||||
on (subq1.y1 = t2.unique1)
|
||||
where t1.unique2 < 42 and t1.stringu1 > t2.stringu2;
|
||||
unique2 | stringu1 | unique1 | stringu2
|
||||
---------+----------+---------+----------
|
||||
11 | WFAAAA | 3 | LKIAAA
|
||||
(1 row)
|
||||
|
||||
--
|
||||
-- test extraction of restriction OR clauses from join OR clause
|
||||
-- (we used to only do this for indexable clauses)
|
||||
@ -3596,7 +3640,7 @@ select t1.* from
|
||||
-> Hash Right Join
|
||||
Output: i8.q2
|
||||
Hash Cond: ((NULL::integer) = i8b1.q2)
|
||||
-> Hash Left Join
|
||||
-> Hash Join
|
||||
Output: i8.q2, (NULL::integer)
|
||||
Hash Cond: (i8.q1 = i8b2.q1)
|
||||
-> Seq Scan on public.int8_tbl i8
|
||||
@ -4018,10 +4062,10 @@ select * from
|
||||
QUERY PLAN
|
||||
---------------------------------------
|
||||
Nested Loop Left Join
|
||||
Join Filter: ((1) = COALESCE((1)))
|
||||
-> Result
|
||||
-> Hash Full Join
|
||||
Hash Cond: (a1.unique1 = (1))
|
||||
Filter: (1 = COALESCE((1)))
|
||||
-> Seq Scan on tenk1 a1
|
||||
-> Hash
|
||||
-> Result
|
||||
@ -4951,13 +4995,10 @@ select v.* from
|
||||
-4567890123456789 |
|
||||
(20 rows)
|
||||
|
||||
create temp table dual();
|
||||
insert into dual default values;
|
||||
analyze dual;
|
||||
select v.* from
|
||||
(int8_tbl x left join (select q1,(select coalesce(q2,0)) q2 from int8_tbl) y on x.q2 = y.q1)
|
||||
left join int4_tbl z on z.f1 = x.q2,
|
||||
lateral (select x.q1,y.q1 from dual union all select x.q2,y.q2 from dual) v(vx,vy);
|
||||
lateral (select x.q1,y.q1 from onerow union all select x.q2,y.q2 from onerow) v(vx,vy);
|
||||
vx | vy
|
||||
-------------------+-------------------
|
||||
4567890123456789 | 123
|
||||
|
@ -999,7 +999,7 @@ select * from
|
||||
QUERY PLAN
|
||||
----------------------------------------------------------
|
||||
Subquery Scan on ss
|
||||
Output: x, u
|
||||
Output: ss.x, ss.u
|
||||
Filter: tattle(ss.x, 8)
|
||||
-> ProjectSet
|
||||
Output: 9, unnest('{1,2,3,11,12,13}'::integer[])
|
||||
@ -1061,7 +1061,7 @@ select * from
|
||||
QUERY PLAN
|
||||
----------------------------------------------------------
|
||||
Subquery Scan on ss
|
||||
Output: x, u
|
||||
Output: ss.x, ss.u
|
||||
Filter: tattle(ss.x, ss.u)
|
||||
-> ProjectSet
|
||||
Output: 9, unnest('{1,2,3,11,12,13}'::integer[])
|
||||
|
@ -37,6 +37,12 @@ INSERT INTO J2_TBL VALUES (0, NULL);
|
||||
INSERT INTO J2_TBL VALUES (NULL, NULL);
|
||||
INSERT INTO J2_TBL VALUES (NULL, 0);
|
||||
|
||||
-- useful in some tests below
|
||||
create temp table onerow();
|
||||
insert into onerow default values;
|
||||
analyze onerow;
|
||||
|
||||
|
||||
--
|
||||
-- CORRELATION NAMES
|
||||
-- Make sure that table/column aliases are supported
|
||||
@ -940,8 +946,8 @@ select t1.unique2, t1.stringu1, t2.unique1, t2.stringu2 from
|
||||
tenk1 t1
|
||||
inner join int4_tbl i1
|
||||
left join (select v1.x2, v2.y1, 11 AS d1
|
||||
from (values(1,0)) v1(x1,x2)
|
||||
left join (values(3,1)) v2(y1,y2)
|
||||
from (select 1,0 from onerow) v1(x1,x2)
|
||||
left join (select 3,1 from onerow) v2(y1,y2)
|
||||
on v1.x1 = v2.y2) subq1
|
||||
on (i1.f1 = subq1.x2)
|
||||
on (t1.unique2 = subq1.d1)
|
||||
@ -953,8 +959,8 @@ select t1.unique2, t1.stringu1, t2.unique1, t2.stringu2 from
|
||||
tenk1 t1
|
||||
inner join int4_tbl i1
|
||||
left join (select v1.x2, v2.y1, 11 AS d1
|
||||
from (values(1,0)) v1(x1,x2)
|
||||
left join (values(3,1)) v2(y1,y2)
|
||||
from (select 1,0 from onerow) v1(x1,x2)
|
||||
left join (select 3,1 from onerow) v2(y1,y2)
|
||||
on v1.x1 = v2.y2) subq1
|
||||
on (i1.f1 = subq1.x2)
|
||||
on (t1.unique2 = subq1.d1)
|
||||
@ -980,6 +986,35 @@ select ss1.d1 from
|
||||
on t1.tenthous = ss1.d1
|
||||
where t1.unique1 < i4.f1;
|
||||
|
||||
-- this variant is foldable by the remove-useless-RESULT-RTEs code
|
||||
|
||||
explain (costs off)
|
||||
select t1.unique2, t1.stringu1, t2.unique1, t2.stringu2 from
|
||||
tenk1 t1
|
||||
inner join int4_tbl i1
|
||||
left join (select v1.x2, v2.y1, 11 AS d1
|
||||
from (values(1,0)) v1(x1,x2)
|
||||
left join (values(3,1)) v2(y1,y2)
|
||||
on v1.x1 = v2.y2) subq1
|
||||
on (i1.f1 = subq1.x2)
|
||||
on (t1.unique2 = subq1.d1)
|
||||
left join tenk1 t2
|
||||
on (subq1.y1 = t2.unique1)
|
||||
where t1.unique2 < 42 and t1.stringu1 > t2.stringu2;
|
||||
|
||||
select t1.unique2, t1.stringu1, t2.unique1, t2.stringu2 from
|
||||
tenk1 t1
|
||||
inner join int4_tbl i1
|
||||
left join (select v1.x2, v2.y1, 11 AS d1
|
||||
from (values(1,0)) v1(x1,x2)
|
||||
left join (values(3,1)) v2(y1,y2)
|
||||
on v1.x1 = v2.y2) subq1
|
||||
on (i1.f1 = subq1.x2)
|
||||
on (t1.unique2 = subq1.d1)
|
||||
left join tenk1 t2
|
||||
on (subq1.y1 = t2.unique1)
|
||||
where t1.unique2 < 42 and t1.stringu1 > t2.stringu2;
|
||||
|
||||
--
|
||||
-- test extraction of restriction OR clauses from join OR clause
|
||||
-- (we used to only do this for indexable clauses)
|
||||
@ -1661,13 +1696,10 @@ select v.* from
|
||||
(int8_tbl x left join (select q1,(select coalesce(q2,0)) q2 from int8_tbl) y on x.q2 = y.q1)
|
||||
left join int4_tbl z on z.f1 = x.q2,
|
||||
lateral (select x.q1,y.q1 union all select x.q2,y.q2) v(vx,vy);
|
||||
create temp table dual();
|
||||
insert into dual default values;
|
||||
analyze dual;
|
||||
select v.* from
|
||||
(int8_tbl x left join (select q1,(select coalesce(q2,0)) q2 from int8_tbl) y on x.q2 = y.q1)
|
||||
left join int4_tbl z on z.f1 = x.q2,
|
||||
lateral (select x.q1,y.q1 from dual union all select x.q2,y.q2 from dual) v(vx,vy);
|
||||
lateral (select x.q1,y.q1 from onerow union all select x.q2,y.q2 from onerow) v(vx,vy);
|
||||
|
||||
explain (verbose, costs off)
|
||||
select * from
|
||||
|
Reference in New Issue
Block a user