| --- |
| layout: global |
| title: Common Table Expression (CTE) |
| displayTitle: Common Table Expression (CTE) |
| license: | |
| 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. |
| --- |
| |
| ### 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 |
| |
| ```sql |
| WITH common_table_expression [ , ... ] |
| ``` |
| |
| While `common_table_expression` is defined as |
| ```sql |
| expression_name [ ( column_name [ , ... ] ) ] [ AS ] ( query ) |
| ``` |
| |
| ### Parameters |
| |
| * **expression_name** |
| |
| Specifies a name for the common table expression. |
| |
| * **query** |
| |
| A [SELECT statement](sql-ref-syntax-qry-select.html). |
| |
| ### Examples |
| |
| ```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| |
| +---+---+---+---+ |
| |
| WITH |
| t AS (SELECT 1), |
| t2 AS ( |
| WITH t AS (SELECT 2) |
| SELECT * FROM t |
| ) |
| SELECT * FROM t2; |
| +---+ |
| | 2| |
| +---+ |
| | 2| |
| +---+ |
| ``` |
| |
| ### Related Statements |
| |
| * [SELECT](sql-ref-syntax-qry-select.html) |