blob: ab07bb0df7a5941210d8e044e54fc2afc1046bae [file] [log] [blame]
<!DOCTYPE html>
<!--[if lt IE 7]> <html class="no-js lt-ie9 lt-ie8 lt-ie7"> <![endif]-->
<!--[if IE 7]> <html class="no-js lt-ie9 lt-ie8"> <![endif]-->
<!--[if IE 8]> <html class="no-js lt-ie9"> <![endif]-->
<!--[if gt IE 8]><!--> <html class="no-js"> <!--<![endif]-->
<head>
<meta charset="utf-8">
<meta http-equiv="X-UA-Compatible" content="IE=edge,chrome=1">
<title>Common Table Expression (CTE) - Spark 3.0.1 Documentation</title>
<link rel="stylesheet" href="css/bootstrap.min.css">
<style>
body {
padding-top: 60px;
padding-bottom: 40px;
}
</style>
<meta name="viewport" content="width=device-width">
<link rel="stylesheet" href="css/bootstrap-responsive.min.css">
<link rel="stylesheet" href="css/main.css">
<script src="js/vendor/modernizr-2.6.1-respond-1.1.0.min.js"></script>
<link rel="stylesheet" href="css/pygments-default.css">
<!-- Google analytics script -->
<script type="text/javascript">
var _gaq = _gaq || [];
_gaq.push(['_setAccount', 'UA-32518208-2']);
_gaq.push(['_trackPageview']);
(function() {
var ga = document.createElement('script'); ga.type = 'text/javascript'; ga.async = true;
ga.src = ('https:' == document.location.protocol ? 'https://ssl' : 'http://www') + '.google-analytics.com/ga.js';
var s = document.getElementsByTagName('script')[0]; s.parentNode.insertBefore(ga, s);
})();
</script>
</head>
<body>
<!--[if lt IE 7]>
<p class="chromeframe">You are using an outdated browser. <a href="https://browsehappy.com/">Upgrade your browser today</a> or <a href="http://www.google.com/chromeframe/?redirect=true">install Google Chrome Frame</a> to better experience this site.</p>
<![endif]-->
<!-- This code is taken from http://twitter.github.com/bootstrap/examples/hero.html -->
<div class="navbar navbar-fixed-top" id="topbar">
<div class="navbar-inner">
<div class="container">
<div class="brand"><a href="index.html">
<img src="img/spark-logo-hd.png" style="height:50px;"/></a><span class="version">3.0.1</span>
</div>
<ul class="nav">
<!--TODO(andyk): Add class="active" attribute to li some how.-->
<li><a href="index.html">Overview</a></li>
<li class="dropdown">
<a href="#" class="dropdown-toggle" data-toggle="dropdown">Programming Guides<b class="caret"></b></a>
<ul class="dropdown-menu">
<li><a href="quick-start.html">Quick Start</a></li>
<li><a href="rdd-programming-guide.html">RDDs, Accumulators, Broadcasts Vars</a></li>
<li><a href="sql-programming-guide.html">SQL, DataFrames, and Datasets</a></li>
<li><a href="structured-streaming-programming-guide.html">Structured Streaming</a></li>
<li><a href="streaming-programming-guide.html">Spark Streaming (DStreams)</a></li>
<li><a href="ml-guide.html">MLlib (Machine Learning)</a></li>
<li><a href="graphx-programming-guide.html">GraphX (Graph Processing)</a></li>
<li><a href="sparkr.html">SparkR (R on Spark)</a></li>
</ul>
</li>
<li class="dropdown">
<a href="#" class="dropdown-toggle" data-toggle="dropdown">API Docs<b class="caret"></b></a>
<ul class="dropdown-menu">
<li><a href="api/scala/org/apache/spark/index.html">Scala</a></li>
<li><a href="api/java/index.html">Java</a></li>
<li><a href="api/python/index.html">Python</a></li>
<li><a href="api/R/index.html">R</a></li>
<li><a href="api/sql/index.html">SQL, Built-in Functions</a></li>
</ul>
</li>
<li class="dropdown">
<a href="#" class="dropdown-toggle" data-toggle="dropdown">Deploying<b class="caret"></b></a>
<ul class="dropdown-menu">
<li><a href="cluster-overview.html">Overview</a></li>
<li><a href="submitting-applications.html">Submitting Applications</a></li>
<li class="divider"></li>
<li><a href="spark-standalone.html">Spark Standalone</a></li>
<li><a href="running-on-mesos.html">Mesos</a></li>
<li><a href="running-on-yarn.html">YARN</a></li>
<li><a href="running-on-kubernetes.html">Kubernetes</a></li>
</ul>
</li>
<li class="dropdown">
<a href="api.html" class="dropdown-toggle" data-toggle="dropdown">More<b class="caret"></b></a>
<ul class="dropdown-menu">
<li><a href="configuration.html">Configuration</a></li>
<li><a href="monitoring.html">Monitoring</a></li>
<li><a href="tuning.html">Tuning Guide</a></li>
<li><a href="job-scheduling.html">Job Scheduling</a></li>
<li><a href="security.html">Security</a></li>
<li><a href="hardware-provisioning.html">Hardware Provisioning</a></li>
<li><a href="migration-guide.html">Migration Guide</a></li>
<li class="divider"></li>
<li><a href="building-spark.html">Building Spark</a></li>
<li><a href="https://spark.apache.org/contributing.html">Contributing to Spark</a></li>
<li><a href="https://spark.apache.org/third-party-projects.html">Third Party Projects</a></li>
</ul>
</li>
</ul>
<!--<p class="navbar-text pull-right"><span class="version-text">v3.0.1</span></p>-->
</div>
</div>
</div>
<div class="container-wrapper">
<div class="left-menu-wrapper">
<div class="left-menu">
<h3><a href="sql-programming-guide.html">Spark SQL Guide</a></h3>
<ul>
<li>
<a href="sql-getting-started.html">
Getting Started
</a>
</li>
<li>
<a href="sql-data-sources.html">
Data Sources
</a>
</li>
<li>
<a href="sql-performance-tuning.html">
Performance Tuning
</a>
</li>
<li>
<a href="sql-distributed-sql-engine.html">
Distributed SQL Engine
</a>
</li>
<li>
<a href="sql-pyspark-pandas-with-arrow.html">
PySpark Usage Guide for Pandas with Apache Arrow
</a>
</li>
<li>
<a href="sql-migration-old.html">
Migration Guide
</a>
</li>
<li>
<a href="sql-ref.html">
SQL Reference
</a>
</li>
<ul>
<li>
<a href="sql-ref-ansi-compliance.html">
ANSI Compliance
</a>
</li>
<li>
<a href="sql-ref-datatypes.html">
Data Types
</a>
</li>
<li>
<a href="sql-ref-datetime-pattern.html">
Datetime Pattern
</a>
</li>
<li>
<a href="sql-ref-functions.html">
Functions
</a>
</li>
<li>
<a href="sql-ref-identifier.html">
Identifiers
</a>
</li>
<li>
<a href="sql-ref-literals.html">
Literals
</a>
</li>
<li>
<a href="sql-ref-null-semantics.html">
Null Semantics
</a>
</li>
<li>
<a href="sql-ref-syntax.html">
SQL Syntax
</a>
</li>
<ul>
<li>
<a href="sql-ref-syntax-ddl.html">
Data Definition Statements
</a>
</li>
<li>
<a href="sql-ref-syntax-dml.html">
Data Manipulation Statements
</a>
</li>
<li>
<a href="sql-ref-syntax-qry.html">
Data Retrieval(Queries)
</a>
</li>
<ul>
<li>
<a href="sql-ref-syntax-qry-select.html">
SELECT
</a>
</li>
<ul>
<li>
<a href="sql-ref-syntax-qry-select-where.html">
WHERE Clause
</a>
</li>
<li>
<a href="sql-ref-syntax-qry-select-groupby.html">
GROUP BY Clause
</a>
</li>
<li>
<a href="sql-ref-syntax-qry-select-having.html">
HAVING Clause
</a>
</li>
<li>
<a href="sql-ref-syntax-qry-select-orderby.html">
ORDER BY Clause
</a>
</li>
<li>
<a href="sql-ref-syntax-qry-select-sortby.html">
SORT BY Clause
</a>
</li>
<li>
<a href="sql-ref-syntax-qry-select-clusterby.html">
CLUSTER BY Clause
</a>
</li>
<li>
<a href="sql-ref-syntax-qry-select-distribute-by.html">
DISTRIBUTE BY Clause
</a>
</li>
<li>
<a href="sql-ref-syntax-qry-select-limit.html">
LIMIT Clause
</a>
</li>
<li>
<a href="sql-ref-syntax-qry-select-cte.html">
<b>Common Table Expression</b>
</a>
</li>
<li>
<a href="sql-ref-syntax-qry-select-hints.html">
Hints
</a>
</li>
<li>
<a href="sql-ref-syntax-qry-select-inline-table.html">
Inline Table
</a>
</li>
<li>
<a href="sql-ref-syntax-qry-select-join.html">
JOIN
</a>
</li>
<li>
<a href="sql-ref-syntax-qry-select-like.html">
LIKE Predicate
</a>
</li>
<li>
<a href="sql-ref-syntax-qry-select-setops.html">
Set Operators
</a>
</li>
<li>
<a href="sql-ref-syntax-qry-select-sampling.html">
TABLESAMPLE
</a>
</li>
<li>
<a href="sql-ref-syntax-qry-select-tvf.html">
Table-valued Function
</a>
</li>
<li>
<a href="sql-ref-syntax-qry-select-window.html">
Window Function
</a>
</li>
<li>
<a href="sql-ref-syntax-qry-select-case.html">
CASE Clause
</a>
</li>
<li>
<a href="sql-ref-syntax-qry-select-lateral-view.html">
LATERAL VIEW Clause
</a>
</li>
<li>
<a href="sql-ref-syntax-qry-select-pivot.html">
PIVOT Clause
</a>
</li>
</ul>
<li>
<a href="sql-ref-syntax-qry-explain.html">
EXPLAIN
</a>
</li>
</ul>
<li>
<a href="sql-ref-syntax-aux.html">
Auxiliary Statements
</a>
</li>
</ul>
</ul>
</ul>
</div>
</div>
<input id="nav-trigger" class="nav-trigger" checked type="checkbox">
<label for="nav-trigger"></label>
<div class="content-with-sidebar" id="content">
<h1 class="title">Common Table Expression (CTE)</h1>
<h3 id="description">Description</h3>
<p>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.</p>
<h3 id="syntax">Syntax</h3>
<div class="language-sql highlighter-rouge"><div class="highlight"><pre class="highlight"><code><span class="k">WITH</span> <span class="n">common_table_expression</span> <span class="p">[</span> <span class="p">,</span> <span class="p">...</span> <span class="p">]</span>
</code></pre></div></div>
<p>While <code class="highlighter-rouge">common_table_expression</code> is defined as</p>
<div class="language-sql highlighter-rouge"><div class="highlight"><pre class="highlight"><code><span class="n">expression_name</span> <span class="p">[</span> <span class="p">(</span> <span class="k">column_name</span> <span class="p">[</span> <span class="p">,</span> <span class="p">...</span> <span class="p">]</span> <span class="p">)</span> <span class="p">]</span> <span class="p">[</span> <span class="k">AS</span> <span class="p">]</span> <span class="p">(</span> <span class="n">query</span> <span class="p">)</span>
</code></pre></div></div>
<h3 id="parameters">Parameters</h3>
<ul>
<li>
<p><strong>expression_name</strong></p>
<p>Specifies a name for the common table expression.</p>
</li>
<li>
<p><strong>query</strong></p>
<p>A <a href="sql-ref-syntax-qry-select.html">SELECT statement</a>.</p>
</li>
</ul>
<h3 id="examples">Examples</h3>
<div class="language-sql highlighter-rouge"><div class="highlight"><pre class="highlight"><code><span class="c1">-- CTE with multiple column aliases</span>
<span class="k">WITH</span> <span class="n">t</span><span class="p">(</span><span class="n">x</span><span class="p">,</span> <span class="n">y</span><span class="p">)</span> <span class="k">AS</span> <span class="p">(</span><span class="k">SELECT</span> <span class="mi">1</span><span class="p">,</span> <span class="mi">2</span><span class="p">)</span>
<span class="k">SELECT</span> <span class="o">*</span> <span class="k">FROM</span> <span class="n">t</span> <span class="k">WHERE</span> <span class="n">x</span> <span class="o">=</span> <span class="mi">1</span> <span class="k">AND</span> <span class="n">y</span> <span class="o">=</span> <span class="mi">2</span><span class="p">;</span>
<span class="o">+</span><span class="c1">---+---+</span>
<span class="o">|</span> <span class="n">x</span><span class="o">|</span> <span class="n">y</span><span class="o">|</span>
<span class="o">+</span><span class="c1">---+---+</span>
<span class="o">|</span> <span class="mi">1</span><span class="o">|</span> <span class="mi">2</span><span class="o">|</span>
<span class="o">+</span><span class="c1">---+---+</span>
<span class="c1">-- CTE in CTE definition</span>
<span class="k">WITH</span> <span class="n">t</span> <span class="k">AS</span> <span class="p">(</span>
<span class="k">WITH</span> <span class="n">t2</span> <span class="k">AS</span> <span class="p">(</span><span class="k">SELECT</span> <span class="mi">1</span><span class="p">)</span>
<span class="k">SELECT</span> <span class="o">*</span> <span class="k">FROM</span> <span class="n">t2</span>
<span class="p">)</span>
<span class="k">SELECT</span> <span class="o">*</span> <span class="k">FROM</span> <span class="n">t</span><span class="p">;</span>
<span class="o">+</span><span class="c1">---+</span>
<span class="o">|</span> <span class="mi">1</span><span class="o">|</span>
<span class="o">+</span><span class="c1">---+</span>
<span class="o">|</span> <span class="mi">1</span><span class="o">|</span>
<span class="o">+</span><span class="c1">---+</span>
<span class="c1">-- CTE in subquery</span>
<span class="k">SELECT</span> <span class="k">max</span><span class="p">(</span><span class="k">c</span><span class="p">)</span> <span class="k">FROM</span> <span class="p">(</span>
<span class="k">WITH</span> <span class="n">t</span><span class="p">(</span><span class="k">c</span><span class="p">)</span> <span class="k">AS</span> <span class="p">(</span><span class="k">SELECT</span> <span class="mi">1</span><span class="p">)</span>
<span class="k">SELECT</span> <span class="o">*</span> <span class="k">FROM</span> <span class="n">t</span>
<span class="p">);</span>
<span class="o">+</span><span class="c1">------+</span>
<span class="o">|</span><span class="k">max</span><span class="p">(</span><span class="k">c</span><span class="p">)</span><span class="o">|</span>
<span class="o">+</span><span class="c1">------+</span>
<span class="o">|</span> <span class="mi">1</span><span class="o">|</span>
<span class="o">+</span><span class="c1">------+</span>
<span class="c1">-- CTE in subquery expression</span>
<span class="k">SELECT</span> <span class="p">(</span>
<span class="k">WITH</span> <span class="n">t</span> <span class="k">AS</span> <span class="p">(</span><span class="k">SELECT</span> <span class="mi">1</span><span class="p">)</span>
<span class="k">SELECT</span> <span class="o">*</span> <span class="k">FROM</span> <span class="n">t</span>
<span class="p">);</span>
<span class="o">+</span><span class="c1">----------------+</span>
<span class="o">|</span><span class="n">scalarsubquery</span><span class="p">()</span><span class="o">|</span>
<span class="o">+</span><span class="c1">----------------+</span>
<span class="o">|</span> <span class="mi">1</span><span class="o">|</span>
<span class="o">+</span><span class="c1">----------------+</span>
<span class="c1">-- CTE in CREATE VIEW statement</span>
<span class="k">CREATE</span> <span class="k">VIEW</span> <span class="n">v</span> <span class="k">AS</span>
<span class="k">WITH</span> <span class="n">t</span><span class="p">(</span><span class="n">a</span><span class="p">,</span> <span class="n">b</span><span class="p">,</span> <span class="k">c</span><span class="p">,</span> <span class="n">d</span><span class="p">)</span> <span class="k">AS</span> <span class="p">(</span><span class="k">SELECT</span> <span class="mi">1</span><span class="p">,</span> <span class="mi">2</span><span class="p">,</span> <span class="mi">3</span><span class="p">,</span> <span class="mi">4</span><span class="p">)</span>
<span class="k">SELECT</span> <span class="o">*</span> <span class="k">FROM</span> <span class="n">t</span><span class="p">;</span>
<span class="k">SELECT</span> <span class="o">*</span> <span class="k">FROM</span> <span class="n">v</span><span class="p">;</span>
<span class="o">+</span><span class="c1">---+---+---+---+</span>
<span class="o">|</span> <span class="n">a</span><span class="o">|</span> <span class="n">b</span><span class="o">|</span> <span class="k">c</span><span class="o">|</span> <span class="n">d</span><span class="o">|</span>
<span class="o">+</span><span class="c1">---+---+---+---+</span>
<span class="o">|</span> <span class="mi">1</span><span class="o">|</span> <span class="mi">2</span><span class="o">|</span> <span class="mi">3</span><span class="o">|</span> <span class="mi">4</span><span class="o">|</span>
<span class="o">+</span><span class="c1">---+---+---+---+</span>
<span class="c1">-- If name conflict is detected in nested CTE, then AnalysisException is thrown by default.</span>
<span class="c1">-- SET spark.sql.legacy.ctePrecedencePolicy = CORRECTED (which is recommended),</span>
<span class="c1">-- inner CTE definitions take precedence over outer definitions.</span>
<span class="k">SET</span> <span class="n">spark</span><span class="p">.</span><span class="k">sql</span><span class="p">.</span><span class="n">legacy</span><span class="p">.</span><span class="n">ctePrecedencePolicy</span> <span class="o">=</span> <span class="n">CORRECTED</span><span class="p">;</span>
<span class="k">WITH</span>
<span class="n">t</span> <span class="k">AS</span> <span class="p">(</span><span class="k">SELECT</span> <span class="mi">1</span><span class="p">),</span>
<span class="n">t2</span> <span class="k">AS</span> <span class="p">(</span>
<span class="k">WITH</span> <span class="n">t</span> <span class="k">AS</span> <span class="p">(</span><span class="k">SELECT</span> <span class="mi">2</span><span class="p">)</span>
<span class="k">SELECT</span> <span class="o">*</span> <span class="k">FROM</span> <span class="n">t</span>
<span class="p">)</span>
<span class="k">SELECT</span> <span class="o">*</span> <span class="k">FROM</span> <span class="n">t2</span><span class="p">;</span>
<span class="o">+</span><span class="c1">---+</span>
<span class="o">|</span> <span class="mi">2</span><span class="o">|</span>
<span class="o">+</span><span class="c1">---+</span>
<span class="o">|</span> <span class="mi">2</span><span class="o">|</span>
<span class="o">+</span><span class="c1">---+</span>
</code></pre></div></div>
<h3 id="related-statements">Related Statements</h3>
<ul>
<li><a href="sql-ref-syntax-qry-select.html">SELECT</a></li>
</ul>
</div>
<!-- /container -->
</div>
<script src="js/vendor/jquery-3.4.1.min.js"></script>
<script src="js/vendor/bootstrap.min.js"></script>
<script src="js/vendor/anchor.min.js"></script>
<script src="js/main.js"></script>
<!-- MathJax Section -->
<script type="text/x-mathjax-config">
MathJax.Hub.Config({
TeX: { equationNumbers: { autoNumber: "AMS" } }
});
</script>
<script>
// Note that we load MathJax this way to work with local file (file://), HTTP and HTTPS.
// We could use "//cdn.mathjax...", but that won't support "file://".
(function(d, script) {
script = d.createElement('script');
script.type = 'text/javascript';
script.async = true;
script.onload = function(){
MathJax.Hub.Config({
tex2jax: {
inlineMath: [ ["$", "$"], ["\\\\(","\\\\)"] ],
displayMath: [ ["$$","$$"], ["\\[", "\\]"] ],
processEscapes: true,
skipTags: ['script', 'noscript', 'style', 'textarea', 'pre']
}
});
};
script.src = ('https:' == document.location.protocol ? 'https://' : 'http://') +
'cdnjs.cloudflare.com/ajax/libs/mathjax/2.7.1/MathJax.js' +
'?config=TeX-AMS-MML_HTMLorMML';
d.getElementsByTagName('head')[0].appendChild(script);
}(document));
</script>
</body>
</html>