The WITH
clause provides a way to write auxiliary statements for use in a larger query. These statements, which are often referred to as Common Table Expressions or CTEs, can be thought of as defining temporary tables that exist just for one query.
NoteLimitations when using a
WITH
clause in Greenplum Database include:
- For a
SELECT
command that includes aWITH
clause, the clause can contain at most a single clause that modifies table data (INSERT
,UPDATE
, orDELETE
command).- For a data-modifying command (
INSERT
,UPDATE
, orDELETE
) that includes aWITH
clause, the clause can only contain aSELECT
command; it cannot contain a data-modifying command.
By default, Greenplum Database enables the RECURSIVE
keyword for the WITH
clause. RECURSIVE
can be deactivated by setting the server configuration parameter gp_recursive_cte to false
.
Parent topic: Querying Data
One use of CTEs is to break down complicated queries into simpler parts. The examples in this section show the WITH
clause being used with a SELECT
command. The example WITH
clauses can be used the same manner with INSERT
, UPDATE
, or DELETE
.
A SELECT
command in the WITH
clause is evaluated only once per execution of the parent query, even if it is referred to more than once by the parent query or sibling WITH
clauses. Thus, expensive calculations that are needed in multiple places can be placed within a WITH
clause to avoid redundant work. Another possible application is to prevent unwanted multiple evaluations of functions with side-effects. However, the other side of this coin is that the optimizer is less able to push restrictions from the parent query down into a WITH
query than an ordinary sub-query. The WITH
query will generally be evaluated as written, without suppression of rows that the parent query might discard afterwards. However, evaluation might stop early if the references to the query demand only a limited number of rows.
The following example query displays per-product sales totals in only the top sales regions:
WITH regional_sales AS (
SELECT region, SUM(amount) AS total_sales
FROM orders
GROUP BY region
), top_regions AS (
SELECT region
FROM regional_sales
WHERE total_sales > (SELECT SUM(total_sales)/10 FROM regional_sales)
)
SELECT region,
product,
SUM(quantity) AS product_units,
SUM(amount) AS product_sales
FROM orders
WHERE region IN (SELECT region FROM top_regions)
GROUP BY region, product;
The WITH
clause defines two auxiliary statements named regional_sales
and top_regions
, where the output of regional_sales
is used in top_regions
and the output of top_regions
is used in the primary SELECT
query. The query could have been written without the WITH
clause, but would have required two levels of nested sub-SELECT
s.
When you specify the optional RECURSIVE
keyword, the WITH
clause can accomplish operations not otherwise possible in standard SQL. Using RECURSIVE
, a WITH
query can refer to its own output. This simple example computes the sum of integers from 1 through 100:
WITH RECURSIVE t(n) AS (
VALUES (1)
UNION ALL
SELECT n+1 FROM t WHERE n < 100
)
SELECT sum(n) FROM t;
The general form of a recursive WITH
query always follows the pattern of: a non-recursive term, followed by a UNION
(or UNION ALL
), and then a recursive term, where only the recursive term can contain a reference to the query output.
<non_recursive_term> UNION [ ALL ] <recursive_term>
A recursive WITH
query that contains a UNION [ ALL ]
is evaluated as follows:
Evaluate the non-recursive term. For UNION
(but not UNION ALL
), discard duplicate rows. Include all remaining rows in the result of the recursive query, and also place them in a temporary working table.
As long as the working table is not empty, repeat these steps:
UNION
(but not UNION ALL
), discard duplicate rows and rows that duplicate any previous result row. Include all remaining rows in the result of the recursive query, and also place them in a temporary intermediate table.NoteWhile
RECURSIVE
allows queries to be specified recursively, Greenplum Database evaluates such queries iteratively internally.
In the example above, the working table has just a single row in each step, and it takes on the values from 1 through 100 in successive steps. In the 100th step, there is no output because of the WHERE
clause, and so the query terminates.
Recursive WITH
queries are typically used to deal with hierarchical or tree-structured data. For example, this query locates all of the direct and indirect sub-parts of a product, given only a table that shows immediate inclusions:
WITH RECURSIVE included_parts(sub_part, part, quantity) AS (
SELECT sub_part, part, quantity FROM parts WHERE part = 'our_product'
UNION ALL
SELECT p.sub_part, p.part, p.quantity * pr.quantity
FROM included_parts pr, parts p
WHERE p.part = pr.sub_part
)
SELECT sub_part, SUM(quantity) as total_quantity
FROM included_parts
GROUP BY sub_part;
When working with recursive WITH
queries, you must ensure that the recursive part of the query eventually returns no tuples, or else the query loops indefinitely.
For some queries, using UNION
instead of UNION ALL
can ensure that the recursive part of the query eventually returns no tuples by discarding rows that duplicate previous output rows. However, often a cycle does not involve output rows that are complete duplicates: it might be sufficient to check just one or a few fields to see if the same point has been reached before. The standard method for handling such situations is to compute an array of the visited values. For example, consider the following query that searches a table graph
using a link
field:
WITH RECURSIVE search_graph(id, link, data, depth) AS (
SELECT g.id, g.link, g.data, 1
FROM graph g
UNION ALL
SELECT g.id, g.link, g.data, sg.depth + 1
FROM graph g, search_graph sg
WHERE g.id = sg.link
)
SELECT * FROM search_graph;
This query loops if the link
relationships contain cycles. Because the query requires a depth
output, changing UNION ALL
to UNION
does not eliminate the looping. Instead the query needs to recognize whether it has reached the same row again while following a particular path of links. This modified query adds two columns, path
and cycle
, to the loop-prone query:
WITH RECURSIVE search_graph(id, link, data, depth, path, cycle) AS (
SELECT g.id, g.link, g.data, 1,
ARRAY[g.id],
false
FROM graph g
UNION ALL
SELECT g.id, g.link, g.data, sg.depth + 1,
path || g.id,
g.id = ANY(path)
FROM graph g, search_graph sg
WHERE g.id = sg.link AND NOT cycle
)
SELECT * FROM search_graph;
Aside from detecting cycles, the array value is useful in its own right since it represents the "path" taken to reach any particular row.
In the general case where more than one field needs to be checked to recognize a cycle, use an array of rows. For example, if we needed to compare fields f1
and f2
:
WITH RECURSIVE search_graph(id, link, data, depth, path, cycle) AS (
SELECT g.id, g.link, g.data, 1,
ARRAY[ROW(g.f1, g.f2)],
false
FROM graph g
UNION ALL
SELECT g.id, g.link, g.data, sg.depth + 1,
path || ROW(g.f1, g.f2),
ROW(g.f1, g.f2) = ANY(path)
FROM graph g, search_graph sg
WHERE g.id = sg.link AND NOT cycle
)
SELECT * FROM search_graph;
Tip: Omit the ROW()
syntax in the case where only one field must be checked to recognize a cycle. This uses a simple array rather than a composite-type array, gaining efficiency.
Tip: The recursive query evaluation algorithm produces its output in breadth-first search order. You can display the results in depth-first search order by making the outer query ORDER BY
a "path" column constructed in this way.
A helpful technique for testing a query when you are not certain if it might loop indefinitely is to place a LIMIT
in the parent query. For example, the following query would loop forever without the LIMIT
clause:
WITH RECURSIVE t(n) AS (
SELECT 1
UNION ALL
SELECT n+1 FROM t
)
SELECT n FROM t LIMIT 100;
This technique works because Greenplum Database evaluates only as many rows of a WITH
query as are actually fetched by the parent query. Using this technique in production environments is not recommended, because other systems might work differently. Also, the technique might not work if the outer query sorts the recursive WITH
results or joins the results to another table, because in such cases the outer query will usually try to fetch all of the WITH
query's output anyway.
A useful property of WITH
queries is that they are normally evaluated only once per execution of the parent query, even if they are referred to more than once by the parent query or sibling WITH
queries. Thus, expensive calculations that are needed in multiple places can be placed within a WITH
query to avoid redundant work. Another possible application is to prevent unwanted multiple evaluations of functions with side-effects. However, the other side of this coin is that the optimizer is not able to push restrictions from the parent query down into a multiply-referenced WITH
query, since that might affect all uses of the WITH
query's output when it should affect only one. Greenplum Database evalues the multiply-referenced WITH
query as written, without suppression of rows that the parent query might discard afterwards. (But, as mentioned above, evaluation might stop early if the reference(s) to the query demand only a limited number of rows.)
If a WITH
query is non-recursive and side-effect-free (that is, it is a SELECT
containing no volatile functions) then it can be folded into the parent query, allowing joint optimization of the two query levels. By default, this happens if the parent query references the WITH
query just once, but not if it references the WITH
query more than once. You can override that decision by specifying MATERIALIZED
to force separate calculation of the WITH
query, or by specifying NOT MATERIALIZED
to force it to be merged into the parent query. The latter choice risks duplicate computation of the WITH
query, but it can still give a net savings if each usage of the WITH
query needs only a small part of the WITH
query's full output.
A simple example of these rules follows:
WITH w AS (
SELECT * FROM big_table
)
SELECT * FROM w WHERE key = 123;
This WITH
query will be folded, producing the same execution plan as:
SELECT * FROM big_table WHERE key = 123;
In particular, if there's an index on key
, Greenplum Database uses it to fetch just the rows having key = 123
. On the other hand, in:
WITH w AS (
SELECT * FROM big_table
)
SELECT * FROM w AS w1 JOIN w AS w2 ON w1.key = w2.ref
WHERE w2.key = 123;
the WITH
query will be materialized, producing a temporary copy of big_table
that is then joined with itself — without benefit of any index. This query will run much more efficiently if written as:
WITH w AS NOT MATERIALIZED (
SELECT * FROM big_table
)
SELECT * FROM w AS w1 JOIN w AS w2 ON w1.key = w2.ref
WHERE w2.key = 123;
so that the parent query's restrictions can be applied directly to scans of big_table
.
An example where NOT MATERIALIZED
could be undesirable is:
WITH w AS (
SELECT key, very_expensive_function(val) as f FROM some_table
)
SELECT * FROM w AS w1 JOIN w AS w2 ON w1.f = w2.f;
Here, materialization of the WITH
query ensures that Greenplum Database evaluations very_expensive_function
only once per table row, not twice.
For a SELECT
command, you can use the data-modifying commands INSERT
, UPDATE
, or DELETE
in a WITH
clause. This allows you to perform several different operations in the same query.
A data-modifying statement in a WITH
clause is run exactly once, and always to completion, independently of whether the primary query reads all (or indeed any) of the output. This is different from the rule when using SELECT
in a WITH
clause, the execution of a SELECT
continues only as long as the primary query demands its output.
This simple CTE query deletes rows from products
. The DELETE
in the WITH
clause deletes the specified rows from products, returning their contents by means of its RETURNING
clause.
WITH deleted_rows AS (
DELETE FROM products
WHERE
"date" >= '2010-10-01' AND
"date" < '2010-11-01'
RETURNING *
)
SELECT * FROM deleted_rows;
Data-modifying statements in a WITH
clause must have RETURNING
clauses, as shown in the previous example. It is the output of the RETURNING
clause, not the target table of the data-modifying statement, that forms the temporary table that can be referred to by the rest of the query. If a data-modifying statement in a WITH
lacks a RETURNING
clause, then it forms no temporary table and cannot be referred to in the rest of the query. Greenplum Database runs such a statement nonetheless.
If the optional RECURSIVE
keyword is enabled, recursive self-references in data-modifying statements are not allowed. In some cases it is possible to work around this limitation by referring to the output of a recursive WITH
. For example, this query would remove all direct and indirect subparts of a product:
WITH RECURSIVE included_parts(sub_part, part) AS (
SELECT sub_part, part FROM parts WHERE part = 'our_product'
UNION ALL
SELECT p.sub_part, p.part
FROM included_parts pr, parts p
WHERE p.part = pr.sub_part
)
DELETE FROM parts
WHERE part IN (SELECT part FROM included_parts);
The sub-statements in a WITH
clause are run concurrently with each other and with the main query. Therefore, when using a data-modifying statement in a WITH
, the order in which the specified updates actually happen is unpredictable. All of the statements are run wth the same snapshot. The effects of the statement are not visible on the target tables. This alleviates the effects of the unpredictability of the actual order of row updates, and means thats the RETURNING
data is the only way to communicate changes between different WITH
sub-statements and the main query.
In this example, the outer SELECT
returns the original prices before the action of the UPDATE
in the WITH
clause:
WITH t AS (
UPDATE products SET price = price * 1.05
RETURNING *
)
SELECT * FROM products;
In this example, the outer SELECT
returns the updated data:
WITH t AS (
UPDATE products SET price = price * 1.05
RETURNING *
)
SELECT * FROM t;
Updating the same row twice in a single statement is not supported. The effects of such a statement will not be predictable. Only one of the modifications takes place, but it is not easy (and sometimes not possible) to predict which modification occurs.
Any table used as the target of a data-modifying statement in a WITH
clause must not have a conditional rule, nor an ALSO
rule, nor an INSTEAD
rule that expands to multiple statements.
When constructing WITH
queries, keep the following in mind:
SELECT FOR UPDATE
cannot be inlined.
Greenplum Database inlines multiply-referenced CTEs only when requested (by specifying NOT MATERIALIZED
).
Multiply-referenced CTEs cannot be inlined if they contain outer self-references.
Greenplum Database does not inline when the CTE includes a volatile function.
An ORDER BY
in the subquery or CTE does not force an ordering for the whole query.
Greenplum Database always materializes a CTE term in a query. Due to this:
UPDATE
or DELETE FROM
statements are not permitted in a CTE term, as it acts more like a read-only temporary table than a dynamic view.While inlining is generally a huge win, there are certain boundary cases where it is not; for example, when a non-trivial expression will be inlined in multiple places.
The GPORCA query optimizer does not support [NOT] MATERIALIZED
.