diff --git a/sql/catalyst/src/main/scala/org/apache/spark/sql/catalyst/analysis/Analyzer.scala b/sql/catalyst/src/main/scala/org/apache/spark/sql/catalyst/analysis/Analyzer.scala index 71bad44c6dc08..edc1a2200db28 100644 --- a/sql/catalyst/src/main/scala/org/apache/spark/sql/catalyst/analysis/Analyzer.scala +++ b/sql/catalyst/src/main/scala/org/apache/spark/sql/catalyst/analysis/Analyzer.scala @@ -209,7 +209,7 @@ class Analyzer( object ResolveRecursiveReferneces extends Rule[LogicalPlan] { def apply(plan: LogicalPlan): LogicalPlan = { val recursiveTables = plan.collect { - case rt @ RecursiveTable(name, _, _) if rt.anchorResolved => name -> rt + case rt @ RecursiveTable(name, _, _, _) if rt.anchorResolved => name -> rt }.toMap plan.resolveOperatorsUp { @@ -231,123 +231,139 @@ class Analyzer( substituteCTE(child, relations.foldLeft(Seq.empty[(String, LogicalPlan)]) { case (resolved, (name, relation)) => val recursiveTableName = if (allowRecursion) Some(name) else None - resolved :+ - name -> executeSameContext(substituteCTE(relation, resolved, recursiveTableName)) - }, None) + val (substitutedPlan, recursiveReferenceFound) = + substituteCTE(relation, resolved, recursiveTableName) + val analyzedPlan = executeSameContext(substitutedPlan) + resolved :+ name -> ( + if (recursiveReferenceFound) { + insertRecursiveTable(analyzedPlan, recursiveTableName.get) + } else { + analyzedPlan + }) + }, None)._1 case other => other } def substituteCTE( plan: LogicalPlan, cteRelations: Seq[(String, LogicalPlan)], - recursiveTableName: Option[String]): LogicalPlan = { - def substitute( - plan: LogicalPlan, - inSubQuery: Boolean = false): (LogicalPlan, Boolean) = { - var recursiveReferenceFound = false - - val newPlan = plan resolveOperatorsDown { - case u: UnresolvedRelation => - val table = u.tableIdentifier.table - - val recursiveReference = recursiveTableName.find(resolver(_, table)).map { name => - if (inSubQuery) { - throw new AnalysisException( - s"Recursive reference ${name} can't be used in a subquery") - } - - recursiveReferenceFound = true + recursiveTableName: Option[String]): (LogicalPlan, Boolean) = { + var recursiveReferenceFound = false - UnresolvedRecursiveReference(name) - } + val newPlan = plan resolveOperatorsDown { + case u: UnresolvedRelation => + val table = u.tableIdentifier.table - recursiveReference - .orElse(cteRelations.find(x => resolver(x._1, table)).map(_._2)) - .getOrElse(u) + val recursiveReference = recursiveTableName.find(resolver(_, table)).map { name => + recursiveReferenceFound = true - case other => - // This cannot be done in ResolveSubquery because ResolveSubquery does not know the CTE. - other transformExpressions { - case e: SubqueryExpression => e.withNewPlan(substitute(e.plan, true)._1) - } - } + UnresolvedRecursiveReference(name) + } - (newPlan, recursiveReferenceFound) + recursiveReference + .orElse(cteRelations.find(x => resolver(x._1, table)).map(_._2)) + .getOrElse(u) + case w @ With(_, cteRelations, _) => + w.copy(cteRelations = cteRelations.map { + case (name, sa @ SubqueryAlias(_, plan)) => + val (substitutedPlan, recursiveReferenceFoundInCTE) = + substituteCTE(plan, Seq.empty, recursiveTableName) + recursiveReferenceFound |= recursiveReferenceFoundInCTE + (name, sa.copy(child = substitutedPlan)) + }) + case other => + // This cannot be done in ResolveSubquery because ResolveSubquery does not know the CTE. + other transformExpressions { + case e: SubqueryExpression => + val (substitutedPlan, recursiveReferenceFoundInSubQuery) = + substituteCTE(e.plan, cteRelations, recursiveTableName) + + recursiveReferenceFound |= recursiveReferenceFoundInSubQuery + e.withNewPlan(substitutedPlan) + } } + (newPlan, recursiveReferenceFound) + } + + def insertRecursiveTable(plan: LogicalPlan, recursiveTableName: String): LogicalPlan = plan match { - case SubqueryAlias(name, u: Union) if recursiveTableName.contains(name.identifier) => + case sa @ SubqueryAlias(name, u: Union) if name.identifier == recursiveTableName => def combineUnions(union: Union): Seq[LogicalPlan] = union.children.flatMap { case u: Union => combineUnions(u) case o => Seq(o) } - val substitutedTerms = combineUnions(u).map(substitute(_)) - val (anchorTerms, recursiveTerms) = substitutedTerms.partition(!_._2) + val combinedTerms = combineUnions(u) + val (anchorTerms, recursiveTerms) = combinedTerms.partition(!_.collectFirst { + case UnresolvedRecursiveReference(name) if name == recursiveTableName => true + }.isDefined) if (!recursiveTerms.isEmpty) { if (anchorTerms.isEmpty) { throw new AnalysisException("There should be at least 1 anchor term defined in the " + - s"recursive query ${recursiveTableName.get}") + s"recursive query ${recursiveTableName}") } - val recursiveTermPlans = recursiveTerms.map(_._1) - def traversePlanAndCheck( plan: LogicalPlan, - isRecursiveReferenceAllowed: Boolean = true): Boolean = plan match { - case UnresolvedRecursiveReference(name) if recursiveTableName.contains(name) => + isRecursiveReferenceAllowed: Boolean = true): Int = plan match { + case UnresolvedRecursiveReference(name) if name == recursiveTableName => if (!isRecursiveReferenceAllowed) { - throw new AnalysisException(s"Recursive reference ${recursiveTableName.get} " + + throw new AnalysisException(s"Recursive reference ${recursiveTableName} " + "cannot be used here. This can be caused by using it in a different join " + "than inner or left outer or right outer, using it on inner side of an " + - "outer join or using it in an aggregate or with a distinct statement") + "outer join, using it with aggregate or distinct, using it in a subquery " + + "or using it multiple times in a recursive term.") } - true + 1 case Join(left, right, Inner, _, _) => - val l = traversePlanAndCheck(left, isRecursiveReferenceAllowed) - val r = traversePlanAndCheck(right, isRecursiveReferenceAllowed) - if (l && r) { - throw new AnalysisException(s"Recursive reference ${recursiveTableName.get} " + - "cannot be used on both sides of an inner join") - } - l || r + traversePlanAndCheck(left, isRecursiveReferenceAllowed) + + traversePlanAndCheck(right, isRecursiveReferenceAllowed) case Join(left, right, LeftOuter, _, _) => - traversePlanAndCheck(left, isRecursiveReferenceAllowed) || + traversePlanAndCheck(left, isRecursiveReferenceAllowed) + traversePlanAndCheck(right, false) case Join(left, right, RightOuter, _, _) => - traversePlanAndCheck(left, false) || + traversePlanAndCheck(left, false) + traversePlanAndCheck(right, isRecursiveReferenceAllowed) case Join(left, right, _, _, _) => - traversePlanAndCheck(left, false) || traversePlanAndCheck(right, false) + traversePlanAndCheck(left, false) + + traversePlanAndCheck(right, false) case Aggregate(_, _, child) => traversePlanAndCheck(child, false) case Distinct(child) => traversePlanAndCheck(child, false) case o => - o.children.map(traversePlanAndCheck(_, isRecursiveReferenceAllowed)).contains(true) + o transformExpressions { + case se: SubqueryExpression => + traversePlanAndCheck(se.plan, false) + se + } + o.children + .map(traversePlanAndCheck(_, isRecursiveReferenceAllowed)) + .foldLeft(0)(_ + _) } - recursiveTermPlans.foreach(traversePlanAndCheck(_)) + recursiveTerms.foreach { recursiveTerm => + if (traversePlanAndCheck(recursiveTerm) > 1) { + throw new AnalysisException(s"Recursive reference ${recursiveTableName} cannot " + + "be used multiple times in a recursive term") + } + } RecursiveTable( - recursiveTableName.get, - SubqueryAlias(name, Union(anchorTerms.map(_._1))), - Union(recursiveTermPlans)) + recursiveTableName, + sa.copy(child = Union(anchorTerms)), + Union(recursiveTerms), + None) } else { - SubqueryAlias(name, Union(substitutedTerms.map(_._1))) + SubqueryAlias(recursiveTableName, Union(combinedTerms)) } case _ => - val (substitutedPlan, recursiveReferenceFound) = substitute(plan) - - if (recursiveReferenceFound) { - throw new AnalysisException(s"Recursive query ${recursiveTableName.get} should " + - "contain UNION ALL statements only") - } - - substitutedPlan + throw new AnalysisException(s"Recursive query ${recursiveTableName} should contain " + + "UNION ALL statements only. This can also be caused by ORDER BY or LIMIT keywords " + + "used on result of UNION ALL.") } } - } /** * Substitute child plan with WindowSpecDefinitions. @@ -1656,7 +1672,7 @@ class Analyzer( case RecursiveReference(name, _) => throw new AnalysisException(s"Recursive reference ${name} can't be used in an " + "aggregate") - case RecursiveTable(_, _, recursiveTerm) => + case RecursiveTable(_, _, recursiveTerm, _) => case o => o.children.map(traversePlanAndCheck) } diff --git a/sql/catalyst/src/main/scala/org/apache/spark/sql/catalyst/plans/logical/basicLogicalOperators.scala b/sql/catalyst/src/main/scala/org/apache/spark/sql/catalyst/plans/logical/basicLogicalOperators.scala index 6ad0b15133065..6fda3f1e7a700 100644 --- a/sql/catalyst/src/main/scala/org/apache/spark/sql/catalyst/plans/logical/basicLogicalOperators.scala +++ b/sql/catalyst/src/main/scala/org/apache/spark/sql/catalyst/plans/logical/basicLogicalOperators.scala @@ -62,7 +62,8 @@ case class Subquery(child: LogicalPlan) extends OrderPreservingUnaryNode { case class RecursiveTable( name: String, anchorTerm: LogicalPlan, - recursiveTerm: LogicalPlan) extends LogicalPlan { + recursiveTerm: LogicalPlan, + limit: Option[Long]) extends LogicalPlan { override def children: Seq[LogicalPlan] = Seq(anchorTerm, recursiveTerm) override def output: Seq[Attribute] = anchorTerm.output.map(_.withNullability(true)) @@ -553,7 +554,8 @@ case class With( override def simpleString(maxFields: Int): String = { val cteAliases = truncatedString(cteRelations.map(_._1), "[", ", ", "]", maxFields) - s"CTE $cteAliases" + val recursive = if (allowRecursion) " recursive" else "" + s"CTE$recursive $cteAliases" } override def innerChildren: Seq[LogicalPlan] = cteRelations.map(_._2) diff --git a/sql/core/src/main/scala/org/apache/spark/sql/execution/SparkStrategies.scala b/sql/core/src/main/scala/org/apache/spark/sql/execution/SparkStrategies.scala index 583fe7eebbede..d3e08962c5a52 100644 --- a/sql/core/src/main/scala/org/apache/spark/sql/execution/SparkStrategies.scala +++ b/sql/core/src/main/scala/org/apache/spark/sql/execution/SparkStrategies.scala @@ -608,9 +608,9 @@ abstract class SparkStrategies extends QueryPlanner[SparkPlan] { execution.ProjectExec(projectList, planLater(child)) :: Nil case logical.Filter(condition, child) => execution.FilterExec(condition, planLater(child)) :: Nil - case logical.RecursiveTable(name, anchorTerm, recursiveTerm) => + case logical.RecursiveTable(name, anchorTerm, recursiveTerm, limit) => execution.RecursiveTableExec( - name, planLater(anchorTerm), planLater(recursiveTerm)) :: Nil + name, planLater(anchorTerm), planLater(recursiveTerm), limit) :: Nil case logical.RecursiveReference(name, output) => execution.RecursiveReferenceExec(name, output) :: Nil case f: logical.TypedFilter => diff --git a/sql/core/src/main/scala/org/apache/spark/sql/execution/basicPhysicalOperators.scala b/sql/core/src/main/scala/org/apache/spark/sql/execution/basicPhysicalOperators.scala index ca342a53796a6..b5c91b8b5982e 100644 --- a/sql/core/src/main/scala/org/apache/spark/sql/execution/basicPhysicalOperators.scala +++ b/sql/core/src/main/scala/org/apache/spark/sql/execution/basicPhysicalOperators.scala @@ -27,7 +27,7 @@ import org.apache.spark.sql.catalyst.expressions._ import org.apache.spark.sql.catalyst.expressions.BindReferences.bindReferences import org.apache.spark.sql.catalyst.expressions.codegen._ import org.apache.spark.sql.catalyst.plans.physical._ -import org.apache.spark.sql.execution.exchange.{ExchangeCoordinator, ShuffleExchangeExec} +import org.apache.spark.sql.execution.exchange.{ExchangeCoordinator, ReusedExchangeExec, ShuffleExchangeExec} import org.apache.spark.sql.execution.metric.SQLMetrics import org.apache.spark.sql.internal.SQLConf import org.apache.spark.sql.types.LongType @@ -232,7 +232,8 @@ case class FilterExec(condition: Expression, child: SparkPlan) case class RecursiveTableExec( name: String, anchorTerm: SparkPlan, - recursiveTerm: SparkPlan) extends SparkPlan { + recursiveTerm: SparkPlan, + limit: Option[Long]) extends SparkPlan { // TODO: how to implement limit? override def children: Seq[SparkPlan] = Seq(anchorTerm, recursiveTerm) override def output: Seq[Attribute] = anchorTerm.output @@ -243,9 +244,10 @@ case class RecursiveTableExec( var temp = anchorTerm.execute().map(_.copy()).cache() var tempCount = temp.count() var result = temp + var sumCount = tempCount var level = 0 val levelLimit = conf.recursionLevelLimit - do { + while ((level == 0 || tempCount > 0) && limit.map(_ < sumCount).getOrElse(true)) { if (level > levelLimit) { throw new SparkException("Recursion level limit reached but query hasn't exhausted, try " + s"increasing ${SQLConf.RECURSION_LEVEL_LIMIT.key}") @@ -261,13 +263,17 @@ case class RecursiveTableExec( if (level > 0) { newRecursiveTerm.reset() } - newRecursiveTerm.foreach { + + def updateRecursiveTables(plan: SparkPlan): Unit = plan.foreach { _ match { case rr: RecursiveReferenceExec if rr.name == name => rr.recursiveTable = temp + case ReusedExchangeExec(_, child) => updateRecursiveTables(child) case _ => } } + updateRecursiveTables(newRecursiveTerm) + val newTemp = newRecursiveTerm.execute().map(_.copy()).cache() tempCount = newTemp.count() temp.unpersist() @@ -276,7 +282,7 @@ case class RecursiveTableExec( result = result.union(temp) level = level + 1 - } while (tempCount > 0) + } result } diff --git a/sql/core/src/main/scala/org/apache/spark/sql/execution/exchange/Exchange.scala b/sql/core/src/main/scala/org/apache/spark/sql/execution/exchange/Exchange.scala index 1a5b7599bb7d9..492b24298ebe9 100644 --- a/sql/core/src/main/scala/org/apache/spark/sql/execution/exchange/Exchange.scala +++ b/sql/core/src/main/scala/org/apache/spark/sql/execution/exchange/Exchange.scala @@ -26,7 +26,7 @@ import org.apache.spark.sql.catalyst.InternalRow import org.apache.spark.sql.catalyst.expressions.{Attribute, AttributeMap, Expression, SortOrder} import org.apache.spark.sql.catalyst.plans.physical.Partitioning import org.apache.spark.sql.catalyst.rules.Rule -import org.apache.spark.sql.execution.{LeafExecNode, SparkPlan, UnaryExecNode} +import org.apache.spark.sql.execution._ import org.apache.spark.sql.internal.SQLConf import org.apache.spark.sql.types.StructType @@ -56,6 +56,10 @@ case class ReusedExchangeExec(override val output: Seq[Attribute], child: Exchan child.execute() } + override def doReset(): Unit = { + child.reset() + } + override protected[sql] def doExecuteBroadcast[T](): broadcast.Broadcast[T] = { child.executeBroadcast() } @@ -90,11 +94,22 @@ case class ReuseExchange(conf: SQLConf) extends Rule[SparkPlan] { return plan } // Build a hash map using schema of exchanges to avoid O(N*N) sameResult calls. - val exchanges = mutable.HashMap[StructType, ArrayBuffer[Exchange]]() + // TODO: document recursion related changes + val allExchanges = mutable.Stack[mutable.HashMap[StructType, ArrayBuffer[Exchange]]]() + allExchanges.push(mutable.HashMap[StructType, ArrayBuffer[Exchange]]()) + val recursiveTables = mutable.Set.empty[String] plan.transformUp { + case rr @ RecursiveReferenceExec(name, _) if !recursiveTables.contains(name) => + allExchanges.push(mutable.HashMap[StructType, ArrayBuffer[Exchange]]()) + recursiveTables += name + rr + case rt @ RecursiveTableExec(name, _, _, _) => + allExchanges.pop() + recursiveTables -= name + rt case exchange: Exchange => // the exchanges that have same results usually also have same schemas (same column names). - val sameSchema = exchanges.getOrElseUpdate(exchange.schema, ArrayBuffer[Exchange]()) + val sameSchema = allExchanges.top.getOrElseUpdate(exchange.schema, ArrayBuffer[Exchange]()) val samePlan = sameSchema.find { e => exchange.sameResult(e) } diff --git a/sql/core/src/test/resources/sql-tests/inputs/recursion.sql b/sql/core/src/test/resources/sql-tests/inputs/recursion.sql index 9941e3ae9a303..c98be33320daa 100644 --- a/sql/core/src/test/resources/sql-tests/inputs/recursion.sql +++ b/sql/core/src/test/resources/sql-tests/inputs/recursion.sql @@ -18,6 +18,75 @@ WITH RECURSIVE r AS ( ) SELECT * FROM r ORDER BY level; +-- sum of 1..100 +WITH RECURSIVE t AS ( + VALUES (1) AS T(n) + UNION ALL + SELECT n + 1 FROM t WHERE n < 100 +) +SELECT SUM(n) FROM t; + +-- terminate recursion without level +WITH RECURSIVE t AS ( + SELECT (VALUES(1)) AS n + UNION ALL + SELECT n + 1 FROM t WHERE n < 5 +) +SELECT * FROM t; + +-- using string column in recursion +WITH RECURSIVE t AS ( + SELECT 'foo' AS n + UNION ALL + SELECT n || ' bar' FROM t WHERE LENGTH(n) < 20 +) +SELECT n FROM t; + +---- TODO: Stack overflow, should work??? +---- using inside subquery +--SET spark.sql.cte.recursion.level.limit = 500; +-- +--WITH RECURSIVE t1 AS ( +-- SELECT 1 AS n +-- UNION ALL +-- SELECT n + 1 FROM t WHERE n < 500 +--), +--t2 AS ( +-- SELECT 1 AS n +-- UNION ALL +-- SELECT n + 1 FROM t WHERE n < 100 +--) +--SELECT COUNT(*) FROM t1 WHERE n < ( +-- SELECT COUNT(*) FROM ( +-- SELECT * FROM t2 WHERE n < 50000 +-- ) +-- WHERE n < 100 +--); + +-- view based on recursion +CREATE TEMPORARY VIEW sums_1_100 AS +WITH RECURSIVE t AS ( + VALUES (1) AS T(n) + UNION ALL + SELECT n + 1 FROM t WHERE n < 100 +) +SELECT SUM(n) FROM t; + +SELECT * FROM sums_1_100; + +-- recursive term has sub UNION +WITH RECURSIVE t AS ( + VALUES (1, 2) AS T(i, j) + UNION ALL + SELECT t2.i, t.j + 1 + FROM ( + SELECT 2 AS i + UNION ALL SELECT 3 AS i + ) AS t2 + JOIN t ON (t2.i = t.i + 1) +) +SELECT * FROM t; + -- unlimited recursion fails at spark.sql.cte.recursion.level.limits level WITH RECURSIVE r AS ( VALUES (0, 'A') AS T(level, data) @@ -162,51 +231,266 @@ SELECT * FROM r; -- department structure represented here is as follows: -- --- ROOT-->A-->B-->C --- | | --- | ∨ --- | D-->F --- ∨ --- E-->G +-- ROOT--->A--->B--->C +-- | | +-- | ∨ +-- | D--->F +-- ∨ +-- E--->G CREATE TEMPORARY VIEW department AS SELECT * FROM VALUES - (0, null, "ROOT"), - (1, 0, "A"), - (2, 1, "B"), - (3, 2, "C"), - (4, 2, "D"), - (5, 0, "E"), - (6, 4, "F"), - (7, 5, "G") - AS department(id, parent_department_id, name); - --- departments under 'A' + (0, null, 'ROOT'), + (1, 0, 'A'), + (2, 1, 'B'), + (3, 2, 'C'), + (4, 2, 'D'), + (5, 0, 'E'), + (6, 4, 'F'), + (7, 5, 'G') + AS department(id, parent_department, name); + +-- all departments under 'A', result should be A, B, C, D and F +WITH RECURSIVE subdepartment AS ( + SELECT name as root_name, * FROM department WHERE name = 'A' + UNION ALL + SELECT sd.root_name, d.* + FROM department AS d, subdepartment AS sd + WHERE d.parent_department = sd.id +) +SELECT * FROM subdepartment ORDER BY name; + +-- all departments under 'A' with "level" number +WITH RECURSIVE subdepartment AS ( + SELECT 1 as level, id, parent_department, name FROM department WHERE name = 'A' + UNION ALL + SELECT sd.level + 1, d.* + FROM department AS d, subdepartment AS sd + WHERE d.parent_department = sd.id +) +SELECT * FROM subdepartment ORDER BY name; + +-- all departments under 'A' with "level" number, only shows level 2 or more +WITH RECURSIVE subdepartment AS ( + SELECT 1 as level, id, parent_department, name FROM department WHERE name = 'A' + UNION ALL + SELECT sd.level + 1, d.* + FROM department AS d, subdepartment AS sd + WHERE d.parent_department = sd.id +) +SELECT * FROM subdepartment WHERE level >= 2 ORDER BY name; + +-- departments above 'A' WITH RECURSIVE subdepartment AS ( SELECT * FROM department WHERE name = 'A' UNION ALL SELECT d.* FROM department AS d - JOIN subdepartment AS sd ON (sd.id = d.parent_department_id) + JOIN subdepartment AS sd ON (sd.parent_department = d.id) ) SELECT id, name FROM subdepartment ORDER BY name; --- departments above 'A' +-- RECURSIVE is ignored if the query has no self-reference WITH RECURSIVE subdepartment AS ( SELECT * FROM department WHERE name = 'A' +) +SELECT * FROM subdepartment ORDER BY name; + +-- recursion via a VIEW +CREATE TEMPORARY VIEW vsubdepartment AS + WITH RECURSIVE subdepartment AS ( + SELECT * FROM department WHERE name = 'A' + UNION ALL + SELECT d.* + FROM department AS d, subdepartment AS sd + WHERE d.parent_department = sd.id + ) + SELECT * FROM subdepartment; + +SELECT * FROM vsubdepartment ORDER BY name; + +-- tree structure represented here is as follows: +-- +-- ROOT--->1--->2---+--->4--->9--->14 +-- | | | | +-- | ∨ ∨ ∨ +-- | 5 6 10 +-- ∨ +-- 3--->7---+--->11--->15 +-- | | | | +-- ∨ ∨ ∨ ∨ +-- 8 12 13 16 +CREATE TEMPORARY VIEW tree AS SELECT * FROM VALUES + (1, NULL), + (2, 1), + (3, 1), + (4, 2), + (5, 2), + (6, 2), + (7, 3), + (8, 3), + (9, 4), + (10, 4), + (11, 7), + (12, 7), + (13, 7), + (14, 9), + (15, 11), + (16, 11) +AS (id, parent_id); + +-- get all paths from "second level" nodes to leaf nodes +WITH RECURSIVE t AS ( + VALUES(1, ARRAY_REMOVE(ARRAY(0), 0)) AS T(id, path) UNION ALL - SELECT d.* - FROM department AS d - JOIN subdepartment AS sd ON (sd.parent_department_id = d.id) + SELECT tree.id, t.path || ARRAY(tree.id) + FROM tree + JOIN t ON tree.parent_id = t.id ) -SELECT id, name FROM subdepartment ORDER BY name; +SELECT t1.*, t2.* +FROM t AS t1 +JOIN t AS t2 ON t1.path[0] = t2.path[0] AND SIZE(t1.path) = 1 AND SIZE(t2.path) > 1 +ORDER BY t1.id, t2.id; + +-- count all paths from "second level" nodes to leaf nodes +WITH RECURSIVE t AS ( + VALUES(1, ARRAY_REMOVE(ARRAY(0), 0)) AS T(id, path) + UNION ALL + SELECT tree.id, t.path || ARRAY(tree.id) + FROM tree + JOIN t ON tree.parent_id = t.id +) +SELECT t1.id, COUNT(t2.*) +FROM t AS t1 +JOIN t AS t2 ON t1.path[0] = t2.path[0] AND SIZE(t1.path) = 1 AND SIZE(t2.path) > 1 +GROUP BY t1.id +ORDER BY t1.id; + +-- get all paths +WITH RECURSIVE t AS ( + VALUES(1, ARRAY_REMOVE(ARRAY(0), 0)) AS T(id, path) + UNION ALL + SELECT tree.id, t.path || ARRAY(tree.id) + FROM tree + JOIN t ON tree.parent_id = t.id +) +SELECT t1.id, t2.path, STRUCT(t2.*) +FROM t AS t1 +JOIN t AS t2 ON t1.id = t2.id; + +-- graph structure represented here is as follows: +-- +-- +--->3 +-- | ∧ +-- | | +-- 2<---1--->4 +-- ∧ | +-- | ∨ +-- +----5 +CREATE TEMPORARY VIEW graph AS SELECT * FROM VALUES + (1, 2, 'arc 1 -> 2'), + (1, 3, 'arc 1 -> 3'), + (2, 3, 'arc 2 -> 3'), + (1, 4, 'arc 1 -> 4'), + (4, 5, 'arc 4 -> 5'), + (5, 1, 'arc 5 -> 1') +AS (f, t, label); + +-- test cycle detection +WITH RECURSIVE search_graph AS ( + SELECT *, ARRAY(STRUCT(g.f, g.t)) AS path, false AS cycle FROM graph g + UNION ALL + SELECT g.*, path || ARRAY(STRUCT(g.f, g.t)), ARRAY_CONTAINS(path, STRUCT(g.f, g.t)) + FROM graph g, search_graph sg + WHERE g.f = sg.t AND NOT cycle +) +SELECT * FROM search_graph; + +-- ordering by the path column has same effect as SEARCH DEPTH FIRST +WITH RECURSIVE search_graph AS ( + SELECT *, ARRAY(STRUCT(g.f, g.t)) AS path, false AS cycle FROM graph g + UNION ALL + SELECT g.*, path || ARRAY(STRUCT(g.f, g.t)), ARRAY_CONTAINS(path, STRUCT(g.f, g.t)) + FROM graph g, search_graph sg + WHERE g.f = sg.t AND NOT cycle +) +SELECT * FROM search_graph ORDER BY path; + +-- test multiple WITH queries +WITH RECURSIVE y AS ( + VALUES (1) AS T(id) +), +x AS ( + SELECT * FROM y + UNION ALL + SELECT id + 1 FROM x WHERE id < 5 +) +SELECT * FROM x; + +WITH RECURSIVE x AS ( + VALUES (1) AS T(id) + UNION ALL + SELECT id + 1 FROM x WHERE id < 5 +), +y AS ( + VALUES (1) AS T(id) + UNION ALL + SELECT id + 1 FROM y WHERE id < 10 +) +SELECT * FROM y LEFT JOIN x ON x.id = y.id; + +WITH RECURSIVE x AS ( + VALUES (1) AS T(id) + UNION ALL + SELECT id + 1 FROM x WHERE id < 5 +), +y AS ( + VALUES (1) AS T(id) + UNION ALL + SELECT id + 1 FROM x WHERE id < 10 +) +SELECT * FROM y LEFT JOIN x ON x.id = y.id; + +WITH RECURSIVE x AS ( + SELECT 1 AS id + UNION ALL + SELECT id + 1 FROM x WHERE id < 3 +), +y AS ( + SELECT * FROM x + UNION ALL + SELECT * FROM x +), +z AS ( + SELECT * FROM x + UNION ALL + SELECT id + 1 FROM z WHERE id < 10 +) +SELECT * FROM z; + +WITH RECURSIVE x AS ( + SELECT 1 AS id + UNION ALL + SELECT id + 1 FROM x WHERE id < 3 +), +y AS ( + SELECT * FROM x + UNION ALL + SELECT * FROM x +), +z AS ( + SELECT * FROM y + UNION ALL + SELECT id + 1 FROM z WHERE id < 10 +) +SELECT * FROM z; -- routes represented here is as follows: -- --- New York<->Boston --- | ∧ --- ∨ | --- Washington---+ --- | --- ∨ +-- New York<-->Boston +-- | ∧ +-- ∨ | +-- Washington--+ +-- | +-- ∨ -- Raleigh CREATE TEMPORARY VIEW routes AS SELECT * FROM VALUES ('New York', 'Washington'), @@ -289,3 +573,327 @@ WITH RECURSIVE sudoku AS ( ) ) SELECT * FROM sudoku WHERE NOT ARRAY_CONTAINS(puzzle, 0); + +-- error cases +WITH RECURSIVE x AS ( + SELECT 1 AS n + INTERSECT + SELECT n + 1 FROM x +) +SELECT * FROM x; + +WITH RECURSIVE x AS ( + SELECT 1 AS n + INTERSECT ALL + SELECT n + 1 FROM x +) +SELECT * FROM x; + +WITH RECURSIVE x AS ( + SELECT 1 AS n + EXCEPT + SELECT n + 1 FROM x +) +SELECT * FROM x; + +WITH RECURSIVE x AS ( + SELECT 1 AS n + EXCEPT ALL + SELECT n + 1 FROM x +) +SELECT * FROM x; + +WITH RECURSIVE x AS ( + SELECT n FROM x +) +SELECT * FROM x; + +WITH RECURSIVE t AS ( + INSERT INTO y SELECT * FROM t +) +VALUES(FALSE); + +CREATE TEMPORARY VIEW y AS SELECT EXPLODE(SEQUENCE(1, 10)) AS a; + +WITH RECURSIVE x AS ( + SELECT a AS n FROM y WHERE a = 1 + UNION ALL + SELECT x.n + 1 FROM y LEFT JOIN x ON x.n = y.a WHERE n < 10 +) +SELECT * FROM x; + +WITH RECURSIVE x AS ( + SELECT a AS n FROM y WHERE a = 1 + UNION ALL + SELECT x.n + 1 FROM x RIGHT JOIN y ON x.n = y.a WHERE n < 10 +) +SELECT * FROM x; + +WITH RECURSIVE x AS ( + SELECT a AS n FROM y WHERE a = 1 + UNION ALL + SELECT x.n + 1 FROM x FULL JOIN y ON x.n = y.a WHERE n < 10 +) SELECT * FROM x; + +WITH RECURSIVE x AS ( + SELECT 1 AS n + UNION ALL + SELECT n + 1 + FROM x + WHERE n IN (SELECT * FROM x) +) +SELECT * FROM x; + +-- aggregate functions +WITH RECURSIVE x AS ( + SELECT 1 AS n + UNION ALL + SELECT COUNT(*) FROM x +) +SELECT * FROM x; + +WITH RECURSIVE x AS ( + SELECT 1 AS n + UNION ALL + SELECT SUM(n) FROM x +) +SELECT * FROM x; + +WITH RECURSIVE x AS ( + SELECT 1 AS n + UNION ALL + SELECT n + 1 FROM x + ORDER BY 1 +) +SELECT * FROM x; + +WITH RECURSIVE x AS ( + SELECT 1 AS n + UNION ALL + SELECT n + 1 FROM x + LIMIT 10 +) +SELECT * FROM x; + +WITH RECURSIVE x AS ( + VALUES (1) AS T(id) + UNION ALL + SELECT ( + SELECT * FROM x + ) + FROM x + WHERE id < 5 +) +SELECT * FROM x; + +-- mutual recursive query is not implemented, +-- y gets resolved as a view defined before and is not treated as forward reference +WITH RECURSIVE x AS ( + SELECT 1 AS id + UNION ALL + SELECT id + 1 FROM y WHERE id < 5 +), +y AS ( + SELECT 1 AS id + UNION ALL + SELECT id + 1 + FROM x + WHERE id < 5 +) +SELECT * FROM x; + +-- this kind of non-linear recursion is allowed +-- PostgreSQL doesn't allow it but MSSQL does +WITH RECURSIVE foo AS ( + VALUES (1) AS T(i) + UNION ALL + SELECT i + 1 FROM foo WHERE i < 10 + UNION ALL + SELECT i + 1 FROM foo WHERE i < 5 +) +SELECT i, COUNT(*) FROM foo GROUP BY i ORDER BY i; + +-- this kind of non-linear recursion is not allowed, a recursive term can contain only one recursive reference +WITH RECURSIVE foo AS ( + VALUES (1) AS T(i) + UNION ALL + SELECT * FROM ( + SELECT i + 1 + FROM foo WHERE i < 10 + UNION ALL + SELECT i + 1 + FROM foo WHERE i < 5 + ) AS t +) +SELECT i, COUNT(*) FROM foo GROUP BY i ORDER BY i; + +-- this kind of non-linear recursion is not allowed, a recursive term can contain only one recursive reference +WITH RECURSIVE foo AS ( + VALUES (1) AS T(i) + UNION ALL ( + SELECT i + 1 FROM foo WHERE i < 10 + EXCEPT + SELECT i + 1 FROM foo WHERE i < 5 + ) +) +SELECT * FROM foo; + +-- this kind of non-linear recursion is not allowed, a recursive term can contain only one recursive reference +WITH RECURSIVE foo AS ( + VALUES (1) AS T(i) + UNION ALL ( + SELECT i + 1 FROM foo WHERE i < 10 + INTERSECT + SELECT i + 1 FROM foo WHERE i < 5 + ) +) +SELECT * FROM foo; + +-- Wrong type induced from non-recursive term +WITH RECURSIVE foo AS ( + VALUES (1), (2) AS T(i) + UNION ALL + SELECT CAST((i + 1) AS DECIMAL(10, 0)) FROM foo WHERE i < 10 +) +SELECT * FROM foo; + +-- rejects different typmod, too (should we allow this?) +WITH RECURSIVE foo AS ( + SELECT CAST(i AS DECIMAL(3, 0)) FROM (VALUES (1), (2)) AS T(i) + UNION ALL + SELECT CAST((i + 1) AS DECIMAL(10, 0)) FROM foo WHERE i < 10 +) +SELECT * FROM foo; + +-- nested recursion +WITH RECURSIVE t AS ( + WITH RECURSIVE s AS ( + VALUES (1) AS T(i) + UNION ALL + SELECT i + 1 FROM s WHERE i < 10 + ) + SELECT i AS j FROM s + UNION ALL + SELECT j + 1 FROM t WHERE j < 10 +) +SELECT * FROM t; + +WITH RECURSIVE outermost AS ( + WITH innermost AS ( + SELECT * FROM outermost + ) + SELECT level + 1 FROM innermost WHERE level < 5 + UNION ALL + SELECT 0 AS level +) +SELECT * FROM outermost; + + +--NOT SUPPORTED: alias in CTE declaration + +---- sum of 1..100 +--WITH RECURSIVE t(n) AS ( +-- VALUES (1) +--UNION ALL +-- SELECT n+1 FROM t WHERE n < 100 +--) +--SELECT sum(n) FROM t; + + +--NOT SUPPORTED: RECURSIVE VIEW statements + +---- recursive view +--CREATE RECURSIVE VIEW nums (n) AS +-- VALUES (1) +--UNION ALL +-- SELECT n+1 FROM nums WHERE n < 5; +-- +--SELECT * FROM nums; +-- +--CREATE OR REPLACE RECURSIVE VIEW nums (n) AS +-- DOES NOT WORK +-- VALUES (1) +--UNION ALL +-- SELECT n+1 FROM nums WHERE n < 6; +-- +--SELECT * FROM nums; + + +--NOT SUPPORTED: UNION combinator in recursive CTE + +---- This is an infinite loop with UNION ALL, but not with UNION +--WITH RECURSIVE t(n) AS ( +-- SELECT 1 +--UNION +-- SELECT 10-n FROM t) +--SELECT * FROM t; + + +--NOT SUPPORTED: LIMIT (infinite recursion is dangerous, limit should be pushed down?) + +---- This'd be an infinite loop, but outside query reads only as much as needed +--WITH RECURSIVE t(n) AS ( +-- VALUES (1) +--UNION ALL +-- SELECT n+1 FROM t) +--SELECT * FROM t LIMIT 10; + + +--NOT SUPPORTED: different types of output in anchor and in recursive term + +-- POSTGRES: In a perfect world, this would work and resolve the literal as int ... +-- but for now, we have to be content with resolving to text too soon. +--WITH RECURSIVE t AS ( +-- SELECT '7' AS n +--UNION ALL +-- SELECT n+1 FROM t WHERE n < 10 +--) +--SELECT n FROM t; + + +--NOT SUPPORTED: WITH can't be nested into FROM as subquery + +-- inside subqueries +--SELECT count(*) FROM ( +-- WITH RECURSIVE t AS ( +-- SELECT 1 AS n UNION ALL SELECT n + 1 FROM t WHERE n < 500 +-- ) +-- SELECT * FROM t) AS t WHERE n < ( +-- SELECT count(*) FROM ( +-- WITH RECURSIVE t AS ( +-- SELECT 1 AS n UNION ALL SELECT n + 1 FROM t WHERE n < 100 +-- ) +-- SELECT * FROM t WHERE n < 50000 +-- ) AS t WHERE n < 100); + + +--NOT SUPPORTED: WITH can't be used with UNION ALL as subquery + +---- corner case in which sub-WITH gets initialized first +--with recursive q as ( +-- select * from department +-- union all +-- (with x as (select * from q) +-- select * from x) +-- ) +--select * from q limit 24; +-- +--with recursive q as ( +-- select * from department +-- union all +-- (with recursive x as ( +-- select * from department +-- union all +-- (select * from q union all select * from x) +-- ) +-- select * from x) +-- ) +--select * from q limit 32; + +--NOT SUPPORTED: forward reference + +---- forward reference OK +--WITH RECURSIVE +-- x(id) AS (SELECT * FROM y UNION ALL SELECT id+1 FROM x WHERE id < 5), +-- y(id) AS (values (1)) +-- SELECT * FROM x; diff --git a/sql/core/src/test/resources/sql-tests/results/recursion.sql.out b/sql/core/src/test/resources/sql-tests/results/recursion.sql.out index 1f9df9bb3cc02..f2af481c177fd 100644 --- a/sql/core/src/test/resources/sql-tests/results/recursion.sql.out +++ b/sql/core/src/test/resources/sql-tests/results/recursion.sql.out @@ -1,5 +1,5 @@ -- Automatically generated by SQLQueryTestSuite --- Number of queries: 25 +-- Number of queries: 73 -- !query 0 @@ -40,29 +40,119 @@ struct -- !query 2 +WITH RECURSIVE t AS ( + VALUES (1) AS T(n) + UNION ALL + SELECT n + 1 FROM t WHERE n < 100 +) +SELECT SUM(n) FROM t +-- !query 2 schema +struct +-- !query 2 output +5050 + + +-- !query 3 +WITH RECURSIVE t AS ( + SELECT (VALUES(1)) AS n + UNION ALL + SELECT n + 1 FROM t WHERE n < 5 +) +SELECT * FROM t +-- !query 3 schema +struct +-- !query 3 output +1 +2 +3 +4 +5 + + +-- !query 4 +WITH RECURSIVE t AS ( + SELECT 'foo' AS n + UNION ALL + SELECT n || ' bar' FROM t WHERE LENGTH(n) < 20 +) +SELECT n FROM t +-- !query 4 schema +struct +-- !query 4 output +foo +foo bar +foo bar bar +foo bar bar bar +foo bar bar bar bar +foo bar bar bar bar bar + + +-- !query 5 +CREATE TEMPORARY VIEW sums_1_100 AS +WITH RECURSIVE t AS ( + VALUES (1) AS T(n) + UNION ALL + SELECT n + 1 FROM t WHERE n < 100 +) +SELECT SUM(n) FROM t +-- !query 5 schema +struct<> +-- !query 5 output + + + +-- !query 6 +SELECT * FROM sums_1_100 +-- !query 6 schema +struct +-- !query 6 output +5050 + + +-- !query 7 +WITH RECURSIVE t AS ( + VALUES (1, 2) AS T(i, j) + UNION ALL + SELECT t2.i, t.j + 1 + FROM ( + SELECT 2 AS i + UNION ALL SELECT 3 AS i + ) AS t2 + JOIN t ON (t2.i = t.i + 1) +) +SELECT * FROM t +-- !query 7 schema +struct +-- !query 7 output +1 2 +2 3 +3 4 + + +-- !query 8 WITH RECURSIVE r AS ( VALUES (0, 'A') AS T(level, data) UNION ALL SELECT level + 1, data FROM r ) SELECT * FROM r ORDER BY level --- !query 2 schema +-- !query 8 schema struct<> --- !query 2 output +-- !query 8 output org.apache.spark.SparkException Recursion level limit reached but query hasn't exhausted, try increasing spark.sql.cte.recursion.level.limit --- !query 3 +-- !query 9 WITH RECURSIVE r AS ( SELECT level + 1, data FROM r WHERE level < 10 UNION ALL VALUES (0, 'A') AS T(level, data) ) SELECT * FROM r ORDER BY level --- !query 3 schema +-- !query 9 schema struct --- !query 3 output +-- !query 9 output 0 A 1 A 2 A @@ -76,7 +166,7 @@ struct 10 A --- !query 4 +-- !query 10 WITH RECURSIVE r AS ( VALUES (0, 'A') AS T(level, data) UNION ALL @@ -85,9 +175,9 @@ WITH RECURSIVE r AS ( VALUES (0, 'B') AS T(level, data) ) SELECT * FROM r ORDER BY level --- !query 4 schema +-- !query 10 schema struct --- !query 4 output +-- !query 10 output 0 A 0 B 1 A @@ -98,7 +188,7 @@ struct 3 B --- !query 5 +-- !query 11 WITH RECURSIVE r AS ( VALUES (0, 'A') AS T(level, data) UNION ALL @@ -107,9 +197,9 @@ WITH RECURSIVE r AS ( SELECT level + 1, data FROM r WHERE level < 3 ) SELECT * FROM r ORDER BY level --- !query 5 schema +-- !query 11 schema struct --- !query 5 output +-- !query 11 output 0 A 1 A 1 A @@ -127,7 +217,7 @@ struct 3 A --- !query 6 +-- !query 12 WITH RECURSIVE r AS ( VALUES (0, 'A') AS T(level, data) UNION ALL @@ -138,9 +228,9 @@ WITH RECURSIVE r AS ( SELECT level + 1, data FROM r WHERE level < 3 ) SELECT * FROM r ORDER BY level --- !query 6 schema +-- !query 12 schema struct --- !query 6 output +-- !query 12 output 0 A 0 B 1 A @@ -173,49 +263,49 @@ struct 3 B --- !query 7 +-- !query 13 WITH RECURSIVE r AS ( VALUES (0, 'A') AS T(level, data) INTERSECT SELECT level + 1, data FROM r WHERE level < 10 ) SELECT * FROM r --- !query 7 schema +-- !query 13 schema struct<> --- !query 7 output +-- !query 13 output org.apache.spark.sql.AnalysisException -Recursive query r should contain UNION ALL statements only; +Recursive query r should contain UNION ALL statements only. This can also be caused by ORDER BY or LIMIT keywords used on result of UNION ALL.; --- !query 8 +-- !query 14 WITH RECURSIVE r AS ( SELECT level + 1, data FROM r WHERE level < 3 UNION ALL SELECT level + 1, data FROM r WHERE level < 3 ) SELECT * FROM r --- !query 8 schema +-- !query 14 schema struct<> --- !query 8 output +-- !query 14 output org.apache.spark.sql.AnalysisException There should be at least 1 anchor term defined in the recursive query r; --- !query 9 +-- !query 15 WITH RECURSIVE r AS ( VALUES (0, 'A') AS T(level, data) UNION ALL SELECT level + 1, data FROM r WHERE (SELECT SUM(level) FROM r) < 10 ) SELECT * FROM r --- !query 9 schema +-- !query 15 schema struct<> --- !query 9 output +-- !query 15 output org.apache.spark.sql.AnalysisException -Recursive reference r can't be used in a subquery; +Recursive reference r cannot be used here. This can be caused by using it in a different join than inner or left outer or right outer, using it on inner side of an outer join, using it with aggregate or distinct, using it in a subquery or using it multiple times in a recursive term.; --- !query 10 +-- !query 16 WITH RECURSIVE r AS ( VALUES (0, 'A') AS T(level, data) UNION ALL @@ -224,14 +314,14 @@ WITH RECURSIVE r AS ( JOIN r AS r2 ON r2.data = r1.data ) SELECT * FROM r --- !query 10 schema +-- !query 16 schema struct<> --- !query 10 output +-- !query 16 output org.apache.spark.sql.AnalysisException -Recursive reference r cannot be used on both sides of an inner join; +Recursive reference r cannot be used multiple times in a recursive term; --- !query 11 +-- !query 17 WITH RECURSIVE r AS ( VALUES (0, 'A') AS T(level, data) UNION ALL @@ -240,14 +330,14 @@ WITH RECURSIVE r AS ( LEFT JOIN r ON r.data = o.data ) SELECT * FROM r --- !query 11 schema +-- !query 17 schema struct<> --- !query 11 output +-- !query 17 output org.apache.spark.sql.AnalysisException -Recursive reference r cannot be used here. This can be caused by using it in a different join than inner or left outer or right outer, using it on inner side of an outer join or using it in an aggregate or with a distinct statement; +Recursive reference r cannot be used here. This can be caused by using it in a different join than inner or left outer or right outer, using it on inner side of an outer join, using it with aggregate or distinct, using it in a subquery or using it multiple times in a recursive term.; --- !query 12 +-- !query 18 WITH RECURSIVE r AS ( VALUES (0, 'A') AS T(level, data) UNION ALL @@ -256,23 +346,23 @@ WITH RECURSIVE r AS ( RIGHT JOIN (SELECT 'B' AS data) AS o ON o.data = r.data ) SELECT * FROM r --- !query 12 schema +-- !query 18 schema struct<> --- !query 12 output +-- !query 18 output org.apache.spark.sql.AnalysisException -Recursive reference r cannot be used here. This can be caused by using it in a different join than inner or left outer or right outer, using it on inner side of an outer join or using it in an aggregate or with a distinct statement; +Recursive reference r cannot be used here. This can be caused by using it in a different join than inner or left outer or right outer, using it on inner side of an outer join, using it with aggregate or distinct, using it in a subquery or using it multiple times in a recursive term.; --- !query 13 +-- !query 19 WITH RECURSIVE r AS ( SELECT MAX(level) AS level, SUM(data) AS data FROM VALUES (0, 1), (0, 2) AS T(level, data) UNION ALL SELECT level + 1, data FROM r WHERE level < 10 ) SELECT * FROM r ORDER BY level --- !query 13 schema +-- !query 19 schema struct --- !query 13 output +-- !query 19 output 0 3 1 3 2 3 @@ -286,114 +376,585 @@ struct 10 3 --- !query 14 +-- !query 20 WITH RECURSIVE r AS ( VALUES (0, 1L) AS T(group, data) UNION ALL SELECT 1, SUM(data) FROM r WHERE data < 10 GROUP BY group ) SELECT * FROM r --- !query 14 schema +-- !query 20 schema struct<> --- !query 14 output +-- !query 20 output org.apache.spark.sql.AnalysisException -Recursive reference r cannot be used here. This can be caused by using it in a different join than inner or left outer or right outer, using it on inner side of an outer join or using it in an aggregate or with a distinct statement; +Recursive reference r cannot be used here. This can be caused by using it in a different join than inner or left outer or right outer, using it on inner side of an outer join, using it with aggregate or distinct, using it in a subquery or using it multiple times in a recursive term.; --- !query 15 +-- !query 21 WITH RECURSIVE r AS ( VALUES (1L) AS T(data) UNION ALL SELECT SUM(data) FROM r WHERE data < 10 ) SELECT * FROM r --- !query 15 schema +-- !query 21 schema struct<> --- !query 15 output +-- !query 21 output org.apache.spark.sql.AnalysisException Recursive reference r can't be used in an aggregate; --- !query 16 +-- !query 22 WITH RECURSIVE r AS ( VALUES (0, 'A') AS T(level, data) UNION ALL SELECT level + 1, data FROM r WHERE level < 10 ) SELECT COUNT(*) FROM r --- !query 16 schema +-- !query 22 schema struct --- !query 16 output +-- !query 22 output 11 --- !query 17 +-- !query 23 WITH RECURSIVE r AS ( VALUES (0, 'A') AS T(level, data) UNION ALL SELECT DISTINCT level + 1, data FROM r WHERE level < 10 ) SELECT * FROM r --- !query 17 schema +-- !query 23 schema struct<> --- !query 17 output +-- !query 23 output org.apache.spark.sql.AnalysisException -Recursive reference r cannot be used here. This can be caused by using it in a different join than inner or left outer or right outer, using it on inner side of an outer join or using it in an aggregate or with a distinct statement; +Recursive reference r cannot be used here. This can be caused by using it in a different join than inner or left outer or right outer, using it on inner side of an outer join, using it with aggregate or distinct, using it in a subquery or using it multiple times in a recursive term.; --- !query 18 +-- !query 24 CREATE TEMPORARY VIEW department AS SELECT * FROM VALUES - (0, null, "ROOT"), - (1, 0, "A"), - (2, 1, "B"), - (3, 2, "C"), - (4, 2, "D"), - (5, 0, "E"), - (6, 4, "F"), - (7, 5, "G") - AS department(id, parent_department_id, name) --- !query 18 schema + (0, null, 'ROOT'), + (1, 0, 'A'), + (2, 1, 'B'), + (3, 2, 'C'), + (4, 2, 'D'), + (5, 0, 'E'), + (6, 4, 'F'), + (7, 5, 'G') + AS department(id, parent_department, name) +-- !query 24 schema struct<> --- !query 18 output +-- !query 24 output --- !query 19 +-- !query 25 +WITH RECURSIVE subdepartment AS ( + SELECT name as root_name, * FROM department WHERE name = 'A' + UNION ALL + SELECT sd.root_name, d.* + FROM department AS d, subdepartment AS sd + WHERE d.parent_department = sd.id +) +SELECT * FROM subdepartment ORDER BY name +-- !query 25 schema +struct +-- !query 25 output +A 1 0 A +A 2 1 B +A 3 2 C +A 4 2 D +A 6 4 F + + +-- !query 26 +WITH RECURSIVE subdepartment AS ( + SELECT 1 as level, id, parent_department, name FROM department WHERE name = 'A' + UNION ALL + SELECT sd.level + 1, d.* + FROM department AS d, subdepartment AS sd + WHERE d.parent_department = sd.id +) +SELECT * FROM subdepartment ORDER BY name +-- !query 26 schema +struct +-- !query 26 output +1 1 0 A +2 2 1 B +3 3 2 C +3 4 2 D +4 6 4 F + + +-- !query 27 +WITH RECURSIVE subdepartment AS ( + SELECT 1 as level, id, parent_department, name FROM department WHERE name = 'A' + UNION ALL + SELECT sd.level + 1, d.* + FROM department AS d, subdepartment AS sd + WHERE d.parent_department = sd.id +) +SELECT * FROM subdepartment WHERE level >= 2 ORDER BY name +-- !query 27 schema +struct +-- !query 27 output +2 2 1 B +3 3 2 C +3 4 2 D +4 6 4 F + + +-- !query 28 WITH RECURSIVE subdepartment AS ( SELECT * FROM department WHERE name = 'A' UNION ALL SELECT d.* FROM department AS d - JOIN subdepartment AS sd ON (sd.id = d.parent_department_id) + JOIN subdepartment AS sd ON (sd.parent_department = d.id) ) SELECT id, name FROM subdepartment ORDER BY name --- !query 19 schema +-- !query 28 schema struct --- !query 19 output +-- !query 28 output 1 A -2 B -3 C -4 D -6 F +0 ROOT --- !query 20 +-- !query 29 WITH RECURSIVE subdepartment AS ( SELECT * FROM department WHERE name = 'A' +) +SELECT * FROM subdepartment ORDER BY name +-- !query 29 schema +struct +-- !query 29 output +1 0 A + + +-- !query 30 +CREATE TEMPORARY VIEW vsubdepartment AS + WITH RECURSIVE subdepartment AS ( + SELECT * FROM department WHERE name = 'A' + UNION ALL + SELECT d.* + FROM department AS d, subdepartment AS sd + WHERE d.parent_department = sd.id + ) + SELECT * FROM subdepartment +-- !query 30 schema +struct<> +-- !query 30 output + + + +-- !query 31 +SELECT * FROM vsubdepartment ORDER BY name +-- !query 31 schema +struct +-- !query 31 output +1 0 A +2 1 B +3 2 C +4 2 D +6 4 F + + +-- !query 32 +CREATE TEMPORARY VIEW tree AS SELECT * FROM VALUES + (1, NULL), + (2, 1), + (3, 1), + (4, 2), + (5, 2), + (6, 2), + (7, 3), + (8, 3), + (9, 4), + (10, 4), + (11, 7), + (12, 7), + (13, 7), + (14, 9), + (15, 11), + (16, 11) +AS (id, parent_id) +-- !query 32 schema +struct<> +-- !query 32 output + + + +-- !query 33 +WITH RECURSIVE t AS ( + VALUES(1, ARRAY_REMOVE(ARRAY(0), 0)) AS T(id, path) UNION ALL - SELECT d.* - FROM department AS d - JOIN subdepartment AS sd ON (sd.parent_department_id = d.id) + SELECT tree.id, t.path || ARRAY(tree.id) + FROM tree + JOIN t ON tree.parent_id = t.id ) -SELECT id, name FROM subdepartment ORDER BY name --- !query 20 schema -struct --- !query 20 output -1 A -0 ROOT +SELECT t1.*, t2.* +FROM t AS t1 +JOIN t AS t2 ON t1.path[0] = t2.path[0] AND SIZE(t1.path) = 1 AND SIZE(t2.path) > 1 +ORDER BY t1.id, t2.id +-- !query 33 schema +struct,id:int,path:array> +-- !query 33 output +2 [2] 4 [2,4] +2 [2] 5 [2,5] +2 [2] 6 [2,6] +2 [2] 9 [2,4,9] +2 [2] 10 [2,4,10] +2 [2] 14 [2,4,9,14] +3 [3] 7 [3,7] +3 [3] 8 [3,8] +3 [3] 11 [3,7,11] +3 [3] 12 [3,7,12] +3 [3] 13 [3,7,13] +3 [3] 15 [3,7,11,15] +3 [3] 16 [3,7,11,16] --- !query 21 +-- !query 34 +WITH RECURSIVE t AS ( + VALUES(1, ARRAY_REMOVE(ARRAY(0), 0)) AS T(id, path) + UNION ALL + SELECT tree.id, t.path || ARRAY(tree.id) + FROM tree + JOIN t ON tree.parent_id = t.id +) +SELECT t1.id, COUNT(t2.*) +FROM t AS t1 +JOIN t AS t2 ON t1.path[0] = t2.path[0] AND SIZE(t1.path) = 1 AND SIZE(t2.path) > 1 +GROUP BY t1.id +ORDER BY t1.id +-- !query 34 schema +struct +-- !query 34 output +2 6 +3 7 + + +-- !query 35 +WITH RECURSIVE t AS ( + VALUES(1, ARRAY_REMOVE(ARRAY(0), 0)) AS T(id, path) + UNION ALL + SELECT tree.id, t.path || ARRAY(tree.id) + FROM tree + JOIN t ON tree.parent_id = t.id +) +SELECT t1.id, t2.path, STRUCT(t2.*) +FROM t AS t1 +JOIN t AS t2 ON t1.id = t2.id +-- !query 35 schema +struct,named_struct(id, id, path, path):struct>> +-- !query 35 output +1 [] {"id":1,"path":[]} +10 [2,4,10] {"id":10,"path":[2,4,10]} +11 [3,7,11] {"id":11,"path":[3,7,11]} +12 [3,7,12] {"id":12,"path":[3,7,12]} +13 [3,7,13] {"id":13,"path":[3,7,13]} +14 [2,4,9,14] {"id":14,"path":[2,4,9,14]} +15 [3,7,11,15] {"id":15,"path":[3,7,11,15]} +16 [3,7,11,16] {"id":16,"path":[3,7,11,16]} +2 [2] {"id":2,"path":[2]} +3 [3] {"id":3,"path":[3]} +4 [2,4] {"id":4,"path":[2,4]} +5 [2,5] {"id":5,"path":[2,5]} +6 [2,6] {"id":6,"path":[2,6]} +7 [3,7] {"id":7,"path":[3,7]} +8 [3,8] {"id":8,"path":[3,8]} +9 [2,4,9] {"id":9,"path":[2,4,9]} + + +-- !query 36 +CREATE TEMPORARY VIEW graph AS SELECT * FROM VALUES + (1, 2, 'arc 1 -> 2'), + (1, 3, 'arc 1 -> 3'), + (2, 3, 'arc 2 -> 3'), + (1, 4, 'arc 1 -> 4'), + (4, 5, 'arc 4 -> 5'), + (5, 1, 'arc 5 -> 1') +AS (f, t, label) +-- !query 36 schema +struct<> +-- !query 36 output + + + +-- !query 37 +WITH RECURSIVE search_graph AS ( + SELECT *, ARRAY(STRUCT(g.f, g.t)) AS path, false AS cycle FROM graph g + UNION ALL + SELECT g.*, path || ARRAY(STRUCT(g.f, g.t)), ARRAY_CONTAINS(path, STRUCT(g.f, g.t)) + FROM graph g, search_graph sg + WHERE g.f = sg.t AND NOT cycle +) +SELECT * FROM search_graph +-- !query 37 schema +struct>,cycle:boolean> +-- !query 37 output +1 2 arc 1 -> 2 [{"f":1,"t":2}] false +1 2 arc 1 -> 2 [{"f":1,"t":4},{"f":4,"t":5},{"f":5,"t":1},{"f":1,"t":2}] false +1 2 arc 1 -> 2 [{"f":4,"t":5},{"f":5,"t":1},{"f":1,"t":2}] false +1 2 arc 1 -> 2 [{"f":5,"t":1},{"f":1,"t":2}] false +1 3 arc 1 -> 3 [{"f":1,"t":3}] false +1 3 arc 1 -> 3 [{"f":1,"t":4},{"f":4,"t":5},{"f":5,"t":1},{"f":1,"t":3}] false +1 3 arc 1 -> 3 [{"f":4,"t":5},{"f":5,"t":1},{"f":1,"t":3}] false +1 3 arc 1 -> 3 [{"f":5,"t":1},{"f":1,"t":3}] false +1 4 arc 1 -> 4 [{"f":1,"t":4},{"f":4,"t":5},{"f":5,"t":1},{"f":1,"t":4}] true +1 4 arc 1 -> 4 [{"f":1,"t":4}] false +1 4 arc 1 -> 4 [{"f":4,"t":5},{"f":5,"t":1},{"f":1,"t":4}] false +1 4 arc 1 -> 4 [{"f":5,"t":1},{"f":1,"t":4}] false +2 3 arc 2 -> 3 [{"f":1,"t":2},{"f":2,"t":3}] false +2 3 arc 2 -> 3 [{"f":1,"t":4},{"f":4,"t":5},{"f":5,"t":1},{"f":1,"t":2},{"f":2,"t":3}] false +2 3 arc 2 -> 3 [{"f":2,"t":3}] false +2 3 arc 2 -> 3 [{"f":4,"t":5},{"f":5,"t":1},{"f":1,"t":2},{"f":2,"t":3}] false +2 3 arc 2 -> 3 [{"f":5,"t":1},{"f":1,"t":2},{"f":2,"t":3}] false +4 5 arc 4 -> 5 [{"f":1,"t":4},{"f":4,"t":5}] false +4 5 arc 4 -> 5 [{"f":4,"t":5},{"f":5,"t":1},{"f":1,"t":4},{"f":4,"t":5}] true +4 5 arc 4 -> 5 [{"f":4,"t":5}] false +4 5 arc 4 -> 5 [{"f":5,"t":1},{"f":1,"t":4},{"f":4,"t":5}] false +5 1 arc 5 -> 1 [{"f":1,"t":4},{"f":4,"t":5},{"f":5,"t":1}] false +5 1 arc 5 -> 1 [{"f":4,"t":5},{"f":5,"t":1}] false +5 1 arc 5 -> 1 [{"f":5,"t":1},{"f":1,"t":4},{"f":4,"t":5},{"f":5,"t":1}] true +5 1 arc 5 -> 1 [{"f":5,"t":1}] false + + +-- !query 38 +WITH RECURSIVE search_graph AS ( + SELECT *, ARRAY(STRUCT(g.f, g.t)) AS path, false AS cycle FROM graph g + UNION ALL + SELECT g.*, path || ARRAY(STRUCT(g.f, g.t)), ARRAY_CONTAINS(path, STRUCT(g.f, g.t)) + FROM graph g, search_graph sg + WHERE g.f = sg.t AND NOT cycle +) +SELECT * FROM search_graph ORDER BY path +-- !query 38 schema +struct>,cycle:boolean> +-- !query 38 output +1 2 arc 1 -> 2 [{"f":1,"t":2}] false +2 3 arc 2 -> 3 [{"f":1,"t":2},{"f":2,"t":3}] false +1 3 arc 1 -> 3 [{"f":1,"t":3}] false +1 4 arc 1 -> 4 [{"f":1,"t":4}] false +4 5 arc 4 -> 5 [{"f":1,"t":4},{"f":4,"t":5}] false +5 1 arc 5 -> 1 [{"f":1,"t":4},{"f":4,"t":5},{"f":5,"t":1}] false +1 2 arc 1 -> 2 [{"f":1,"t":4},{"f":4,"t":5},{"f":5,"t":1},{"f":1,"t":2}] false +2 3 arc 2 -> 3 [{"f":1,"t":4},{"f":4,"t":5},{"f":5,"t":1},{"f":1,"t":2},{"f":2,"t":3}] false +1 3 arc 1 -> 3 [{"f":1,"t":4},{"f":4,"t":5},{"f":5,"t":1},{"f":1,"t":3}] false +1 4 arc 1 -> 4 [{"f":1,"t":4},{"f":4,"t":5},{"f":5,"t":1},{"f":1,"t":4}] true +2 3 arc 2 -> 3 [{"f":2,"t":3}] false +4 5 arc 4 -> 5 [{"f":4,"t":5}] false +5 1 arc 5 -> 1 [{"f":4,"t":5},{"f":5,"t":1}] false +1 2 arc 1 -> 2 [{"f":4,"t":5},{"f":5,"t":1},{"f":1,"t":2}] false +2 3 arc 2 -> 3 [{"f":4,"t":5},{"f":5,"t":1},{"f":1,"t":2},{"f":2,"t":3}] false +1 3 arc 1 -> 3 [{"f":4,"t":5},{"f":5,"t":1},{"f":1,"t":3}] false +1 4 arc 1 -> 4 [{"f":4,"t":5},{"f":5,"t":1},{"f":1,"t":4}] false +4 5 arc 4 -> 5 [{"f":4,"t":5},{"f":5,"t":1},{"f":1,"t":4},{"f":4,"t":5}] true +5 1 arc 5 -> 1 [{"f":5,"t":1}] false +1 2 arc 1 -> 2 [{"f":5,"t":1},{"f":1,"t":2}] false +2 3 arc 2 -> 3 [{"f":5,"t":1},{"f":1,"t":2},{"f":2,"t":3}] false +1 3 arc 1 -> 3 [{"f":5,"t":1},{"f":1,"t":3}] false +1 4 arc 1 -> 4 [{"f":5,"t":1},{"f":1,"t":4}] false +4 5 arc 4 -> 5 [{"f":5,"t":1},{"f":1,"t":4},{"f":4,"t":5}] false +5 1 arc 5 -> 1 [{"f":5,"t":1},{"f":1,"t":4},{"f":4,"t":5},{"f":5,"t":1}] true + + +-- !query 39 +WITH RECURSIVE y AS ( + VALUES (1) AS T(id) +), +x AS ( + SELECT * FROM y + UNION ALL + SELECT id + 1 FROM x WHERE id < 5 +) +SELECT * FROM x +-- !query 39 schema +struct +-- !query 39 output +1 +2 +3 +4 +5 + + +-- !query 40 +WITH RECURSIVE x AS ( + VALUES (1) AS T(id) + UNION ALL + SELECT id + 1 FROM x WHERE id < 5 +), +y AS ( + VALUES (1) AS T(id) + UNION ALL + SELECT id + 1 FROM y WHERE id < 10 +) +SELECT * FROM y LEFT JOIN x ON x.id = y.id +-- !query 40 schema +struct +-- !query 40 output +1 1 +10 NULL +2 2 +3 3 +4 4 +5 5 +6 NULL +7 NULL +8 NULL +9 NULL + + +-- !query 41 +WITH RECURSIVE x AS ( + VALUES (1) AS T(id) + UNION ALL + SELECT id + 1 FROM x WHERE id < 5 +), +y AS ( + VALUES (1) AS T(id) + UNION ALL + SELECT id + 1 FROM x WHERE id < 10 +) +SELECT * FROM y LEFT JOIN x ON x.id = y.id +-- !query 41 schema +struct +-- !query 41 output +1 1 +2 2 +3 3 +4 4 +5 5 +6 NULL + + +-- !query 42 +WITH RECURSIVE x AS ( + SELECT 1 AS id + UNION ALL + SELECT id + 1 FROM x WHERE id < 3 +), +y AS ( + SELECT * FROM x + UNION ALL + SELECT * FROM x +), +z AS ( + SELECT * FROM x + UNION ALL + SELECT id + 1 FROM z WHERE id < 10 +) +SELECT * FROM z +-- !query 42 schema +struct +-- !query 42 output +1 +10 +10 +10 +2 +2 +3 +3 +3 +4 +4 +4 +5 +5 +5 +6 +6 +6 +7 +7 +7 +8 +8 +8 +9 +9 +9 + + +-- !query 43 +WITH RECURSIVE x AS ( + SELECT 1 AS id + UNION ALL + SELECT id + 1 FROM x WHERE id < 3 +), +y AS ( + SELECT * FROM x + UNION ALL + SELECT * FROM x +), +z AS ( + SELECT * FROM y + UNION ALL + SELECT id + 1 FROM z WHERE id < 10 +) +SELECT * FROM z +-- !query 43 schema +struct +-- !query 43 output +1 +1 +10 +10 +10 +10 +10 +10 +2 +2 +2 +2 +3 +3 +3 +3 +3 +3 +4 +4 +4 +4 +4 +4 +5 +5 +5 +5 +5 +5 +6 +6 +6 +6 +6 +6 +7 +7 +7 +7 +7 +7 +8 +8 +8 +8 +8 +8 +9 +9 +9 +9 +9 +9 + + +-- !query 44 CREATE TEMPORARY VIEW routes AS SELECT * FROM VALUES ('New York', 'Washington'), ('New York', 'Boston'), @@ -401,13 +962,13 @@ CREATE TEMPORARY VIEW routes AS SELECT * FROM VALUES ('Washington', 'Boston'), ('Washington', 'Raleigh') AS routes(origin, destination) --- !query 21 schema +-- !query 44 schema struct<> --- !query 21 output +-- !query 44 output --- !query 22 +-- !query 45 WITH RECURSIVE destinations_from_new_york AS ( SELECT 'New York' AS destination, ARRAY('New York') AS path, 0 AS length UNION ALL @@ -416,9 +977,9 @@ WITH RECURSIVE destinations_from_new_york AS ( JOIN destinations_from_new_york AS d ON d.destination = r.origin AND NOT ARRAY_CONTAINS(d.path, r.destination) ) SELECT * FROM destinations_from_new_york --- !query 22 schema +-- !query 45 schema struct,length:int> --- !query 22 output +-- !query 45 output Boston ["New York","Boston"] 1 Boston ["New York","Washington","Boston"] 2 New York ["New York"] 0 @@ -426,16 +987,16 @@ Raleigh ["New York","Washington","Raleigh"] 2 Washington ["New York","Washington"] 1 --- !query 23 +-- !query 46 WITH RECURSIVE fibonacci AS ( VALUES (0, 1) AS T(a, b) UNION ALL SELECT b, a + b FROM fibonacci WHERE a < 10 ) SELECT a FROM fibonacci ORDER BY a --- !query 23 schema +-- !query 46 schema struct --- !query 23 output +-- !query 46 output 0 1 1 @@ -446,7 +1007,7 @@ struct 13 --- !query 24 +-- !query 47 WITH RECURSIVE sudoku AS ( VALUES ( ARRAY( @@ -501,7 +1062,448 @@ WITH RECURSIVE sudoku AS ( ) ) SELECT * FROM sudoku WHERE NOT ARRAY_CONTAINS(puzzle, 0) --- !query 24 schema +-- !query 47 schema struct,level:int> --- !query 24 output +-- !query 47 output [4,8,6,9,2,3,7,5,1,5,1,3,7,6,8,9,4,2,7,9,2,5,1,4,8,3,6,2,7,4,8,5,6,1,9,3,9,6,1,3,4,7,2,8,5,8,3,5,2,9,1,4,6,7,6,2,8,1,3,9,5,7,4,3,5,7,4,8,2,6,1,9,1,4,9,6,7,5,3,2,8] 55 + + +-- !query 48 +WITH RECURSIVE x AS ( + SELECT 1 AS n + INTERSECT + SELECT n + 1 FROM x +) +SELECT * FROM x +-- !query 48 schema +struct<> +-- !query 48 output +org.apache.spark.sql.AnalysisException +Recursive query x should contain UNION ALL statements only. This can also be caused by ORDER BY or LIMIT keywords used on result of UNION ALL.; + + +-- !query 49 +WITH RECURSIVE x AS ( + SELECT 1 AS n + INTERSECT ALL + SELECT n + 1 FROM x +) +SELECT * FROM x +-- !query 49 schema +struct<> +-- !query 49 output +org.apache.spark.sql.AnalysisException +Recursive query x should contain UNION ALL statements only. This can also be caused by ORDER BY or LIMIT keywords used on result of UNION ALL.; + + +-- !query 50 +WITH RECURSIVE x AS ( + SELECT 1 AS n + EXCEPT + SELECT n + 1 FROM x +) +SELECT * FROM x +-- !query 50 schema +struct<> +-- !query 50 output +org.apache.spark.sql.AnalysisException +Recursive query x should contain UNION ALL statements only. This can also be caused by ORDER BY or LIMIT keywords used on result of UNION ALL.; + + +-- !query 51 +WITH RECURSIVE x AS ( + SELECT 1 AS n + EXCEPT ALL + SELECT n + 1 FROM x +) +SELECT * FROM x +-- !query 51 schema +struct<> +-- !query 51 output +org.apache.spark.sql.AnalysisException +Recursive query x should contain UNION ALL statements only. This can also be caused by ORDER BY or LIMIT keywords used on result of UNION ALL.; + + +-- !query 52 +WITH RECURSIVE x AS ( + SELECT n FROM x +) +SELECT * FROM x +-- !query 52 schema +struct<> +-- !query 52 output +org.apache.spark.sql.AnalysisException +Recursive query x should contain UNION ALL statements only. This can also be caused by ORDER BY or LIMIT keywords used on result of UNION ALL.; + + +-- !query 53 +WITH RECURSIVE t AS ( + INSERT INTO y SELECT * FROM t +) +VALUES(FALSE) +-- !query 53 schema +struct<> +-- !query 53 output +org.apache.spark.sql.AnalysisException +Recursive query t should contain UNION ALL statements only. This can also be caused by ORDER BY or LIMIT keywords used on result of UNION ALL.; + + +-- !query 54 +CREATE TEMPORARY VIEW y AS SELECT EXPLODE(SEQUENCE(1, 10)) AS a +-- !query 54 schema +struct<> +-- !query 54 output + + + +-- !query 55 +WITH RECURSIVE x AS ( + SELECT a AS n FROM y WHERE a = 1 + UNION ALL + SELECT x.n + 1 FROM y LEFT JOIN x ON x.n = y.a WHERE n < 10 +) +SELECT * FROM x +-- !query 55 schema +struct<> +-- !query 55 output +org.apache.spark.sql.AnalysisException +Recursive reference x cannot be used here. This can be caused by using it in a different join than inner or left outer or right outer, using it on inner side of an outer join, using it with aggregate or distinct, using it in a subquery or using it multiple times in a recursive term.; + + +-- !query 56 +WITH RECURSIVE x AS ( + SELECT a AS n FROM y WHERE a = 1 + UNION ALL + SELECT x.n + 1 FROM x RIGHT JOIN y ON x.n = y.a WHERE n < 10 +) +SELECT * FROM x +-- !query 56 schema +struct<> +-- !query 56 output +org.apache.spark.sql.AnalysisException +Recursive reference x cannot be used here. This can be caused by using it in a different join than inner or left outer or right outer, using it on inner side of an outer join, using it with aggregate or distinct, using it in a subquery or using it multiple times in a recursive term.; + + +-- !query 57 +WITH RECURSIVE x AS ( + SELECT a AS n FROM y WHERE a = 1 + UNION ALL + SELECT x.n + 1 FROM x FULL JOIN y ON x.n = y.a WHERE n < 10 +) SELECT * FROM x +-- !query 57 schema +struct<> +-- !query 57 output +org.apache.spark.sql.AnalysisException +Recursive reference x cannot be used here. This can be caused by using it in a different join than inner or left outer or right outer, using it on inner side of an outer join, using it with aggregate or distinct, using it in a subquery or using it multiple times in a recursive term.; + + +-- !query 58 +WITH RECURSIVE x AS ( + SELECT 1 AS n + UNION ALL + SELECT n + 1 + FROM x + WHERE n IN (SELECT * FROM x) +) +SELECT * FROM x +-- !query 58 schema +struct<> +-- !query 58 output +org.apache.spark.sql.AnalysisException +Recursive reference x cannot be used here. This can be caused by using it in a different join than inner or left outer or right outer, using it on inner side of an outer join, using it with aggregate or distinct, using it in a subquery or using it multiple times in a recursive term.; + + +-- !query 59 +WITH RECURSIVE x AS ( + SELECT 1 AS n + UNION ALL + SELECT COUNT(*) FROM x +) +SELECT * FROM x +-- !query 59 schema +struct<> +-- !query 59 output +org.apache.spark.sql.AnalysisException +Recursive reference x cannot be used here. This can be caused by using it in a different join than inner or left outer or right outer, using it on inner side of an outer join, using it with aggregate or distinct, using it in a subquery or using it multiple times in a recursive term.; + + +-- !query 60 +WITH RECURSIVE x AS ( + SELECT 1 AS n + UNION ALL + SELECT SUM(n) FROM x +) +SELECT * FROM x +-- !query 60 schema +struct<> +-- !query 60 output +org.apache.spark.sql.AnalysisException +Recursive reference x can't be used in an aggregate; + + +-- !query 61 +WITH RECURSIVE x AS ( + SELECT 1 AS n + UNION ALL + SELECT n + 1 FROM x + ORDER BY 1 +) +SELECT * FROM x +-- !query 61 schema +struct<> +-- !query 61 output +org.apache.spark.sql.AnalysisException +Recursive query x should contain UNION ALL statements only. This can also be caused by ORDER BY or LIMIT keywords used on result of UNION ALL.; + + +-- !query 62 +WITH RECURSIVE x AS ( + SELECT 1 AS n + UNION ALL + SELECT n + 1 FROM x + LIMIT 10 +) +SELECT * FROM x +-- !query 62 schema +struct<> +-- !query 62 output +org.apache.spark.sql.AnalysisException +Recursive query x should contain UNION ALL statements only. This can also be caused by ORDER BY or LIMIT keywords used on result of UNION ALL.; + + +-- !query 63 +WITH RECURSIVE x AS ( + VALUES (1) AS T(id) + UNION ALL + SELECT ( + SELECT * FROM x + ) + FROM x + WHERE id < 5 +) +SELECT * FROM x +-- !query 63 schema +struct<> +-- !query 63 output +org.apache.spark.sql.AnalysisException +Recursive reference x cannot be used here. This can be caused by using it in a different join than inner or left outer or right outer, using it on inner side of an outer join, using it with aggregate or distinct, using it in a subquery or using it multiple times in a recursive term.; + + +-- !query 64 +WITH RECURSIVE x AS ( + SELECT 1 AS id + UNION ALL + SELECT id + 1 FROM y WHERE id < 5 +), +y AS ( + SELECT 1 AS id + UNION ALL + SELECT id + 1 + FROM x + WHERE id < 5 +) +SELECT * FROM x +-- !query 64 schema +struct<> +-- !query 64 output +org.apache.spark.sql.AnalysisException +cannot resolve '`id`' given input columns: [y.a]; line 4 pos 29 + + +-- !query 65 +WITH RECURSIVE foo AS ( + VALUES (1) AS T(i) + UNION ALL + SELECT i + 1 FROM foo WHERE i < 10 + UNION ALL + SELECT i + 1 FROM foo WHERE i < 5 +) +SELECT i, COUNT(*) FROM foo GROUP BY i ORDER BY i +-- !query 65 schema +struct +-- !query 65 output +1 1 +2 2 +3 4 +4 8 +5 16 +6 16 +7 16 +8 16 +9 16 +10 16 + + +-- !query 66 +WITH RECURSIVE foo AS ( + VALUES (1) AS T(i) + UNION ALL + SELECT * FROM ( + SELECT i + 1 + FROM foo WHERE i < 10 + UNION ALL + SELECT i + 1 + FROM foo WHERE i < 5 + ) AS t +) +SELECT i, COUNT(*) FROM foo GROUP BY i ORDER BY i +-- !query 66 schema +struct<> +-- !query 66 output +org.apache.spark.sql.AnalysisException +Recursive reference foo cannot be used multiple times in a recursive term; + + +-- !query 67 +WITH RECURSIVE foo AS ( + VALUES (1) AS T(i) + UNION ALL ( + SELECT i + 1 FROM foo WHERE i < 10 + EXCEPT + SELECT i + 1 FROM foo WHERE i < 5 + ) +) +SELECT * FROM foo +-- !query 67 schema +struct<> +-- !query 67 output +org.apache.spark.sql.AnalysisException +Recursive reference foo cannot be used multiple times in a recursive term; + + +-- !query 68 +WITH RECURSIVE foo AS ( + VALUES (1) AS T(i) + UNION ALL ( + SELECT i + 1 FROM foo WHERE i < 10 + INTERSECT + SELECT i + 1 FROM foo WHERE i < 5 + ) +) +SELECT * FROM foo +-- !query 68 schema +struct<> +-- !query 68 output +org.apache.spark.sql.AnalysisException +Recursive reference foo cannot be used multiple times in a recursive term; + + +-- !query 69 +WITH RECURSIVE foo AS ( + VALUES (1), (2) AS T(i) + UNION ALL + SELECT CAST((i + 1) AS DECIMAL(10, 0)) FROM foo WHERE i < 10 +) +SELECT * FROM foo +-- !query 69 schema +struct<> +-- !query 69 output +org.apache.spark.sql.AnalysisException +Anchor term types List(IntegerType) and recursive term types List(DecimalType(10,0)) doesn't match; + + +-- !query 70 +WITH RECURSIVE foo AS ( + SELECT CAST(i AS DECIMAL(3, 0)) FROM (VALUES (1), (2)) AS T(i) + UNION ALL + SELECT CAST((i + 1) AS DECIMAL(10, 0)) FROM foo WHERE i < 10 +) +SELECT * FROM foo +-- !query 70 schema +struct<> +-- !query 70 output +org.apache.spark.sql.AnalysisException +Anchor term types List(DecimalType(3,0)) and recursive term types List(DecimalType(10,0)) doesn't match; + + +-- !query 71 +WITH RECURSIVE t AS ( + WITH RECURSIVE s AS ( + VALUES (1) AS T(i) + UNION ALL + SELECT i + 1 FROM s WHERE i < 10 + ) + SELECT i AS j FROM s + UNION ALL + SELECT j + 1 FROM t WHERE j < 10 +) +SELECT * FROM t +-- !query 71 schema +struct +-- !query 71 output +1 +10 +10 +10 +10 +10 +10 +10 +10 +10 +10 +2 +2 +3 +3 +3 +4 +4 +4 +4 +5 +5 +5 +5 +5 +6 +6 +6 +6 +6 +6 +7 +7 +7 +7 +7 +7 +7 +8 +8 +8 +8 +8 +8 +8 +8 +9 +9 +9 +9 +9 +9 +9 +9 +9 + + +-- !query 72 +WITH RECURSIVE outermost AS ( + WITH innermost AS ( + SELECT * FROM outermost + ) + SELECT level + 1 FROM innermost WHERE level < 5 + UNION ALL + SELECT 0 AS level +) +SELECT * FROM outermost +-- !query 72 schema +struct +-- !query 72 output +0 +1 +2 +3 +4 +5