Common table expression (CTE)
Applies to: Databricks SQL Databricks Runtime
Defines a temporary result set that you can reference possibly multiple times within the scope of a SQL statement. A CTE is used mainly in a SELECT
statement.
Syntax
WITH common_table_expression [, ...]
common_table_expression
view_identifier [ ( column_identifier [, ...] ) ] [ AS ] ( query )
Parameters
view_identifier
An identifier by which the
common_table_expression
can be referencedcolumn_identifier
An optional identifier by which a column of the
common_table_expression
can be referenced.If
column_identifier
s are specified their number must match the number of columns returned by thequery
. If no names are specified the column names are derived from thequery
.-
A query producing a result set.
Examples
-- CTE with multiple column aliases
> WITH t(x, y) AS (SELECT 1, 2)
SELECT * FROM t WHERE x = 1 AND y = 2;
1 2
-- CTE in CTE definition
> WITH t AS (
WITH t2 AS (SELECT 1)
SELECT * FROM t2)
SELECT * FROM t;
1
-- CTE in subquery
> SELECT max(c) FROM (
WITH t(c) AS (SELECT 1)
SELECT * FROM t);
1
-- CTE in subquery expression
> SELECT (WITH t AS (SELECT 1)
SELECT * FROM t);
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;
1 2 3 4
-- CTE names are scoped
> WITH t AS (SELECT 1),
t2 AS (
WITH t AS (SELECT 2)
SELECT * FROM t)
SELECT * FROM t2;
2