SELECT
Retrieves rows from a table or view.
Synopsis
[ WITH [ RECURSIVE ] <with_query> [, ...] ]
SELECT [ALL | DISTINCT [ON (<expression> [, ...])]]
[* | <expression> [[AS] <output_name>] [, ...]]
[FROM <from_item> [, ...]]
[WHERE <condition>]
[GROUP BY <grouping_element> [, ...]]
[HAVING <condition> [, ...]]
[WINDOW <window_name> AS (<window_definition>) [, ...] ]
[{UNION | INTERSECT | EXCEPT} [ALL | DISTINCT] <select>]
[ORDER BY <expression> [ASC | DESC | USING <operator>] [NULLS {FIRST | LAST}] [, ...]]
[LIMIT {<count> | ALL}]
[OFFSET <start> [ ROW | ROWS ] ]
[FETCH { FIRST | NEXT } [ <count> ] { ROW | ROWS } ONLY]
[FOR {UPDATE | NO KEY UPDATE | SHARE | KEY SHARE} [OF <table_name> [, ...]] [NOWAIT | SKIP LOCKED ] [...]]
-- where <from_item> can be one of:
[ONLY] <table_name> [ * ] [ [ AS ] <alias> [ ( <column_alias> [, ...] ) ] ]
[ TABLESAMPLE <sampling_method> ( <argument> [, ...] ) [ REPEATABLE ( <seed> ) ] ]
[LATERAL] ( <select> ) [ AS ] <alias> [( <column_alias> [, ...] ) ]
<with_query_name> [ [ AS ] <alias> [ ( <column_alias> [, ...] ) ] ]
[LATERAL] <function_name> ( [ <argument> [, ...] ] )
[ WITH ORDINALITY ] [ [ AS ] <alias> [ ( <column_alias> [, ...] ) ] ]
[LATERAL] <function_name> ( [ <argument> [, ...] ] ) [ AS ] <alias> ( <column_definition> [, ...] )
[LATERAL] <function_name> ( [ <argument> [, ...] ] ) AS ( <column_definition> [, ...] )
[LATERAL] ROWS FROM( <function_name> ( [ <argument> [, ...] ] ) [ AS ( <column_definition> [, ...] ) ] [, ...] )
[ WITH ORDINALITY ] [ [ AS ] <alias> [ ( <column_alias> [, ...] ) ] ]
<from_item> <join_type> <from_item> { ON <join_condition> | USING ( <join_column> [, ...] ) }
<from_item> NATURAL <join_type> <from_item>
<from_item> CROSS JOIN <from_item>
-- where <grouping_element> can be one of:
()
<expression>
ROLLUP (<expression> [,...])
CUBE (<expression> [,...])
GROUPING SETS (<grouping_element> [, ...])
-- where <with_query> is:
<with_query_name> [( <column_name> [, ...] )] AS ( [ NOT ] MATERIALIZED ] ( <select> | <values> | <insert> | <update> | delete )
TABLE [ ONLY ] <table_name> [ * ]
Description
SELECT
retrieves rows from zero or more tables. The general processing of SELECT
is as follows:
- All queries in the
WITH
clause are computed. These effectively serve as temporary tables that can be referenced in theFROM
list. AWITH
query that is referenced more than once inFROM
is computed only once, unless specified otherwise withNOT MATERIALIZED
. (See WITH Clause below.) - All elements in the
FROM
list are computed. (Each element in theFROM
list is a real or virtual table.) If more than one element is specified in theFROM
list, they are cross-joined together. (See FROM Clause below.) - If the
WHERE
clause is specified, all rows that do not satisfy the condition are eliminated from the output. (See WHERE Clause below.) - If the
GROUP BY
clause is specified, or if there are aggregate function calls, the output is combined into groups of rows that match on one or more values, and the results of aggregate functions are computed. If theHAVING
clause is present, it eliminates groups that do not satisfy the given condition. (See GROUP BY Clause and HAVING Clause below.) - The actual output rows are computed using the
SELECT
output expressions for each selected row or row group. (See SELECT List below.) SELECT DISTINCT
eliminates duplicate rows from the result.SELECT DISTINCT ON
eliminates rows that match on all the specified expressions.SELECT ALL
(the default) will return all candidate rows, including duplicates. (See DISTINCT Clause below.)- If a window expression is specified (and optional
WINDOW
clause), the output is organized according to the positional (row) or value-based (range) window frame. (See WINDOW Clause below.) - Using the operators
UNION
,INTERSECT
, andEXCEPT
, the output of more than oneSELECT
statement can be combined to form a single result set. TheUNION
operator returns all rows that are in one or both of the result sets. TheINTERSECT
operator returns all rows that are strictly in both result sets. TheEXCEPT
operator returns the rows that are in the first result set but not in the second. In all three cases, duplicate rows are eliminated unlessALL
is specified. The noise wordDISTINCT
can be added to explicitly specify eliminating duplicate rows. Notice thatDISTINCT
is the default behavior here, even thoughALL
is the default forSELECT
itself. (See UNION Clause, INTERSECT Clause, and EXCEPT Clause below.) - If the
ORDER BY
clause is specified, the returned rows are sorted in the specified order. IfORDER BY
is not given, the rows are returned in whatever order the system finds fastest to produce. (See ORDER BY Clause below.) - If the
LIMIT
(orFETCH FIRST
) orOFFSET
clause is specified, theSELECT
command only returns a subset of the result rows. (See LIMIT Clause below.) - If
FOR UPDATE
,FOR NO KEY UPDATE
,FOR SHARE
, orFOR KEY SHARE
is specified, theSELECT
command locks the entire table against concurrent updates when the Global Deadlock Detector is deactivated (the default). When the Global Deadlock Detector is activated, it affects some simpleSELECT
statements that contain a locking clause. (See The Locking Clause below.)
You must have SELECT
privilege on each column used in a SELECT
command. The use of FOR NO KEY UPDATE
, FOR UPDATE
, FOR SHARE
, or FOR KEY SHARE
requires UPDATE
privilege as well (for at least one column of each table so selected).
Parameters
The WITH
clause
The WITH
clause allows you to specify one or more subqueries that can be referenced by name in the primary query. The subqueries effectively act as temporary tables or views for the duration of the primary query. Each subquery can be a SELECT
, TABLE
, VALUES
, INSERT
, UPDATE
, or DELETE
statement. When writing a data-modifying statement (INSERT
, UPDATE
, or DELETE
) in WITH
, it is usual to include a RETURNING
clause. It is the output of RETURNING
, not the underlying table that the statement modifies, that forms the temporary table that is read by the primary query. If RETURNING
is omitted, the statement is still run, but it produces no output so it cannot be referenced as a table by the primary query.
For a SELECT
command that includes a WITH
clause, the clause can contain at most a single clause that modifies table data (INSERT
, UPDATE
, or DELETE
command).
A name (without schema qualification) must be specified for each WITH
query. Optionally, you can specify a list of column names; if this is omitted, the names are inferred from the subquery.
If RECURSIVE
is specified, it allows a SELECT
subquery to reference itself by name. Such a subquery must have the form:
<non_recursive_term> UNION [ALL | DISTINCT] <recursive_term>
where the recursive self-reference appears on the right-hand side of the UNION
. Only one recursive self-reference is permitted per query. Recursive data-modifying statements are not supported, but you can use the results of a recursive SELECT
query in a data-modifying statement.
If the RECURSIVE
keyword is specified, the WITH
queries need not be ordered: a query can reference another query that is later in the list. However, circular references, or mutual recursion, are not supported. Without the RECURSIVE
keyword, WITH
queries can reference only sibling WITH
queries that are earlier in the WITH
list.
When there are multiple queries in the WITH
clause, RECURSIVE
should be written only once, immediately after WITH
. It applies to all queries in the WITH
clause, though it has no effect on queries that do not use recursion or forward references.
WITH RECURSIVE
limitations. These items are not supported:
- A recursive
WITH
clause that contains the following in the<recursive_term>
.- Subqueries with a self-reference
DISTINCT
clauseGROUP BY
clause- A window function
- A recursive
WITH
clause where the<with_query_name>
is a part of a set operation.
Following is an example of the set operation limitation. This query returns an error because the set operation UNION
contains a reference to the table foo
.
WITH RECURSIVE foo(i) AS (
SELECT 1
UNION ALL
SELECT i+1 FROM (SELECT * FROM foo UNION SELECT 0) bar
)
SELECT * FROM foo LIMIT 5;
This recursive CTE is allowed because the set operation UNION
does not have a reference to the CTE foo
.
WITH RECURSIVE foo(i) AS (
SELECT 1
UNION ALL
SELECT i+1 FROM (SELECT * FROM bar UNION SELECT 0) bar, foo
WHERE foo.i = bar.a
)
SELECT * FROM foo LIMIT 5;
The primary query and the WITH
queries are all (notionally) run at the same time. This implies that the effects of a data-modifying statement in WITH
cannot be seen from other parts of the query, other than by reading its RETURNING
output. If two such data-modifying statements attempt to modify the same row, the results are unspecified.
A key property of WITH
queries is that they are evaluated only once per execution of the primary query, even if the primary query refers to them more than once. In particular, data-modifying statements are guaranteed to be run once and only once, regardless of whether the primary query reads all or any of their output.
However, a WITH
query can be marked NOT MATERIALIZED
to remove this guarantee. In that case, the WITH
query can be folded into the primary query much as though it were a simple sub-SELECT
in the primary query's FROM
clause. This results in duplicate computations if the primary query refers to that WITH
query more than once; but if each such use requires only a few rows of the WITH
query's total output, NOT MATERIALIZED
can provide a net savings by allowing the queries to be optimized jointly. NOT MATERIALIZED
is ignored if it is attached to a WITH
query that is recursive or is not side-effect-free (for example, is not a plain SELECT
containing no volatile functions).
By default, a side-effect-free WITH
query is folded into the primary query if it is used exactly once in the primary query's FROM
clause. This allows joint optimization of the two query levels in situations where that should be semantically invisible. However, such folding can be prevented by marking the WITH
query as MATERIALIZED
. That might be useful, for example, if the WITH
query is being used as an optimization fence to prevent the planner from choosing a bad plan. Apache Cloudberry versions before 7 never did such folding, so queries written for older versions might rely on WITH
to act as an optimization fence.
See WITH Queries (Common Table Expressions) in the Apache Cloudberry Administrator Guide for additional information.
The FROM
clause
The FROM
clause specifies one or more source tables for the SELECT
. If multiple sources are specified, the result is the Cartesian product (cross join) of all the sources. But usually qualification conditions are added (via WHERE
) to restrict the returned rows to a small subset of the Cartesian product.
The FROM
clause can contain the following elements:
table_name
The name (optionally schema-qualified) of an existing table or view. If ONLY
is specified before the table name, only that table is scanned. If ONLY
is not specified, the table and all of its descendant tables (if any) are scanned. Optionally, you can specify *
after the table name to explicitly indicate that descendant tables are included.
alias
A substitute name for the FROM
item containing the alias. An alias is used for brevity or to eliminate ambiguity for self-joins (where the same table is scanned multiple times). When you provide an alias, it completely hides the actual name of the table or function; for example given FROM foo AS f
, the remainder of the SELECT
must refer to this FROM
item as f
not foo
. If you specify an alias, you can also specify a column alias list to provide substitute names for one or more columns of the table.
TABLESAMPLE sampling_method ( argument [, ...] ) [ REPEATABLE ( seed ) ]
A TABLESAMPLE
clause after a table_name indicates that the specified sampling_method should be used to retrieve a subset of the rows in that table. This sampling precedes the application of any other filters such as WHERE
clauses. The standard Apache Cloudberry distribution includes two sampling methods, BERNOULLI
and SYSTEM
. You can install other sampling methods in the database via extensions.
The BERNOULLI
and SYSTEM
sampling methods each accept a single argument which is the fraction of the table to sample, expressed as a percentage between 0 and 100. This argument can be any real-valued expression. (Other sampling methods might accept more or different arguments.) These two methods each return a randomly-chosen sample of the table that will contain approximately the specified percentage of the table's rows. The BERNOULLI
method scans the whole table and selects or ignores individual rows independently with the specified probability. The SYSTEM
method does block-level sampling with each block having the specified chance of being selected; all rows in each selected block are returned. The SYSTEM
method is significantly faster than the BERNOULLI
method when small sampling percentages are specified, but it may return a less-random sample of the table as a result of clustering effects.
The optional REPEATABLE
clause specifies a seed number or expression to use for generating random numbers within the sampling method. The seed value can be any non-null floating-point value. Two queries that specify the same seed and argument values will select the same sample of the table, if the table has not been changed meanwhile. But different seed values usually produce different samples. If REPEATABLE
is not specified, then Apache Cloudberry selects a new random sample for each query, based upon a system-generated seed. Note that some add-on sampling methods do not accept REPEATABLE
, and will always produce new samples on each use.
select
A sub-SELECT
can appear in the FROM
clause. This acts as though its output were created as a temporary table for the duration of this single SELECT
command. Note that the sub-SELECT
must be surrounded by parentheses, and an alias must be provided for it. A VALUES command can also be used here. See "Non-standard Clauses" in the Compatibility section for limitations of using correlated sub-selects in Apache Cloudberry.
with_query_name
A WITH
query is referenced in the FROM
clause by specifying its name, just as though the name were a table name. You can provide an alias in the same way as for a table.
The WITH
query hides a table of the same name for the purposes of the primary query. If necessary, you can refer to a table of the same name by schema-qualifying the table's name.
function_name
Function calls can appear in the FROM
clause. (This is especially useful for functions that return result sets, but any function can be used.) This acts as though the function's output were created as a temporary table for the duration of this single SELECT
command. When you add the optional WITH ORDINALITY
clause to the function call, Apache Cloudberry appends a new column after all of the function's output columns with numbering for each row.
You can provide an alias in the same way as for a table. If an alias is specified, you can also specify a column alias list to provide substitute names for one or more attributes of the function's composite return type, including the column added by ORDINALITY
if present.
You can combine multiple function calls into a single FROM
-clause item by surrounding them with ROWS FROM( ... )
. The output of such an item is the concatenation of the first row from each function, then the second row from each function, etc. If some of the functions produce fewer rows than others, null values are substituted for the missing data, so that the total number of rows returned is always the same as for the function that produced the most rows.
If the function has been defined as returning the record
data type, then an alias or the key word AS
must be present, followed by a column definition list in the form ( <column_name> <data_type> [, ... ] )
. The column definition list must match the actual number and types of columns returned by the function.
When using the ROWS FROM( ... )
syntax, if one of the functions requires a column definition list, it's preferred to put the column definition list after the function call inside ROWS FROM( ... )
. A column definition list can be placed after the ROWS FROM( ... )
construct only if there's just a single function and no WITH ORDINALITY
clause.
To use ORDINALITY
together with a column definition list, you must use the ROWS FROM( ... )
syntax and put the column definition list inside ROWS FROM( ... )
.
join_type
One of:
[INNER] JOIN
LEFT [OUTER] JOIN
RIGHT [OUTER] JOIN
FULL [OUTER] JOIN
For the INNER
and OUTER
join types, you must specify a join condition, namely exactly one of NATURAL
, ON <join_condition>
, or USING ( <join_column> [, ...])
. Continue reading for the meaning.
A JOIN clause combines two FROM
items, which for convenience are referred to as "tables", though in reality they can be any type of FROM
item. Use parentheses if necessary to determine the order of nesting. In the absence of parentheses, JOIN
s nest left-to-right. JOIN
binds more tightly than the commas separating FROM
-list items. All of the JOIN
options are a notational convenience; they do nothing that cannot be achieved with plain FROM
and WHERE
.
LEFT OUTER JOIN
returns all rows in the qualified Cartesian product (i.e., all combined rows that pass its join condition), plus one copy of each row in the left-hand table for which there was no right-hand row that passed the join condition. This left-hand row is extended to the full width of the joined table by inserting null values for the right-hand columns. Note that only the JOIN
clause's own condition is considered while deciding which rows have matches. Outer conditions are applied afterwards.
Conversely, RIGHT OUTER JOIN
returns all the joined rows, plus one row for each unmatched right-hand row (extended with nulls on the left). This is just a notational convenience, since you could convert it to a LEFT OUTER JOIN
by switching the left and right tables.
FULL OUTER JOIN
returns all the joined rows, plus one row for each unmatched left-hand row (extended with nulls on the right), plus one row for each unmatched right-hand row (extended with nulls on the left).
ON join_condition
join_condition is an expression resulting in a value of type boolean
(similar to a WHERE
clause) that specifies which rows in a join are considered to match.
USING (join_column [, ...])
A clause of the form USING ( a, b, ... )
is shorthand for ON left_table.a = right_table.a AND left_table.b = right_table.b ...
. Also, USING
implies that only one of each pair of equivalent columns will be included in the join output, not both.
NATURAL
NATURAL
is shorthand for a USING
list that mentions all columns in the two tables that have the same names. If there are no common column names, NATURAL
is equivalent to ON TRUE
.
CROSS JOIN
CROSS JOIN
is equivalent to INNER JOIN ON (TRUE)
, that is, no rows are removed by qualification. They produce a simple Cartesian product, the same result as you get from listing the two tables at the top level of FROM
, but restricted by the join condition (if any).
LATERAL
The LATERAL
key word can precede a sub-SELECT FROM
item. This allows the sub-SELECT
to refer to columns of FROM
items that appear before it in the FROM
list. (Without LATERAL
, Apache Cloudberry evaluates each sub-SELECT
independently and so cannot cross-reference any other FROM
item.)
LATERAL
can also precede a function-call FROM
item. In this case it is a noise word, because the function expression can refer to earlier FROM
items.
A LATERAL
item can appear at top level in the FROM
list, or within a JOIN
tree. In the latter case it can also refer to any items that are on the left-hand side of a JOIN
that it is on the right-hand side of.
When a FROM
item contains LATERAL
cross-references, evaluation proceeds as follows: for each row of the FROM
item providing the cross-referenced column(s), or set of rows of multiple FROM
items providing the columns, the LATERAL
item is evaluated using that row or row set's values of the columns. The resulting row(s) are joined as usual with the rows they were computed from. This is repeated for each row or set of rows from the column source table(s).
The column source table(s) must be INNER
or LEFT
joined to the LATERAL
item, else there would not be a well-defined set of rows from which to compute each set of rows for the LATERAL
item. Thus, although a construct such as <X> RIGHT JOIN LATERAL <Y>
is syntactically valid, Apache Cloudberry does not permit <Y>
to reference <X>
.
The WHERE
clause
The optional WHERE
clause has the general form:
WHERE <condition>
where condition is any expression that evaluates to a result of type boolean
. Any row that does not satisfy this condition will be eliminated from the output. A row satisfies the condition if it returns true when the actual row values are substituted for any variable references.
The GROUP BY
clause
The optional GROUP BY
clause has the general form:
GROUP BY <grouping_element> [, ...]