-
Notifications
You must be signed in to change notification settings - Fork 29k
[SPARK-28228][SQL] Fix substitution order of nested WITH clauses #25029
New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
Changes from 1 commit
8288f02
4a913e8
e1f32bd
73824bf
45f0642
55a01ea
7d9d96f
File filter
Filter by extension
Conversations
Jump to
Diff view
Diff view
- Loading branch information
There are no files selected for viewing
| Original file line number | Diff line number | Diff line change |
|---|---|---|
| @@ -0,0 +1,123 @@ | ||
| /* | ||
| * Licensed to the Apache Software Foundation (ASF) under one or more | ||
| * contributor license agreements. See the NOTICE file distributed with | ||
| * this work for additional information regarding copyright ownership. | ||
| * The ASF licenses this file to You under the Apache License, Version 2.0 | ||
| * (the "License"); you may not use this file except in compliance with | ||
| * the License. You may obtain a copy of the License at | ||
| * | ||
| * http://www.apache.org/licenses/LICENSE-2.0 | ||
| * | ||
| * Unless required by applicable law or agreed to in writing, software | ||
| * distributed under the License is distributed on an "AS IS" BASIS, | ||
| * WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. | ||
| * See the License for the specific language governing permissions and | ||
| * limitations under the License. | ||
| */ | ||
|
|
||
| package org.apache.spark.sql.catalyst.analysis | ||
|
|
||
| import org.apache.spark.sql.catalyst.expressions.SubqueryExpression | ||
| import org.apache.spark.sql.catalyst.plans.logical.{LogicalPlan, With} | ||
| import org.apache.spark.sql.catalyst.rules.Rule | ||
| import org.apache.spark.sql.internal.SQLConf | ||
|
|
||
| /** | ||
| * Analyze WITH nodes and substitute child plan with CTE definitions. | ||
| */ | ||
| object CTESubstitution extends Rule[LogicalPlan] { | ||
| def apply(plan: LogicalPlan): LogicalPlan = if (SQLConf.get.legacyCTESubstitutionEnabled) { | ||
| legacyTraverseAndSubstituteCTE(plan) | ||
dongjoon-hyun marked this conversation as resolved.
Outdated
Show resolved
Hide resolved
|
||
| } else { | ||
| traverseAndSubstituteCTE(plan, false) | ||
| } | ||
|
|
||
| private def legacyTraverseAndSubstituteCTE(plan: LogicalPlan): LogicalPlan = { | ||
| plan.resolveOperatorsUp { | ||
| case With(child, relations) => | ||
| // substitute CTE expressions right-to-left to resolve references to previous CTEs: | ||
| // with a as (select * from t), b as (select * from a) select * from b | ||
| relations.foldRight(child) { | ||
| case ((cteName, ctePlan), currentPlan) => substituteCTE(currentPlan, cteName, ctePlan) | ||
| } | ||
| } | ||
| } | ||
|
|
||
| /** | ||
| * Traverse the plan and expression nodes as a tree and replace matching references to CTE | ||
| * definitions. | ||
| * - If the rule encounters a WITH node then it substitutes the child of the node with CTE | ||
| * definitions of the node right-to-left order as a definition can reference to a previous | ||
| * one. | ||
| * For example the following query is valid: | ||
| * WITH | ||
| * t AS (SELECT 1), | ||
| * t2 AS (SELECT * FROM t) | ||
| * SELECT * FROM t2 | ||
| * - If a CTE definition contains an inner WITH node then substitution of inner should take | ||
| * precedence because it can shadow an outer CTE definition. | ||
| * For example the following query should return 2: | ||
| * WITH | ||
| * t AS (SELECT 1), | ||
| * t2 AS ( | ||
| * WITH t AS (SELECT 2) | ||
| * SELECT * FROM t | ||
| * ) | ||
| * SELECT * FROM t2 | ||
| * - If a CTE definition contains a subquery that contains an inner WITH node then substitution | ||
| * of inner should take precedence because it can shadow an outer CTE definition. | ||
| * For example the following query should return 2: | ||
| * WITH t AS (SELECT 1 AS c) | ||
| * SELECT max(c) FROM ( | ||
| * WITH t AS (SELECT 2 AS c) | ||
| * SELECT * FROM t | ||
| * ) | ||
| * - If a CTE definition contains a subquery expression that contains an inner WITH node then | ||
| * substitution of inner should take precedence because it can shadow an outer CTE | ||
| * definition. | ||
| * For example the following query should return 2: | ||
| * WITH t AS (SELECT 1) | ||
| * SELECT ( | ||
| * WITH t AS (SELECT 2) | ||
| * SELECT * FROM t | ||
| * ) | ||
| * @param plan the plan to be traversed | ||
peter-toth marked this conversation as resolved.
Outdated
Show resolved
Hide resolved
|
||
| * @param inTraverse whether the current traverse is called from another traverse, only in this | ||
| * case name collision can occur | ||
| * @return then plan where CTE substitution is applied | ||
peter-toth marked this conversation as resolved.
Outdated
Show resolved
Hide resolved
|
||
| */ | ||
| private def traverseAndSubstituteCTE(plan: LogicalPlan, inTraverse: Boolean): LogicalPlan = { | ||
| plan.resolveOperatorsUp { | ||
| case With(child: LogicalPlan, relations) => | ||
| val traversedChild = child transformExpressions { | ||
| case e: SubqueryExpression => e.withNewPlan(traverseAndSubstituteCTE(e.plan, true)) | ||
|
Contributor
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. The subquery expression seems not correctly handled.
Contributor
Author
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. Yes, it probably should be
Member
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. Oh. Thanks, @cloud-fan .
Contributor
Author
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. I've opened #28318 to fix it. |
||
| } | ||
|
|
||
| relations.foldRight(traversedChild) { | ||
| case ((cteName, ctePlan), currentPlan) => | ||
| lazy val substitutedCTEPlan = traverseAndSubstituteCTE(ctePlan, true) | ||
dongjoon-hyun marked this conversation as resolved.
Show resolved
Hide resolved
|
||
| substituteCTE(currentPlan, cteName, substitutedCTEPlan) | ||
dongjoon-hyun marked this conversation as resolved.
Show resolved
Hide resolved
|
||
| } | ||
|
|
||
| case other if inTraverse => | ||
dongjoon-hyun marked this conversation as resolved.
Show resolved
Hide resolved
|
||
| other.transformExpressions { | ||
| case e: SubqueryExpression => e.withNewPlan(traverseAndSubstituteCTE(e.plan, true)) | ||
| } | ||
| } | ||
| } | ||
|
|
||
| // A CTE definition might not be used at all so ctePlan is call by name. | ||
| private def substituteCTE( | ||
| plan: LogicalPlan, | ||
| cteName: String, | ||
| ctePlan: => LogicalPlan): LogicalPlan = | ||
| plan resolveOperatorsUp { | ||
| case UnresolvedRelation(Seq(table)) if plan.conf.resolver(cteName, table) => ctePlan | ||
|
|
||
| case other => | ||
| // This cannot be done in ResolveSubquery because ResolveSubquery does not know the CTE. | ||
| other transformExpressions { | ||
| case e: SubqueryExpression => e.withNewPlan(substituteCTE(e.plan, cteName, ctePlan)) | ||
| } | ||
| } | ||
| } | ||
| Original file line number | Diff line number | Diff line change |
|---|---|---|
| @@ -0,0 +1,115 @@ | ||
| create temporary view t as select * from values 0, 1, 2 as t(id); | ||
| create temporary view t2 as select * from values 0, 1 as t(id); | ||
|
|
||
| -- CTE legacy substitution | ||
| SET spark.sql.legacy.cte.substitution.enabled=true; | ||
|
|
||
| -- CTE in CTE definition | ||
| WITH t as ( | ||
| WITH t2 AS (SELECT 1) | ||
| SELECT * FROM t2 | ||
| ) | ||
| SELECT * FROM t; | ||
|
|
||
| -- CTE in subquery | ||
| SELECT max(c) FROM ( | ||
| WITH t(c) AS (SELECT 1) | ||
| SELECT * FROM t | ||
| ); | ||
|
|
||
| -- CTE in subquery expression | ||
| SELECT ( | ||
| WITH t AS (SELECT 1) | ||
| SELECT * FROM t | ||
| ); | ||
|
|
||
| -- CTE in CTE definition shadows outer | ||
| WITH | ||
| t AS (SELECT 1), | ||
| t2 AS ( | ||
| WITH t AS (SELECT 2) | ||
| SELECT * FROM t | ||
| ) | ||
| SELECT * FROM t2; | ||
|
|
||
| -- CTE in CTE definition shadows outer 2 | ||
| WITH | ||
| t(c) AS (SELECT 1), | ||
| t2 AS ( | ||
| SELECT ( | ||
| SELECT max(c) FROM ( | ||
| WITH t(c) AS (SELECT 2) | ||
| SELECT * FROM t | ||
| ) | ||
| ) | ||
| ) | ||
| SELECT * FROM t2; | ||
|
|
||
| -- CTE in CTE definition shadows outer 3 | ||
| WITH | ||
| t AS (SELECT 1), | ||
| t2 AS ( | ||
| WITH t AS (SELECT 2), | ||
| t2 AS ( | ||
| WITH t AS (SELECT 3) | ||
| SELECT * FROM t | ||
| ) | ||
| SELECT * FROM t2 | ||
| ) | ||
| SELECT * FROM t2; | ||
|
|
||
| -- CTE in subquery shadows outer | ||
| WITH t(c) AS (SELECT 1) | ||
| SELECT max(c) FROM ( | ||
| WITH t(c) AS (SELECT 2) | ||
| SELECT * FROM t | ||
| ); | ||
|
|
||
| -- CTE in subquery shadows outer 2 | ||
| WITH t(c) AS (SELECT 1) | ||
| SELECT sum(c) FROM ( | ||
| SELECT max(c) AS c FROM ( | ||
| WITH t(c) AS (SELECT 2) | ||
| SELECT * FROM t | ||
| ) | ||
| ); | ||
|
|
||
| -- CTE in subquery shadows outer 3 | ||
| WITH t(c) AS (SELECT 1) | ||
| SELECT sum(c) FROM ( | ||
| WITH t(c) AS (SELECT 2) | ||
| SELECT max(c) AS c FROM ( | ||
| WITH t(c) AS (SELECT 3) | ||
| SELECT * FROM t | ||
| ) | ||
| ); | ||
|
|
||
| -- CTE in subquery expression shadows outer | ||
| WITH t AS (SELECT 1) | ||
| SELECT ( | ||
| WITH t AS (SELECT 2) | ||
| SELECT * FROM t | ||
| ); | ||
|
|
||
| -- CTE in subquery expression shadows outer 2 | ||
| WITH t AS (SELECT 1) | ||
| SELECT ( | ||
| SELECT ( | ||
| WITH t AS (SELECT 2) | ||
| SELECT * FROM t | ||
| ) | ||
| ); | ||
|
|
||
| -- CTE in subquery expression shadows outer 3 | ||
| WITH t AS (SELECT 1) | ||
| SELECT ( | ||
| WITH t AS (SELECT 2) | ||
| SELECT ( | ||
| WITH t AS (SELECT 3) | ||
| SELECT * FROM t | ||
| ) | ||
| ); | ||
|
|
||
| -- Clean up | ||
| DROP VIEW IF EXISTS t; | ||
| DROP VIEW IF EXISTS t2; |
Uh oh!
There was an error while loading. Please reload this page.