-
Notifications
You must be signed in to change notification settings - Fork 29.1k
[SPARK-31428][SQL][DOCS] Document Common Table Expression in SQL Reference #28196
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
Closed
Closed
Changes from all commits
Commits
Show all changes
5 commits
Select commit
Hold shift + click to select a range
File filter
Filter by extension
Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
There are no files selected for viewing
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
| Original file line number | Diff line number | Diff line change |
|---|---|---|
|
|
@@ -19,4 +19,111 @@ license: | | |
| limitations under the License. | ||
| --- | ||
|
|
||
| **This page is under construction** | ||
| ### Description | ||
|
|
||
| A common table expression (CTE) defines a temporary result set that a user can reference possibly multiple times within the scope of a SQL statement. A CTE is used mainly in a SELECT statement. | ||
|
|
||
| ### Syntax | ||
|
|
||
| {% highlight sql %} | ||
| WITH common_table_expression [ , ... ] | ||
| {% endhighlight %} | ||
|
|
||
| While `common_table_expression` is defined as | ||
| {% highlight sql %} | ||
| expression_name [ ( column_name [ , ... ] ) ] [ AS ] ( [ common_table_expression ] query ) | ||
| {% endhighlight %} | ||
|
|
||
| ### Parameters | ||
|
|
||
| <dl> | ||
| <dt><code><em>expression_name</em></code></dt> | ||
| <dd> | ||
| Specifies a name for the common table expression. | ||
| </dd> | ||
| </dl> | ||
| <dl> | ||
| <dt><code><em>query</em></code></dt> | ||
| <dd> | ||
| A <a href="sql-ref-syntax-qry-select.html">SELECT</a> statement. | ||
| </dd> | ||
| </dl> | ||
|
|
||
| ### Examples | ||
|
|
||
| {% highlight sql %} | ||
| -- CTE with multiple column aliases | ||
| WITH t(x, y) AS (SELECT 1, 2) | ||
| SELECT * FROM t WHERE x = 1 AND y = 2; | ||
| +---+---+ | ||
| | x| y| | ||
| +---+---+ | ||
| | 1| 2| | ||
| +---+---+ | ||
|
|
||
| -- CTE in CTE definition | ||
| WITH t as ( | ||
| WITH t2 AS (SELECT 1) | ||
| SELECT * FROM t2 | ||
| ) | ||
| SELECT * FROM t; | ||
| +---+ | ||
| | 1| | ||
| +---+ | ||
| | 1| | ||
| +---+ | ||
|
|
||
| -- CTE in subquery | ||
| SELECT max(c) FROM ( | ||
| WITH t(c) AS (SELECT 1) | ||
| SELECT * FROM t | ||
| ); | ||
| +------+ | ||
| |max(c)| | ||
| +------+ | ||
| | 1| | ||
| +------+ | ||
|
|
||
| -- CTE in subquery expression | ||
| SELECT ( | ||
| WITH t AS (SELECT 1) | ||
| SELECT * FROM t | ||
| ); | ||
| +----------------+ | ||
| |scalarsubquery()| | ||
| +----------------+ | ||
| | 1| | ||
| +----------------+ | ||
|
|
||
| -- CTE in CREATE VIEW statement | ||
| CREATE VIEW v AS | ||
| WITH t(a, b, c, d) AS (SELECT 1, 2, 3, 4) | ||
| SELECT * FROM t; | ||
| SELECT * FROM v; | ||
| +---+---+---+---+ | ||
| | a| b| c| d| | ||
| +---+---+---+---+ | ||
| | 1| 2| 3| 4| | ||
| +---+---+---+---+ | ||
|
|
||
| -- If name conflict is detected in nested CTE, then AnalysisException is thrown by default. | ||
| -- SET spark.sql.legacy.ctePrecedencePolicy = CORRECTED (which is recommended), | ||
| -- inner CTE definitions take precedence over outer definitions. | ||
| SET spark.sql.legacy.ctePrecedencePolicy = CORRECTED; | ||
| WITH | ||
| t AS (SELECT 1), | ||
| t2 AS ( | ||
| WITH t AS (SELECT 2) | ||
| SELECT * FROM t | ||
| ) | ||
| SELECT * FROM t2; | ||
| +---+ | ||
| | 2| | ||
| +---+ | ||
| | 2| | ||
| +---+ | ||
| {% endhighlight %} | ||
|
|
||
|
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. How about adding one more CTE example in
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. Will do |
||
| ### Related Statements | ||
|
|
||
| * [SELECT](sql-ref-syntax-qry-select.html) | ||
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Add this suggestion to a batch that can be applied as a single commit.
This suggestion is invalid because no changes were made to the code.
Suggestions cannot be applied while the pull request is closed.
Suggestions cannot be applied while viewing a subset of changes.
Only one suggestion per line can be applied in a batch.
Add this suggestion to a batch that can be applied as a single commit.
Applying suggestions on deleted lines is not supported.
You must change the existing code in this line in order to create a valid suggestion.
Outdated suggestions cannot be applied.
This suggestion has been applied or marked resolved.
Suggestions cannot be applied from pending reviews.
Suggestions cannot be applied on multi-line comments.
Suggestions cannot be applied while the pull request is queued to merge.
Suggestion cannot be applied right now. Please check back later.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
We still need to describe this? I personally think users can see the migration guide for these kinds of legacy behaviours.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
Thanks for your comment.
I prefer to document the default behavior. I actually thought the default behavior is "inner CTE definitions take precedence over outer definitions". When I tried the example, I was surprised to see the Exception, then I looked the code and found out I need to set spark.sql.legacy.ctePrecedencePolicy to make it work. So I guess it is worth mentioning the default here.