summaryrefslogtreecommitdiff
path: root/src/test
diff options
context:
space:
mode:
Diffstat (limited to 'src/test')
-rw-r--r--src/test/regress/expected/join.out263
-rw-r--r--src/test/regress/sql/join.sql41
2 files changed, 265 insertions, 39 deletions
diff --git a/src/test/regress/expected/join.out b/src/test/regress/expected/join.out
index 814ddd80469..fc3e1688068 100644
--- a/src/test/regress/expected/join.out
+++ b/src/test/regress/expected/join.out
@@ -3577,6 +3577,195 @@ select v.* from
-4567890123456789 |
(20 rows)
+explain (verbose, costs off)
+select * from
+ int8_tbl a left join
+ lateral (select *, a.q2 as x from int8_tbl b) ss on a.q2 = ss.q1;
+ QUERY PLAN
+------------------------------------------
+ Nested Loop Left Join
+ Output: a.q1, a.q2, b.q1, b.q2, (a.q2)
+ -> Seq Scan on public.int8_tbl a
+ Output: a.q1, a.q2
+ -> Seq Scan on public.int8_tbl b
+ Output: b.q1, b.q2, a.q2
+ Filter: (a.q2 = b.q1)
+(7 rows)
+
+select * from
+ int8_tbl a left join
+ lateral (select *, a.q2 as x from int8_tbl b) ss on a.q2 = ss.q1;
+ q1 | q2 | q1 | q2 | x
+------------------+-------------------+------------------+-------------------+------------------
+ 123 | 456 | | |
+ 123 | 4567890123456789 | 4567890123456789 | 123 | 4567890123456789
+ 123 | 4567890123456789 | 4567890123456789 | 4567890123456789 | 4567890123456789
+ 123 | 4567890123456789 | 4567890123456789 | -4567890123456789 | 4567890123456789
+ 4567890123456789 | 123 | 123 | 456 | 123
+ 4567890123456789 | 123 | 123 | 4567890123456789 | 123
+ 4567890123456789 | 4567890123456789 | 4567890123456789 | 123 | 4567890123456789
+ 4567890123456789 | 4567890123456789 | 4567890123456789 | 4567890123456789 | 4567890123456789
+ 4567890123456789 | 4567890123456789 | 4567890123456789 | -4567890123456789 | 4567890123456789
+ 4567890123456789 | -4567890123456789 | | |
+(10 rows)
+
+explain (verbose, costs off)
+select * from
+ int8_tbl a left join
+ lateral (select *, coalesce(a.q2, 42) as x from int8_tbl b) ss on a.q2 = ss.q1;
+ QUERY PLAN
+----------------------------------------------------------------
+ Nested Loop Left Join
+ Output: a.q1, a.q2, b.q1, b.q2, (COALESCE(a.q2, 42::bigint))
+ -> Seq Scan on public.int8_tbl a
+ Output: a.q1, a.q2
+ -> Seq Scan on public.int8_tbl b
+ Output: b.q1, b.q2, COALESCE(a.q2, 42::bigint)
+ Filter: (a.q2 = b.q1)
+(7 rows)
+
+select * from
+ int8_tbl a left join
+ lateral (select *, coalesce(a.q2, 42) as x from int8_tbl b) ss on a.q2 = ss.q1;
+ q1 | q2 | q1 | q2 | x
+------------------+-------------------+------------------+-------------------+------------------
+ 123 | 456 | | |
+ 123 | 4567890123456789 | 4567890123456789 | 123 | 4567890123456789
+ 123 | 4567890123456789 | 4567890123456789 | 4567890123456789 | 4567890123456789
+ 123 | 4567890123456789 | 4567890123456789 | -4567890123456789 | 4567890123456789
+ 4567890123456789 | 123 | 123 | 456 | 123
+ 4567890123456789 | 123 | 123 | 4567890123456789 | 123
+ 4567890123456789 | 4567890123456789 | 4567890123456789 | 123 | 4567890123456789
+ 4567890123456789 | 4567890123456789 | 4567890123456789 | 4567890123456789 | 4567890123456789
+ 4567890123456789 | 4567890123456789 | 4567890123456789 | -4567890123456789 | 4567890123456789
+ 4567890123456789 | -4567890123456789 | | |
+(10 rows)
+
+-- lateral can result in join conditions appearing below their
+-- real semantic level
+explain (verbose, costs off)
+select * from int4_tbl i left join
+ lateral (select * from int2_tbl j where i.f1 = j.f1) k on true;
+ QUERY PLAN
+-------------------------------------------
+ Nested Loop Left Join
+ Output: i.f1, j.f1
+ Filter: (i.f1 = j.f1)
+ -> Seq Scan on public.int4_tbl i
+ Output: i.f1
+ -> Materialize
+ Output: j.f1
+ -> Seq Scan on public.int2_tbl j
+ Output: j.f1
+(9 rows)
+
+select * from int4_tbl i left join
+ lateral (select * from int2_tbl j where i.f1 = j.f1) k on true;
+ f1 | f1
+----+----
+ 0 | 0
+(1 row)
+
+explain (verbose, costs off)
+select * from int4_tbl i left join
+ lateral (select coalesce(i) from int2_tbl j where i.f1 = j.f1) k on true;
+ QUERY PLAN
+-------------------------------------
+ Nested Loop Left Join
+ Output: i.f1, (COALESCE(i.*))
+ -> Seq Scan on public.int4_tbl i
+ Output: i.f1, i.*
+ -> Seq Scan on public.int2_tbl j
+ Output: j.f1, COALESCE(i.*)
+ Filter: (i.f1 = j.f1)
+(7 rows)
+
+select * from int4_tbl i left join
+ lateral (select coalesce(i) from int2_tbl j where i.f1 = j.f1) k on true;
+ f1 | coalesce
+-------------+----------
+ 0 | (0)
+ 123456 |
+ -123456 |
+ 2147483647 |
+ -2147483647 |
+(5 rows)
+
+-- lateral reference in a PlaceHolderVar evaluated at join level
+explain (verbose, costs off)
+select * from
+ int8_tbl a left join lateral
+ (select b.q1 as bq1, c.q1 as cq1, least(a.q1,b.q1,c.q1) from
+ int8_tbl b cross join int8_tbl c) ss
+ on a.q2 = ss.bq1;
+ QUERY PLAN
+-------------------------------------------------------------
+ Nested Loop Left Join
+ Output: a.q1, a.q2, b.q1, c.q1, (LEAST(a.q1, b.q1, c.q1))
+ -> Seq Scan on public.int8_tbl a
+ Output: a.q1, a.q2
+ -> Nested Loop
+ Output: b.q1, c.q1, LEAST(a.q1, b.q1, c.q1)
+ Join Filter: (a.q2 = b.q1)
+ -> Seq Scan on public.int8_tbl b
+ Output: b.q1, b.q2
+ -> Materialize
+ Output: c.q1
+ -> Seq Scan on public.int8_tbl c
+ Output: c.q1
+(13 rows)
+
+select * from
+ int8_tbl a left join lateral
+ (select b.q1 as bq1, c.q1 as cq1, least(a.q1,b.q1,c.q1) from
+ int8_tbl b cross join int8_tbl c) ss
+ on a.q2 = ss.bq1;
+ q1 | q2 | bq1 | cq1 | least
+------------------+-------------------+------------------+------------------+------------------
+ 123 | 456 | | |
+ 123 | 4567890123456789 | 4567890123456789 | 123 | 123
+ 123 | 4567890123456789 | 4567890123456789 | 123 | 123
+ 123 | 4567890123456789 | 4567890123456789 | 4567890123456789 | 123
+ 123 | 4567890123456789 | 4567890123456789 | 4567890123456789 | 123
+ 123 | 4567890123456789 | 4567890123456789 | 4567890123456789 | 123
+ 123 | 4567890123456789 | 4567890123456789 | 123 | 123
+ 123 | 4567890123456789 | 4567890123456789 | 123 | 123
+ 123 | 4567890123456789 | 4567890123456789 | 4567890123456789 | 123
+ 123 | 4567890123456789 | 4567890123456789 | 4567890123456789 | 123
+ 123 | 4567890123456789 | 4567890123456789 | 4567890123456789 | 123
+ 123 | 4567890123456789 | 4567890123456789 | 123 | 123
+ 123 | 4567890123456789 | 4567890123456789 | 123 | 123
+ 123 | 4567890123456789 | 4567890123456789 | 4567890123456789 | 123
+ 123 | 4567890123456789 | 4567890123456789 | 4567890123456789 | 123
+ 123 | 4567890123456789 | 4567890123456789 | 4567890123456789 | 123
+ 4567890123456789 | 123 | 123 | 123 | 123
+ 4567890123456789 | 123 | 123 | 123 | 123
+ 4567890123456789 | 123 | 123 | 4567890123456789 | 123
+ 4567890123456789 | 123 | 123 | 4567890123456789 | 123
+ 4567890123456789 | 123 | 123 | 4567890123456789 | 123
+ 4567890123456789 | 123 | 123 | 123 | 123
+ 4567890123456789 | 123 | 123 | 123 | 123
+ 4567890123456789 | 123 | 123 | 4567890123456789 | 123
+ 4567890123456789 | 123 | 123 | 4567890123456789 | 123
+ 4567890123456789 | 123 | 123 | 4567890123456789 | 123
+ 4567890123456789 | 4567890123456789 | 4567890123456789 | 123 | 123
+ 4567890123456789 | 4567890123456789 | 4567890123456789 | 123 | 123
+ 4567890123456789 | 4567890123456789 | 4567890123456789 | 4567890123456789 | 4567890123456789
+ 4567890123456789 | 4567890123456789 | 4567890123456789 | 4567890123456789 | 4567890123456789
+ 4567890123456789 | 4567890123456789 | 4567890123456789 | 4567890123456789 | 4567890123456789
+ 4567890123456789 | 4567890123456789 | 4567890123456789 | 123 | 123
+ 4567890123456789 | 4567890123456789 | 4567890123456789 | 123 | 123
+ 4567890123456789 | 4567890123456789 | 4567890123456789 | 4567890123456789 | 4567890123456789
+ 4567890123456789 | 4567890123456789 | 4567890123456789 | 4567890123456789 | 4567890123456789
+ 4567890123456789 | 4567890123456789 | 4567890123456789 | 4567890123456789 | 4567890123456789
+ 4567890123456789 | 4567890123456789 | 4567890123456789 | 123 | 123
+ 4567890123456789 | 4567890123456789 | 4567890123456789 | 123 | 123
+ 4567890123456789 | 4567890123456789 | 4567890123456789 | 4567890123456789 | 4567890123456789
+ 4567890123456789 | 4567890123456789 | 4567890123456789 | 4567890123456789 | 4567890123456789
+ 4567890123456789 | 4567890123456789 | 4567890123456789 | 4567890123456789 | 4567890123456789
+ 4567890123456789 | -4567890123456789 | | |
+(42 rows)
+
-- case requiring nested PlaceHolderVars
explain (verbose, costs off)
select * from
@@ -3595,7 +3784,7 @@ select * from
Output: c.q1, c.q2, a.q1, a.q2, b.q1, d.q1, (COALESCE(b.q2, 42::bigint)), (COALESCE((COALESCE(b.q2, 42::bigint)), d.q2))
Hash Cond: (d.q1 = c.q2)
-> Nested Loop
- Output: a.q1, a.q2, b.q1, d.q1, (COALESCE(b.q2, 42::bigint)), COALESCE((COALESCE(b.q2, 42::bigint)), d.q2)
+ Output: a.q1, a.q2, b.q1, d.q1, (COALESCE(b.q2, 42::bigint)), (COALESCE((COALESCE(b.q2, 42::bigint)), d.q2))
-> Hash Left Join
Output: a.q1, a.q2, b.q1, (COALESCE(b.q2, 42::bigint))
Hash Cond: (a.q2 = b.q1)
@@ -3605,17 +3794,15 @@ select * from
Output: b.q1, (COALESCE(b.q2, 42::bigint))
-> Seq Scan on public.int8_tbl b
Output: b.q1, COALESCE(b.q2, 42::bigint)
- -> Materialize
- Output: d.q1, d.q2
- -> Seq Scan on public.int8_tbl d
- Output: d.q1, d.q2
+ -> Seq Scan on public.int8_tbl d
+ Output: d.q1, COALESCE((COALESCE(b.q2, 42::bigint)), d.q2)
-> Hash
Output: c.q1, c.q2
-> Seq Scan on public.int8_tbl c
Output: c.q1, c.q2
-> Result
Output: (COALESCE((COALESCE(b.q2, 42::bigint)), d.q2))
-(26 rows)
+(24 rows)
-- case that breaks the old ph_may_need optimization
explain (verbose, costs off)
@@ -3629,45 +3816,43 @@ select c.*,a.*,ss1.q1,ss2.q1,ss3.* from
lateral (select q1, coalesce(ss1.x,q2) as y from int8_tbl d) ss2
) on c.q2 = ss2.q1,
lateral (select * from int4_tbl i where ss2.y > f1) ss3;
- QUERY PLAN
--------------------------------------------------------------------------------------------
- Hash Right Join
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------
+ Nested Loop
Output: c.q1, c.q2, a.q1, a.q2, b.q1, d.q1, i.f1
- Hash Cond: (d.q1 = c.q2)
- Filter: ((COALESCE((COALESCE(b.q2, (b2.f1)::bigint)), d.q2)) > i.f1)
- -> Nested Loop
- Output: a.q1, a.q2, b.q1, d.q1, COALESCE((COALESCE(b.q2, (b2.f1)::bigint)), d.q2)
- -> Hash Right Join
- Output: a.q1, a.q2, b.q1, (COALESCE(b.q2, (b2.f1)::bigint))
- Hash Cond: (b.q1 = a.q2)
- -> Nested Loop
- Output: b.q1, COALESCE(b.q2, (b2.f1)::bigint)
- Join Filter: (b.q1 < b2.f1)
- -> Seq Scan on public.int8_tbl b
- Output: b.q1, b.q2
- -> Materialize
- Output: b2.f1
- -> Seq Scan on public.int4_tbl b2
+ Join Filter: ((COALESCE((COALESCE(b.q2, (b2.f1)::bigint)), d.q2)) > i.f1)
+ -> Hash Right Join
+ Output: c.q1, c.q2, a.q1, a.q2, b.q1, d.q1, (COALESCE((COALESCE(b.q2, (b2.f1)::bigint)), d.q2))
+ Hash Cond: (d.q1 = c.q2)
+ -> Nested Loop
+ Output: a.q1, a.q2, b.q1, d.q1, (COALESCE((COALESCE(b.q2, (b2.f1)::bigint)), d.q2))
+ -> Hash Right Join
+ Output: a.q1, a.q2, b.q1, (COALESCE(b.q2, (b2.f1)::bigint))
+ Hash Cond: (b.q1 = a.q2)
+ -> Nested Loop
+ Output: b.q1, COALESCE(b.q2, (b2.f1)::bigint)
+ Join Filter: (b.q1 < b2.f1)
+ -> Seq Scan on public.int8_tbl b
+ Output: b.q1, b.q2
+ -> Materialize
Output: b2.f1
- -> Hash
- Output: a.q1, a.q2
- -> Seq Scan on public.int8_tbl a
+ -> Seq Scan on public.int4_tbl b2
+ Output: b2.f1
+ -> Hash
Output: a.q1, a.q2
- -> Materialize
- Output: d.q1, d.q2
+ -> Seq Scan on public.int8_tbl a
+ Output: a.q1, a.q2
-> Seq Scan on public.int8_tbl d
- Output: d.q1, d.q2
- -> Hash
- Output: c.q1, c.q2, i.f1
- -> Nested Loop
- Output: c.q1, c.q2, i.f1
+ Output: d.q1, COALESCE((COALESCE(b.q2, (b2.f1)::bigint)), d.q2)
+ -> Hash
+ Output: c.q1, c.q2
-> Seq Scan on public.int8_tbl c
Output: c.q1, c.q2
- -> Materialize
- Output: i.f1
- -> Seq Scan on public.int4_tbl i
- Output: i.f1
-(36 rows)
+ -> Materialize
+ Output: i.f1
+ -> Seq Scan on public.int4_tbl i
+ Output: i.f1
+(34 rows)
-- test some error cases where LATERAL should have been used but wasn't
select f1,g from int4_tbl a, (select f1 as g) ss;
diff --git a/src/test/regress/sql/join.sql b/src/test/regress/sql/join.sql
index 7ec2cbeea4b..36853ddce49 100644
--- a/src/test/regress/sql/join.sql
+++ b/src/test/regress/sql/join.sql
@@ -995,6 +995,47 @@ select v.* from
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);
+explain (verbose, costs off)
+select * from
+ int8_tbl a left join
+ lateral (select *, a.q2 as x from int8_tbl b) ss on a.q2 = ss.q1;
+select * from
+ int8_tbl a left join
+ lateral (select *, a.q2 as x from int8_tbl b) ss on a.q2 = ss.q1;
+explain (verbose, costs off)
+select * from
+ int8_tbl a left join
+ lateral (select *, coalesce(a.q2, 42) as x from int8_tbl b) ss on a.q2 = ss.q1;
+select * from
+ int8_tbl a left join
+ lateral (select *, coalesce(a.q2, 42) as x from int8_tbl b) ss on a.q2 = ss.q1;
+
+-- lateral can result in join conditions appearing below their
+-- real semantic level
+explain (verbose, costs off)
+select * from int4_tbl i left join
+ lateral (select * from int2_tbl j where i.f1 = j.f1) k on true;
+select * from int4_tbl i left join
+ lateral (select * from int2_tbl j where i.f1 = j.f1) k on true;
+explain (verbose, costs off)
+select * from int4_tbl i left join
+ lateral (select coalesce(i) from int2_tbl j where i.f1 = j.f1) k on true;
+select * from int4_tbl i left join
+ lateral (select coalesce(i) from int2_tbl j where i.f1 = j.f1) k on true;
+
+-- lateral reference in a PlaceHolderVar evaluated at join level
+explain (verbose, costs off)
+select * from
+ int8_tbl a left join lateral
+ (select b.q1 as bq1, c.q1 as cq1, least(a.q1,b.q1,c.q1) from
+ int8_tbl b cross join int8_tbl c) ss
+ on a.q2 = ss.bq1;
+select * from
+ int8_tbl a left join lateral
+ (select b.q1 as bq1, c.q1 as cq1, least(a.q1,b.q1,c.q1) from
+ int8_tbl b cross join int8_tbl c) ss
+ on a.q2 = ss.bq1;
+
-- case requiring nested PlaceHolderVars
explain (verbose, costs off)
select * from