From 038a614d4efe8f75c2e6bc2c862cf0b1e3dd37a4 Mon Sep 17 00:00:00 2001 From: Nikhil Benesch Date: Thu, 23 Jul 2020 00:32:08 -0400 Subject: [PATCH] sql: support LATERAL joins A LATERAL join allows the right-hand side of the join to access columns defined on the left-hand side of the join. A simple example from the PostgreSQL docs is the query SELECT * FROM foo, LATERAL (SELECT * FROM bar WHERE bar.id = foo.bar_id) ss which is equivalent to: SELECT * FROM foo, bar WHERE bar.id = foo.bar_id; The hope is that LATERAL joins will be useful for expressing "top-k within a group", as in: SELECT * FROM (SELECT DISTINCT cat FROM foo) grp, JOIN LATERAL (SELECT * FROM foo WHERE foo.cat = grp.cat ORDER BY foo.val LIMIT $k) --- src/sql/src/plan/decorrelate.rs | 45 +- src/sql/src/plan/explain.rs | 14 +- src/sql/src/plan/expr.rs | 76 ++- src/sql/src/plan/query.rs | 123 ++-- src/sql/src/plan/scope.rs | 1 - src/sql/src/plan/transform_expr.rs | 14 +- .../cockroach/subquery_correlated.slt | 35 +- test/sqllogictest/postgres/lateral-join.slt | 641 ++++++++++++++++++ test/sqllogictest/table_func.slt | 69 +- 9 files changed, 899 insertions(+), 119 deletions(-) create mode 100644 test/sqllogictest/postgres/lateral-join.slt diff --git a/src/sql/src/plan/decorrelate.rs b/src/sql/src/plan/decorrelate.rs index 3de3938744adf..41873dcf561cd 100644 --- a/src/sql/src/plan/decorrelate.rs +++ b/src/sql/src/plan/decorrelate.rs @@ -165,13 +165,13 @@ impl RelationExpr { } input } - FlatMap { input, func, exprs } => { + CallTable { func, exprs } => { // FlatMap expressions may contain correlated subqueries. Unlike Map they are not // allowed to refer to the results of previous expressions, and we have a simpler // implementation that appends all relevant columns first, then applies the flatmap // operator to the result, then strips off any columns introduce by subqueries. - let mut input = input.applied_to(id_gen, get_outer, col_map); + let mut input = get_outer; let old_arity = input.arity(); let exprs = exprs @@ -209,6 +209,45 @@ impl RelationExpr { } input } + Join { + left, + right, + on, + kind, + } if kind.is_lateral() => { + let left = left.applied_to(id_gen, get_outer, col_map); + let mut join = branch( + id_gen, + left, + col_map, + *right, + |id_gen, right, get_left, col_map| { + let join = right.applied_to(id_gen, get_left.clone(), col_map); + if let JoinKind::LeftOuter { .. } = kind { + let default = join + .typ() + .column_types + .into_iter() + .skip(get_left.arity()) + .map(|typ| (Datum::Null, typ.nullable(true))) + .collect(); + get_left.lookup(id_gen, join, default) + } else { + join + } + }, + ); + let old_arity = join.arity(); + let on = on.applied_to(id_gen, col_map, &mut join); + join = join.filter(vec![on]); + let new_arity = join.arity(); + if old_arity != new_arity { + // This means we added some columns to handle + // subqueries, and now we need to get rid of them. + join = join.project((0..old_arity).collect()); + } + join + } Join { left, right, @@ -257,7 +296,7 @@ impl RelationExpr { } join.let_in(id_gen, |id_gen, get_join| { let mut result = get_join.clone(); - if let JoinKind::LeftOuter | JoinKind::FullOuter = kind { + if let JoinKind::LeftOuter { .. } | JoinKind::FullOuter { .. } = kind { let left_outer = get_left.clone().anti_lookup( id_gen, get_join.clone(), diff --git a/src/sql/src/plan/explain.rs b/src/sql/src/plan/explain.rs index 3ff835e286f24..07bcf1a9b2661 100644 --- a/src/sql/src/plan/explain.rs +++ b/src/sql/src/plan/explain.rs @@ -133,7 +133,7 @@ impl RelationExpr { Some(parent_expr) => match parent_expr { Project { .. } | Map { .. } - | FlatMap { .. } + | CallTable { .. } | Filter { .. } | Reduce { .. } | TopK { .. } @@ -163,7 +163,7 @@ impl RelationExpr { | TopK { .. } => (), Map { scalars, .. } => scalar_exprs.extend(scalars), Filter { predicates, .. } => scalar_exprs.extend(predicates), - FlatMap { exprs, .. } => scalar_exprs.extend(exprs), + CallTable { exprs, .. } => scalar_exprs.extend(exprs), Join { on, .. } => scalar_exprs.push(on), Reduce { aggregates, .. } => { scalar_exprs.extend(aggregates.iter().map(|a| &*a.expr)) @@ -241,10 +241,10 @@ impl RelationExpr { ) .unwrap(); } - FlatMap { func, exprs, .. } => { + CallTable { func, exprs } => { write!( pretty, - "FlatMap {}({})", + "CallTable {}({})", func, Separated( ", ", @@ -445,8 +445,10 @@ impl std::fmt::Display for JoinKind { f, "{}", match self { - JoinKind::Inner => "Inner", - JoinKind::LeftOuter => "LeftOuter", + JoinKind::Inner { lateral: false } => "Inner", + JoinKind::Inner { lateral: true } => "InnerLateral", + JoinKind::LeftOuter { lateral: false } => "LeftOuter", + JoinKind::LeftOuter { lateral: true } => "LeftOuterLateral", JoinKind::RightOuter => "RightOuter", JoinKind::FullOuter => "FullOuter", } diff --git a/src/sql/src/plan/expr.rs b/src/sql/src/plan/expr.rs index b6b12315687d9..0da17e47ec57c 100644 --- a/src/sql/src/plan/expr.rs +++ b/src/sql/src/plan/expr.rs @@ -12,6 +12,7 @@ //! similar to that file, with some differences which are noted below. It gets turned into that //! representation via a call to decorrelate(). +use std::borrow::Cow; use std::collections::BTreeMap; use std::mem; @@ -54,8 +55,7 @@ pub enum RelationExpr { input: Box, scalars: Vec, }, - FlatMap { - input: Box, + CallTable { func: TableFunc, exprs: Vec, }, @@ -255,12 +255,21 @@ pub struct ColumnRef { #[derive(Debug, Clone, PartialEq, Eq)] pub enum JoinKind { - Inner, - LeftOuter, + Inner { lateral: bool }, + LeftOuter { lateral: bool }, RightOuter, FullOuter, } +impl JoinKind { + pub fn is_lateral(&self) -> bool { + match self { + JoinKind::Inner { lateral } | JoinKind::LeftOuter { lateral } => *lateral, + JoinKind::RightOuter | JoinKind::FullOuter => false, + } + } +} + #[derive(Debug, Clone, PartialEq, Eq)] pub struct AggregateExpr { pub func: AggregateFunc, @@ -293,32 +302,35 @@ impl RelationExpr { } typ } - RelationExpr::FlatMap { - input, - func, - exprs: _, - } => { - let mut typ = input.typ(outers, params); - typ.column_types.extend(func.output_type().column_types); - // FlatMap can add duplicate rows, so input keys are no longer valid - RelationType::new(typ.column_types) - } + RelationExpr::CallTable { func, exprs: _ } => func.output_type(), RelationExpr::Filter { input, .. } | RelationExpr::TopK { input, .. } => { input.typ(outers, params) } RelationExpr::Join { left, right, kind, .. } => { - let left_nullable = *kind == JoinKind::RightOuter || *kind == JoinKind::FullOuter; - let right_nullable = *kind == JoinKind::LeftOuter || *kind == JoinKind::FullOuter; + let left_nullable = matches!(kind, JoinKind::RightOuter | JoinKind::FullOuter); + let right_nullable = + matches!(kind, JoinKind::LeftOuter { .. } | JoinKind::FullOuter); let lt = left.typ(outers, params).column_types.into_iter().map(|t| { let nullable = t.nullable || left_nullable; t.nullable(nullable) }); - let rt = right.typ(outers, params).column_types.into_iter().map(|t| { - let nullable = t.nullable || right_nullable; - t.nullable(nullable) - }); + let outers = if kind.is_lateral() { + let mut outers = outers.to_vec(); + outers.push(RelationType::new(lt.clone().collect())); + Cow::Owned(outers) + } else { + Cow::Borrowed(outers) + }; + let rt = right + .typ(&outers, params) + .column_types + .into_iter() + .map(|t| { + let nullable = t.nullable || right_nullable; + t.nullable(nullable) + }); RelationType::new(lt.chain(rt).collect()) } RelationExpr::Reduce { @@ -364,7 +376,7 @@ impl RelationExpr { RelationExpr::Get { typ, .. } => typ.column_types.len(), RelationExpr::Project { outputs, .. } => outputs.len(), RelationExpr::Map { input, scalars } => input.arity() + scalars.len(), - RelationExpr::FlatMap { input, func, .. } => input.arity() + func.output_arity(), + RelationExpr::CallTable { func, .. } => func.output_arity(), RelationExpr::Filter { input, .. } | RelationExpr::TopK { input, .. } | RelationExpr::Distinct { input } @@ -507,16 +519,15 @@ impl RelationExpr { F: FnMut(&'a Self), { match self { - RelationExpr::Constant { .. } | RelationExpr::Get { .. } => (), + RelationExpr::Constant { .. } + | RelationExpr::Get { .. } + | RelationExpr::CallTable { .. } => (), RelationExpr::Project { input, .. } => { f(input); } RelationExpr::Map { input, .. } => { f(input); } - RelationExpr::FlatMap { input, .. } => { - f(input); - } RelationExpr::Filter { input, .. } => { f(input); } @@ -559,16 +570,15 @@ impl RelationExpr { F: FnMut(&'a mut Self), { match self { - RelationExpr::Constant { .. } | RelationExpr::Get { .. } => (), + RelationExpr::Constant { .. } + | RelationExpr::Get { .. } + | RelationExpr::CallTable { .. } => (), RelationExpr::Project { input, .. } => { f(input); } RelationExpr::Map { input, .. } => { f(input); } - RelationExpr::FlatMap { input, .. } => { - f(input); - } RelationExpr::Filter { input, .. } => { f(input); } @@ -609,11 +619,12 @@ impl RelationExpr { { match self { RelationExpr::Join { - kind: _, + kind, on, left, right, } => { + let depth = if kind.is_lateral() { depth + 1 } else { depth }; on.visit_columns(depth, f); left.visit_columns(depth, f); right.visit_columns(depth, f); @@ -624,11 +635,10 @@ impl RelationExpr { } input.visit_columns(depth, f); } - RelationExpr::FlatMap { exprs, input, .. } => { + RelationExpr::CallTable { exprs, .. } => { for expr in exprs { expr.visit_columns(depth, f); } - input.visit_columns(depth, f); } RelationExpr::Filter { predicates, input } => { for predicate in predicates { @@ -669,7 +679,7 @@ impl RelationExpr { scalar.bind_parameters(parameters); } } - RelationExpr::FlatMap { exprs, .. } => { + RelationExpr::CallTable { exprs, .. } => { for expr in exprs { expr.bind_parameters(parameters); } diff --git a/src/sql/src/plan/query.rs b/src/sql/src/plan/query.rs index a9028b9355370..7b5b5f2b1d42e 100644 --- a/src/sql/src/plan/query.rs +++ b/src/sql/src/plan/query.rs @@ -915,14 +915,25 @@ fn plan_table_with_joins<'a>( Ok((left, left_scope)) } -fn plan_table_factor<'a>( +fn plan_table_factor( qcx: &QueryContext, left: RelationExpr, left_scope: Scope, join_operator: &JoinOperator, - table_factor: &'a TableFactor, + table_factor: &TableFactor, ) -> Result<(RelationExpr, Scope), anyhow::Error> { - match table_factor { + let lateral = matches!( + table_factor, + TableFactor::Function { .. } | TableFactor::Derived { lateral: true, .. } + ); + + let qcx = if lateral { + Cow::Owned(qcx.derived_context(left_scope.clone(), &qcx.relation_type(&left))) + } else { + Cow::Borrowed(qcx) + }; + + let (expr, scope) = match table_factor { TableFactor::Table { name, alias } => { let name = qcx.scx.resolve_item(name.clone())?; let item = qcx.scx.catalog.get_item(&name); @@ -931,51 +942,51 @@ fn plan_table_factor<'a>( typ: item.desc()?.typ().clone(), }; let column_names = item.desc()?.iter_names().map(|n| n.cloned()).collect(); - let scope = plan_table_alias(qcx, alias.as_ref(), Some(name.into()), column_names)?; - plan_join_operator(qcx, &join_operator, left, left_scope, expr, scope) + let scope = plan_table_alias(&qcx, alias.as_ref(), Some(name.into()), column_names)?; + (expr, scope) } + TableFactor::Function { name, args, alias } => { let ecx = &ExprContext { - qcx, + qcx: &qcx, name: "FROM table function", - scope: &left_scope, - relation_type: &qcx.relation_type(&left), + scope: &Scope::empty(Some(qcx.outer_scope.clone())), + relation_type: &RelationType::empty(), allow_aggregates: false, allow_subqueries: true, }; - plan_table_function(ecx, left, &name, alias.as_ref(), args) + plan_table_function(ecx, &name, alias.as_ref(), args)? } + TableFactor::Derived { - lateral, + lateral: _, subquery, alias, } => { - if *lateral { - unsupported!(3111, "LATERAL derived tables"); - } let (expr, scope) = plan_subquery(&qcx, &subquery)?; let table_name = None; let column_names = scope.column_names().map(|n| n.cloned()).collect(); - let scope = plan_table_alias(qcx, alias.as_ref(), table_name, column_names)?; - plan_join_operator(qcx, &join_operator, left, left_scope, expr, scope) + let scope = plan_table_alias(&qcx, alias.as_ref(), table_name, column_names)?; + (expr, scope) } + TableFactor::NestedJoin(table_with_joins) => { - let (identity, identity_scope) = plan_join_identity(qcx); - let (expr, scope) = plan_table_with_joins( - qcx, + let (identity, identity_scope) = plan_join_identity(&qcx); + plan_table_with_joins( + &qcx, identity, identity_scope, &JoinOperator::CrossJoin, table_with_joins, - )?; - plan_join_operator(qcx, &join_operator, left, left_scope, expr, scope) + )? } - } + }; + + plan_join_operator(&qcx, &join_operator, left, left_scope, expr, scope, lateral) } fn plan_table_function( ecx: &ExprContext, - left: RelationExpr, name: &ObjectName, alias: Option<&TableAlias>, args: &FunctionArgs, @@ -986,8 +997,7 @@ fn plan_table_function( FunctionArgs::Args(args) => args, }; let tf = func::select_table_func(ecx, &*ident, args)?; - let call = RelationExpr::FlatMap { - input: Box::new(left), + let call = RelationExpr::CallTable { func: tf.func, exprs: tf.exprs, }; @@ -997,7 +1007,7 @@ fn plan_table_function( item: ident, }; let scope = plan_table_alias(ecx.qcx, alias, Some(name), tf.column_names)?; - Ok((call, ecx.scope.clone().product(scope))) + Ok((call, scope)) } fn plan_table_alias( @@ -1160,6 +1170,7 @@ fn plan_join_operator( left_scope: Scope, right: RelationExpr, right_scope: Scope, + lateral: bool, ) -> Result<(RelationExpr, Scope), anyhow::Error> { match operator { JoinOperator::Inner(constraint) => plan_join_constraint( @@ -1169,7 +1180,7 @@ fn plan_join_operator( left_scope, right, right_scope, - JoinKind::Inner, + JoinKind::Inner { lateral }, ), JoinOperator::LeftOuter(constraint) => plan_join_constraint( qcx, @@ -1178,37 +1189,47 @@ fn plan_join_operator( left_scope, right, right_scope, - JoinKind::LeftOuter, - ), - JoinOperator::RightOuter(constraint) => plan_join_constraint( - qcx, - &constraint, - left, - left_scope, - right, - right_scope, - JoinKind::RightOuter, - ), - JoinOperator::FullOuter(constraint) => plan_join_constraint( - qcx, - &constraint, - left, - left_scope, - right, - right_scope, - JoinKind::FullOuter, + JoinKind::LeftOuter { lateral }, ), + JoinOperator::RightOuter(constraint) => { + if lateral { + bail!("the combining JOIN type must be INNER or LEFT for a LATERAL reference"); + } + plan_join_constraint( + qcx, + &constraint, + left, + left_scope, + right, + right_scope, + JoinKind::RightOuter, + ) + } + JoinOperator::FullOuter(constraint) => { + if lateral { + bail!("the combining JOIN type must be INNER or LEFT for a LATERAL reference"); + } + plan_join_constraint( + qcx, + &constraint, + left, + left_scope, + right, + right_scope, + JoinKind::FullOuter, + ) + } JoinOperator::CrossJoin => { - let join = if left.is_join_identity() { + let join = if !lateral && left.is_join_identity() { right - } else if right.is_join_identity() { + } else if !lateral && right.is_join_identity() { left } else { RelationExpr::Join { left: Box::new(left), right: Box::new(right), on: ScalarExpr::literal_true(), - kind: JoinKind::Inner, + kind: JoinKind::Inner { lateral }, } }; Ok((join, left_scope.product(right_scope))) @@ -1244,7 +1265,7 @@ fn plan_join_constraint<'a>( allow_subqueries: true, }; let on = plan_expr(ecx, expr)?.type_as(ecx, ScalarType::Bool)?; - if kind == JoinKind::Inner { + if let JoinKind::Inner { .. } = kind { for (l, r) in find_trivial_column_equivalences(&on) { // When we can statically prove that two columns are // equivalent after a join, the right column becomes @@ -2027,7 +2048,7 @@ pub enum QueryLifetime { } /// The state required when planning a `Query`. -#[derive(Debug)] +#[derive(Debug, Clone)] pub struct QueryContext<'a> { /// The context for the containing `Statement`. pub scx: &'a StatementContext<'a>, @@ -2061,7 +2082,7 @@ impl<'a> QueryContext<'a> { expr.typ(&self.outer_relation_types, &self.param_types.borrow()) } - fn derived_context(&self, scope: Scope, relation_type: &RelationType) -> QueryContext { + fn derived_context(&self, scope: Scope, relation_type: &RelationType) -> QueryContext<'a> { QueryContext { scx: self.scx, lifetime: self.lifetime, diff --git a/src/sql/src/plan/scope.rs b/src/sql/src/plan/scope.rs index aefa2b80848e7..62324894db9f6 100644 --- a/src/sql/src/plan/scope.rs +++ b/src/sql/src/plan/scope.rs @@ -266,7 +266,6 @@ impl Scope { } pub fn product(self, right: Self) -> Self { - assert!(self.outer_scope == right.outer_scope); Scope { items: self .items diff --git a/src/sql/src/plan/transform_expr.rs b/src/sql/src/plan/transform_expr.rs index 408e2b4de892f..04b7eb234b7fd 100644 --- a/src/sql/src/plan/transform_expr.rs +++ b/src/sql/src/plan/transform_expr.rs @@ -58,7 +58,7 @@ pub fn split_subquery_predicates(expr: &mut RelationExpr) { walk_scalar(scalar); } } - RelationExpr::FlatMap { exprs, .. } => { + RelationExpr::CallTable { exprs, .. } => { for expr in exprs { walk_scalar(expr); } @@ -155,12 +155,7 @@ pub fn split_subquery_predicates(expr: &mut RelationExpr) { pub fn try_simplify_quantified_comparisons(expr: &mut RelationExpr) { fn walk_relation(expr: &mut RelationExpr, outers: &[RelationType]) { expr.visit_mut(&mut |expr| match expr { - RelationExpr::Map { scalars, input } - | RelationExpr::FlatMap { - exprs: scalars, - input, - .. - } => { + RelationExpr::Map { scalars, input } => { let mut outers = outers.to_vec(); outers.push(input.typ(&outers, &NO_PARAMS)); for scalar in scalars { @@ -174,6 +169,11 @@ pub fn try_simplify_quantified_comparisons(expr: &mut RelationExpr) { walk_scalar(pred, &outers, true); } } + RelationExpr::CallTable { exprs, .. } => { + for scalar in exprs { + walk_scalar(scalar, &outers, false); + } + } _ => (), }) } diff --git a/test/sqllogictest/cockroach/subquery_correlated.slt b/test/sqllogictest/cockroach/subquery_correlated.slt index 087564966faf3..dc37d0595aac8 100644 --- a/test/sqllogictest/cockroach/subquery_correlated.slt +++ b/test/sqllogictest/cockroach/subquery_correlated.slt @@ -878,23 +878,38 @@ SELECT (SELECT string_agg(DISTINCT ship, ', ') WHERE o_c_id=c.c_id) FROM c ORDER BY c_id -# #3111 -statement error supported +query ITI SELECT * FROM - (SELECT c_id AS c_c_id, bill FROM c), - LATERAL (SELECT row_number() OVER () AS rownum FROM o WHERE c_id = c_c_id) -ORDER BY c_c_id, bill, rownum + (SELECT c_id AS c_c_id, bill FROM c) s1, + LATERAL (SELECT o_id FROM o WHERE c_id = c_c_id) s2 +ORDER BY c_c_id, bill, o_id +---- +1 CA 10 +1 CA 20 +1 CA 30 +2 TX 40 +2 TX 50 +2 TX 60 +4 TX 70 +4 TX 80 +6 FL 90 -# #3111 -statement error supported +query TI SELECT * FROM - (SELECT bill FROM c), - LATERAL (SELECT row_number() OVER (PARTITION BY bill) AS rownum FROM o WHERE ship = bill) -ORDER BY bill, rownum + (SELECT bill FROM c) s1, + LATERAL (SELECT o_id FROM o WHERE ship = bill) s2 +ORDER BY bill, o_id +---- +CA 10 +CA 20 +CA 30 +CA 40 +TX 50 +TX 50 # ------------------------------------------------------------------------------ # Subqueries in other interesting locations. diff --git a/test/sqllogictest/postgres/lateral-join.slt b/test/sqllogictest/postgres/lateral-join.slt new file mode 100644 index 0000000000000..2055d86397985 --- /dev/null +++ b/test/sqllogictest/postgres/lateral-join.slt @@ -0,0 +1,641 @@ +# Copyright 1994, Regents of the University of California. +# Copyright 1996-2019 PostgreSQL Global Development Group. +# Copyright Materialize, Inc. All rights reserved. +# +# Use of this software is governed by the Business Source License +# included in the LICENSE file at the root of this repository. +# +# As of the Change Date specified in that file, in accordance with +# the Business Source License, use of this software will be governed +# by the Apache License, Version 2.0. +# +# This file is derived from the regression test suite in PostgreSQL. +# The original file was retrieved on July 23, 2020 from: +# +# https://github.com/postgres/postgres/blob/5940ffb221316ab73e6fdc780dfe9a07d4221ebb/src/test/regress/expected/timestamp.out +# +# The original source code is subject to the terms of the PostgreSQL +# license, a copy of which can be found in the LICENSE file at the +# root of this repository. + +mode cockroach + +statement ok +CREATE TABLE int4_tbl (f1 int) + +statement ok +INSERT INTO int4_tbl (f1) VALUES (0), (123456), (-123456), (2147483647), (-2147483647) + +statement ok +CREATE TABLE int8_tbl (q1 bigint, q2 bigint) + +statement ok +INSERT INTO int8_tbl VALUES + (123, 456), + (123, 4567890123456789), + (4567890123456789, 123), + (4567890123456789, 4567890123456789), + (4567890123456789, -4567890123456789) + +statement ok +CREATE TABLE tenk1 ( + unique1 int, + unique2 int, + two int, +) + +statement ok +INSERT INTO tenk1 VALUES + (2, 0, 0), + (1, 3, 1), + (6, 9, 0), + (5, 8, 0), + (0, 4, 0), + (7, 7, 1), + (9, 2, 1), + (4, 6, 1), + (8, 1, 0), + (3, 5, 1) + +statement ok +CREATE TABLE onerow () + +statement ok +INSERT INTO onerow DEFAULT VALUES + +query II colnames +select unique2, x.* +from tenk1 a, lateral (select * from int4_tbl b where f1 = a.unique1) x; +---- +unique2 f1 +4 0 + +query II colnames +select unique2, x.* +from int4_tbl x, lateral (select unique2 from tenk1 where f1 = unique1) ss; +---- +unique2 f1 +4 0 + +query II colnames,rowsort +select unique2, x.* +from int4_tbl x left join lateral (select unique1, unique2 from tenk1 where f1 = unique1) ss on true; +---- +unique2 f1 +4 0 +NULL -123456 +NULL -2147483647 +NULL 123456 +NULL 2147483647 + +# check scoping of lateral versus parent references +# the first of these should return int8_tbl.q2, the second int8_tbl.q1 +# TODO(benesch): col name should be "r", not "?column?" +query III colnames,rowsort +select *, (select r from (select q1 as q2) x, (select q2 as r) y) from int8_tbl +---- +q1 q2 ?column? +123 456 456 +123 4567890123456789 4567890123456789 +4567890123456789 123 123 +4567890123456789 4567890123456789 4567890123456789 +4567890123456789 -4567890123456789 -4567890123456789 + +# TODO(benesch): col name should be "r", not "?column?" +# TODO(benesch): panics. +# query III colnames,rowsort +# select *, (select r from (select q1 as q2) x, lateral (select q2 as r) y) from int8_tbl; +# ---- +# q1 q2 ?column? +# 123 456 123 +# 123 4567890123456789 123 +# 4567890123456789 123 4567890123456789 +# 4567890123456789 4567890123456789 4567890123456789 +# 4567890123456789 -4567890123456789 4567890123456789 + +# lateral with function in FROM +query I colnames +select count(*) from tenk1 a, lateral generate_series(1,two) g; +---- +count +5 + +# TODO(benesch): causes a panic. +# +# query III colnames,rowsort +# select * from generate_series(100,200) g, +# lateral (select * from int8_tbl a where g = q1 union all +# select * from int8_tbl b where g = q2) ss +# ---- +# g q1 q2 +# 123 123 456 +# 123 123 4567890123456789 +# 123 4567890123456789 123 + +query I colnames +select count(*) from tenk1 a, + tenk1 b join lateral (values(a.unique1)) ss(x) on b.unique2 = ss.x; +---- +count +10 + +query I colnames +select count(*) from tenk1 a, + tenk1 b join lateral (values(a.unique1),(-1)) ss(x) on b.unique2 = ss.x; +---- +count +10 + +# TODO(benesch): output failure. +# +# lateral injecting a strange outer join condition +# query IIIII colnames +# select * from int8_tbl a, +# int8_tbl x left join lateral (select a.q1 from int4_tbl y) ss(z) +# on x.q2 = ss.z +# order by a.q1, a.q2, x.q1, x.q2, ss.z; +# ---- +# q1 q2 q1 q2 z +# 123 456 123 456 NULL +# 123 456 123 4567890123456789 NULL +# 123 456 4567890123456789 -4567890123456789 NULL +# 123 456 4567890123456789 123 123 +# 123 456 4567890123456789 123 123 +# 123 456 4567890123456789 123 123 +# 123 456 4567890123456789 123 123 +# 123 456 4567890123456789 123 123 +# 123 456 4567890123456789 4567890123456789 NULL +# 123 4567890123456789 123 456 NULL +# 123 4567890123456789 123 4567890123456789 NULL +# 123 4567890123456789 4567890123456789 -4567890123456789 NULL +# 123 4567890123456789 4567890123456789 123 123 +# 123 4567890123456789 4567890123456789 123 123 +# 123 4567890123456789 4567890123456789 123 123 +# 123 4567890123456789 4567890123456789 123 123 +# 123 4567890123456789 4567890123456789 123 123 +# 123 4567890123456789 4567890123456789 4567890123456789 NULL +# 4567890123456789 -4567890123456789 123 456 NULL +# 4567890123456789 -4567890123456789 123 4567890123456789 4567890123456789 +# 4567890123456789 -4567890123456789 123 4567890123456789 4567890123456789 +# 4567890123456789 -4567890123456789 123 4567890123456789 4567890123456789 +# 4567890123456789 -4567890123456789 123 4567890123456789 4567890123456789 +# 4567890123456789 -4567890123456789 123 4567890123456789 4567890123456789 +# 4567890123456789 -4567890123456789 4567890123456789 -4567890123456789 NULL +# 4567890123456789 -4567890123456789 4567890123456789 123 NULL +# 4567890123456789 -4567890123456789 4567890123456789 4567890123456789 4567890123456789 +# 4567890123456789 -4567890123456789 4567890123456789 4567890123456789 4567890123456789 +# 4567890123456789 -4567890123456789 4567890123456789 4567890123456789 4567890123456789 +# 4567890123456789 -4567890123456789 4567890123456789 4567890123456789 4567890123456789 +# 4567890123456789 -4567890123456789 4567890123456789 4567890123456789 4567890123456789 +# 4567890123456789 123 123 456 NULL +# 4567890123456789 123 123 4567890123456789 4567890123456789 +# 4567890123456789 123 123 4567890123456789 4567890123456789 +# 4567890123456789 123 123 4567890123456789 4567890123456789 +# 4567890123456789 123 123 4567890123456789 4567890123456789 +# 4567890123456789 123 123 4567890123456789 4567890123456789 +# 4567890123456789 123 4567890123456789 -4567890123456789 NULL +# 4567890123456789 123 4567890123456789 123 NULL +# 4567890123456789 123 4567890123456789 4567890123456789 4567890123456789 +# 4567890123456789 123 4567890123456789 4567890123456789 4567890123456789 +# 4567890123456789 123 4567890123456789 4567890123456789 4567890123456789 +# 4567890123456789 123 4567890123456789 4567890123456789 4567890123456789 +# 4567890123456789 123 4567890123456789 4567890123456789 4567890123456789 +# 4567890123456789 4567890123456789 123 456 NULL +# 4567890123456789 4567890123456789 123 4567890123456789 4567890123456789 +# 4567890123456789 4567890123456789 123 4567890123456789 4567890123456789 +# 4567890123456789 4567890123456789 123 4567890123456789 4567890123456789 +# 4567890123456789 4567890123456789 123 4567890123456789 4567890123456789 +# 4567890123456789 4567890123456789 123 4567890123456789 4567890123456789 +# 4567890123456789 4567890123456789 4567890123456789 -4567890123456789 NULL +# 4567890123456789 4567890123456789 4567890123456789 123 NULL +# 4567890123456789 4567890123456789 4567890123456789 4567890123456789 4567890123456789 +# 4567890123456789 4567890123456789 4567890123456789 4567890123456789 4567890123456789 +# 4567890123456789 4567890123456789 4567890123456789 4567890123456789 4567890123456789 +# 4567890123456789 4567890123456789 4567890123456789 4567890123456789 4567890123456789 +# 4567890123456789 4567890123456789 4567890123456789 4567890123456789 4567890123456789 + +# lateral reference to a join alias variable +query III colnames +select * from (select f1/2 as x from int4_tbl) ss1 join int4_tbl i4 on x = f1, + lateral (select x) ss2(y); +---- +x f1 y +0 0 0 + +query III colnames,rowsort +select * from (select f1 as x from int4_tbl) ss1 join int4_tbl i4 on x = f1, + lateral (values(x)) ss2(y); +---- +x f1 y + 0 0 0 + 123456 123456 123456 + -123456 -123456 -123456 + 2147483647 2147483647 2147483647 +-2147483647 -2147483647 -2147483647 + +# TODO(benesch): parse failure. +# +# query III colnames +# select * from ((select f1/2 as x from int4_tbl) ss1 join int4_tbl i4 on x = f1) j, +# lateral (select x) ss2(y); +# ---- +# x f1 y +# 0 0 0 + +# lateral references requiring pullup +query II rowsort +select * from (values(1)) x(lb), + lateral generate_series(lb,4) x4; +---- +1 1 +1 2 +1 3 +1 4 + +query II rowsort +select * from (select f1/1000000000 from int4_tbl) x(lb), + lateral generate_series(lb,4) x4; +---- +-2 0 +-2 1 +-2 2 +-2 3 +-2 4 +-2 -1 +-2 -2 +0 0 +0 0 +0 0 +0 1 +0 1 +0 1 +0 2 +0 2 +0 2 +0 3 +0 3 +0 3 +0 4 +0 4 +0 4 +2 2 +2 3 +2 4 + +query II colnames +select * from (values(1)) x(lb), + lateral (values(lb)) y(lbcopy) +---- +lb lbcopy +1 1 + +query II colnames +select * from (values(1)) x(lb), + lateral (select lb from int4_tbl) y(lbcopy); +---- +lb lbcopy +1 1 +1 1 +1 1 +1 1 +1 1 + +query IIIIIII colnames,rowsort +select * from + int8_tbl x left join (select q1,coalesce(q2,0) q2 from int8_tbl) y on x.q2 = y.q1, + lateral (values(x.q1,y.q1,y.q2)) v(xq1,yq1,yq2); +---- +q1 q2 q1 q2 xq1 yq1 yq2 +4567890123456789 -4567890123456789 NULL NULL 4567890123456789 NULL NULL +4567890123456789 123 123 456 4567890123456789 123 456 +4567890123456789 123 123 4567890123456789 4567890123456789 123 4567890123456789 +123 456 NULL NULL 123 NULL NULL +123 4567890123456789 4567890123456789 123 123 4567890123456789 123 +123 4567890123456789 4567890123456789 4567890123456789 123 4567890123456789 4567890123456789 +123 4567890123456789 4567890123456789 -4567890123456789 123 4567890123456789 -4567890123456789 +4567890123456789 4567890123456789 4567890123456789 123 4567890123456789 4567890123456789 123 +4567890123456789 4567890123456789 4567890123456789 4567890123456789 4567890123456789 4567890123456789 4567890123456789 +4567890123456789 4567890123456789 4567890123456789 -4567890123456789 4567890123456789 4567890123456789 -4567890123456789 + +query IIIIIII colnames,rowsort +select * from + int8_tbl x left join (select q1,coalesce(q2,0) q2 from int8_tbl) y on x.q2 = y.q1, + lateral (select x.q1,y.q1,y.q2) v(xq1,yq1,yq2); +---- +q1 q2 q1 q2 xq1 yq1 yq2 +4567890123456789 -4567890123456789 NULL NULL 4567890123456789 NULL NULL +4567890123456789 123 123 456 4567890123456789 123 456 +4567890123456789 123 123 4567890123456789 4567890123456789 123 4567890123456789 +123 456 NULL NULL 123 NULL NULL +123 4567890123456789 4567890123456789 123 123 4567890123456789 123 +123 4567890123456789 4567890123456789 4567890123456789 123 4567890123456789 4567890123456789 +123 4567890123456789 4567890123456789 -4567890123456789 123 4567890123456789 -4567890123456789 +4567890123456789 4567890123456789 4567890123456789 123 4567890123456789 4567890123456789 123 +4567890123456789 4567890123456789 4567890123456789 4567890123456789 4567890123456789 4567890123456789 4567890123456789 +4567890123456789 4567890123456789 4567890123456789 -4567890123456789 4567890123456789 4567890123456789 -4567890123456789 + +query II colnames,rowsort +select x.* from + int8_tbl x left join (select q1,coalesce(q2,0) q2 from int8_tbl) y on x.q2 = y.q1, + lateral (select x.q1,y.q1,y.q2) v(xq1,yq1,yq2); +---- +q1 q2 +123 456 +123 4567890123456789 +123 4567890123456789 +123 4567890123456789 +4567890123456789 123 +4567890123456789 123 +4567890123456789 4567890123456789 +4567890123456789 4567890123456789 +4567890123456789 4567890123456789 +4567890123456789 -4567890123456789 + +query II colnames,rowsort +select v.* from + (int8_tbl x left join (select q1,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); +---- +vx vy +123 NULL +456 NULL +123 4567890123456789 +4567890123456789 -4567890123456789 +123 4567890123456789 +4567890123456789 4567890123456789 +123 4567890123456789 +4567890123456789 123 +4567890123456789 123 +123 4567890123456789 +4567890123456789 123 +123 456 +4567890123456789 4567890123456789 +4567890123456789 -4567890123456789 +4567890123456789 4567890123456789 +4567890123456789 4567890123456789 +4567890123456789 4567890123456789 +4567890123456789 123 +4567890123456789 NULL +-4567890123456789 NULL + +# TODO(benesch): output failure. +# +# query II colnames,rowsort +# 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); +# ---- +# vx vy +# 4567890123456789 123 +# 123 456 +# 4567890123456789 123 +# 123 4567890123456789 +# 4567890123456789 4567890123456789 +# 4567890123456789 123 +# 123 4567890123456789 +# 4567890123456789 123 +# 4567890123456789 4567890123456789 +# 4567890123456789 4567890123456789 +# 123 4567890123456789 +# 4567890123456789 4567890123456789 +# 4567890123456789 4567890123456789 +# 4567890123456789 -4567890123456789 +# 123 4567890123456789 +# 4567890123456789 -4567890123456789 +# 123 NULL +# 456 NULL +# 4567890123456789 NULL +# 4567890123456789 NULL + +query II +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 onerow union all select x.q2,y.q2 from onerow) v(vx,vy); +---- +vx vy +4567890123456789 123 +123 456 +4567890123456789 123 +123 4567890123456789 +4567890123456789 4567890123456789 +4567890123456789 123 +123 4567890123456789 +4567890123456789 123 +4567890123456789 4567890123456789 +4567890123456789 4567890123456789 +123 4567890123456789 +4567890123456789 4567890123456789 +4567890123456789 4567890123456789 +4567890123456789 -4567890123456789 +123 4567890123456789 +4567890123456789 -4567890123456789 +123 NULL +456 NULL +4567890123456789 NULL +-4567890123456789 NULL + +# 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) +# +# 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 +# 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 +# 123456 | +# -123456 | +# 2147483647 | +# -2147483647 | +# (5 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) +# +# select * from int4_tbl a, +# lateral ( +# select * from int4_tbl b left join int8_tbl c on (b.f1 = q1 and a.f1 = q2) +# ) ss; +# f1 | f1 | q1 | q2 +# -------------+-------------+----+---- +# 0 | 0 | | +# 0 | 123456 | | +# 0 | -123456 | | +# 0 | 2147483647 | | +# 0 | -2147483647 | | +# 123456 | 0 | | +# 123456 | 123456 | | +# 123456 | -123456 | | +# 123456 | 2147483647 | | +# 123456 | -2147483647 | | +# -123456 | 0 | | +# -123456 | 123456 | | +# -123456 | -123456 | | +# -123456 | 2147483647 | | +# -123456 | -2147483647 | | +# 2147483647 | 0 | | +# 2147483647 | 123456 | | +# 2147483647 | -123456 | | +# 2147483647 | 2147483647 | | +# 2147483647 | -2147483647 | | +# -2147483647 | 0 | | +# -2147483647 | 123456 | | +# -2147483647 | -123456 | | +# -2147483647 | 2147483647 | | +# -2147483647 | -2147483647 | | +# (25 rows) +# +# lateral reference in a PlaceHolderVar evaluated at join level +# 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) + + +# check handling of nested appendrels inside LATERAL +query II colnames,rowsort +select * from + ((select 2 as v) union all (select 3 as v)) as q1 + cross join lateral + ((select * from + ((select 4 as v) union all (select 5 as v)) as q3) + union all + (select q1.v) + ) as q2; +---- +v v +2 4 +2 5 +2 2 +3 4 +3 5 +3 3 + +# TODO(benesch): this panics. +# check we don't try to do a unique-ified semijoin with LATERAL +# query III colnames +# select * from +# (values (0,9998), (1,1000)) v(id,x), +# lateral (select f1 from int4_tbl +# where f1 = any (select unique1 from tenk1 +# where unique2 = v.x offset 0)) ss; +# ---- +# id x f1 +# 0 4 0 + +query error column "f1" does not exist +select f1,g from int4_tbl a, (select f1 as g) ss; + +query error column "a.f1" does not exist +select f1,g from int4_tbl a, (select a.f1 as g) ss; + +query error column "f1" does not exist +select f1,g from int4_tbl a cross join (select f1 as g) ss; + +query error column "a.f1" does not exist +select f1,g from int4_tbl a cross join (select a.f1 as g) ss; + +# SQL:2008 says the left table is in scope but illegal to access here +query error the combining JOIN type must be INNER or LEFT for a LATERAL reference +select f1,g from int4_tbl a right join lateral generate_series(0, a.f1) g on true; + +query error the combining JOIN type must be INNER or LEFT for a LATERAL reference +select f1,g from int4_tbl a full join lateral generate_series(0, a.f1) g on true; + +# check we complain about ambiguous table references +# query error table reference "x" is ambiguous +# select * from +# int8_tbl x cross join (int4_tbl x cross join lateral (select x.f1) ss); + +# LATERAL can be used to put an aggregate into the FROM clause of its query +# query error aggregate functions are not allowed in FROM clause of their own query level +# select 1 from tenk1 a, lateral (select max(a.unique1) from int4_tbl b) ss; diff --git a/test/sqllogictest/table_func.slt b/test/sqllogictest/table_func.slt index 7b1b5a5a59c07..49732fecd24bb 100644 --- a/test/sqllogictest/table_func.slt +++ b/test/sqllogictest/table_func.slt @@ -82,7 +82,12 @@ EXPLAIN RAW PLAN FOR SELECT generate_series FROM generate_series(-2, 2) ---- %0 = | Constant () -| FlatMap generate_series(-(2), 2) + +%1 = +| CallTable generate_series(-(2), 2) + +%2 = +| InnerLateralJoin %0 %1 on true EOF @@ -167,7 +172,12 @@ EXPLAIN RAW PLAN FOR SELECT * FROM x, generate_series(1, a) ---- %0 = | Get materialize.public.x (u5) -| FlatMap generate_series(1, #0) + +%1 = +| CallTable generate_series(1, #^0) + +%2 = +| InnerLateralJoin %0 %1 on true EOF @@ -176,7 +186,12 @@ EXPLAIN RAW PLAN FOR SELECT * FROM x, generate_series(100::bigint, a) ---- %0 = | Get materialize.public.x (u5) -| FlatMap generate_series(i32toi64(100), i32toi64(#0)) + +%1 = +| CallTable generate_series(i32toi64(100), i32toi64(#^0)) + +%2 = +| InnerLateralJoin %0 %1 on true EOF @@ -185,8 +200,18 @@ EXPLAIN PLAN FOR SELECT * FROM x, generate_series(1, a) ---- %0 = | Get materialize.public.x (u5) +| ArrangeBy (#0) + +%1 = +| Get materialize.public.x (u5) | FlatMap generate_series(1, #0) -| | demand = (#0..#2) +| | demand = (#0, #2) + +%2 = +| Join %0 %1 (= #0 #2) +| | implementation = Differential %1 %0.(#0) +| | demand = (#0, #1, #4) +| Project (#0, #1, #4) EOF @@ -204,9 +229,23 @@ EXPLAIN PLAN FOR SELECT * FROM x x1, x x2, generate_series(x1.a, x2.a) WHERE x1. | Join %0 %1 | | implementation = Differential %1 %0.() | | demand = (#0..#3) -| FlatMap generate_series(#0, #2) -| | demand = (#0..#4) + +%3 = +| Get %2 | Filter (#1 = #3) +| ArrangeBy (#0, #2) + +%4 = +| Get %2 +| Distinct group=(#0, #2) +| FlatMap generate_series(#0, #1) +| | demand = (#0..#2) + +%5 = +| Join %3 %4 (= #0 #4) (= #2 #5) +| | implementation = Differential %4 %3.(#0, #2) +| | demand = (#0..#3, #6) +| Project (#0..#3, #6) EOF @@ -224,9 +263,23 @@ EXPLAIN PLAN FOR SELECT * FROM x x1, x x2, generate_series(x1.a, x2.a) WHERE x1. | Join %0 %1 | | implementation = Differential %1 %0.() | | demand = (#0..#3) -| FlatMap generate_series(#0, #2) -| | demand = (#0..#4) + +%3 = +| Get %2 | Filter (#1 = #3) +| ArrangeBy (#0, #2) + +%4 = +| Get %2 +| Distinct group=(#0, #2) +| FlatMap generate_series(#0, #1) +| | demand = (#0..#2) + +%5 = +| Join %3 %4 (= #0 #4) (= #2 #5) +| | implementation = Differential %4 %3.(#0, #2) +| | demand = (#0..#3, #6) +| Project (#0..#3, #6) EOF