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. Cloudberry Database 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 Cloudberry Database 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 Cloudberry Database 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 Cloudberry Database 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 Cloudberry Database.
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, Cloudberry Database 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
, Cloudberry Database 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, Cloudberry Database 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> [, ...]
where <grouping_element>
can be one of:
()
<expression>
ROLLUP (<expression> [,...])
CUBE (<expression> [,...])
GROUPING SETS ((<grouping_element> [, ...]))
GROUP BY
condenses into a single row all selected rows that share the same values for the grouped expressions. An expression used inside a grouping_element can be an input column name, or the name or ordinal number of an output column (SELECT
list item), or an arbitrary expression formed from input-column values. In case of ambiguity, a GROUP BY
name will be interpreted as an input-column name rather than an output column name.
If any of GROUPING SETS
, ROLLUP
, or CUBE
are present as grouping elements, then the GROUP BY
clause as a whole defines some number of independent grouping sets. The effect of this is equivalent to constructing a UNION ALL
between subqueries with the individual grouping sets as their GROUP BY
clauses. For further details on the handling of grouping sets, refer to GROUPING SETS, CUBE, and ROLLUP in the PostgreSQL documentation.
Aggregate functions, if any are used, are computed across all rows making up each group, producing a separate value for each group. (If there are aggregate functions but no GROUP BY
clause, the query is treated as having a single group comprising all of the selected rows.) You can further filter the set of rows fed to each aggregate function by attaching a FILTER
clause to the aggregate function call. When a FILTER
clause is present, only those rows matching it are included in the input to that aggregate function.
When GROUP BY
is present, or any aggregate functions are present, it is not valid for the SELECT
list expressions to refer to ungrouped columns except within aggregate functions or when the ungrouped column is functionally dependent on the grouped columns, since there would otherwise be more than one possible value to return for an ungrouped column. A functional dependency exists if the grouped columns (or a subset thereof) are the primary key of the table containing the ungrouped column.
Keep in mind that all aggregate functions are evaluated before evaluating any "scalar" expressions in the HAVING
clause or SELECT
list. This means that, for example, a CASE
expression cannot be used to skip evaluation of an aggregate function.
Currently, FOR NO KEY UPDATE
, FOR UPDATE
, FOR SHARE
, and FOR KEY SHARE
cannot be specified with GROUP BY
.
Cloudberry Database has the following additional OLAP grouping extensions (often referred to as supergroups):
ROLLUP
A ROLLUP
grouping is an extension to the GROUP BY
clause that creates aggregate subtotals that roll up from the most detailed level to a grand total, following a list of grouping columns (or expressions). ROLLUP
takes an ordered list of grouping columns, calculates the standard aggregate values specified in the GROUP BY
clause, then creates progressively higher-level subtotals, moving from right to left through the list. Finally, it creates a grand total. A ROLLUP
grouping can be thought of as a series of grouping sets. For example:
GROUP BY ROLLUP (a,b,c)
is equivalent to:
GROUP BY GROUPING SETS( (a,b,c), (a,b), (a), () )
Notice that the n elements of a ROLLUP
translate to n+1 grouping sets. Also, the order in which the grouping expressions are specified is significant in a ROLLUP
.
CUBE
A CUBE
grouping is an extension to the GROUP BY
clause that creates subtotals for all of the possible combinations of the given list of grouping columns (or expressions). In terms of multidimensional analysis, CUBE
generates all the subtotals that could be calculated for a data cube with the specified dimensions. For example:
GROUP BY CUBE (a,b,c)
is equivalent to:
GROUP BY GROUPING SETS( (a,b,c), (a,b), (a,c), (b,c), (a),
(b), (c), () )
Notice that n elements of a CUBE
translate to 2n grouping sets. Consider using CUBE
in any situation requiring cross-tabular reports. CUBE
is typically most suitable in queries that use columns from multiple dimensions rather than columns representing different levels of a single dimension. For instance, a commonly requested cross-tabulation might need subtotals for all the combinations of month, state, and product.
GROUPING SETS
You can selectively specify the set of groups that you want to create using a GROUPING SETS
expression within a GROUP BY
clause. This allows precise specification across multiple dimensions without computing a whole ROLLUP
or CUBE
. For example:
GROUP BY GROUPING SETS( (a,c), (a,b) )
If using the grouping extension clauses ROLLUP
, CUBE
, or GROUPING SETS
, two challenges arise. First, how do you determine which result rows are subtotals, and then the exact level of aggregation for a given subtotal. Or, how do you differentiate between result rows that contain both stored NULL
values and "NULL" values created by the ROLLUP
or CUBE
. Secondly, when duplicate grouping sets are specified in the GROUP BY
clause, how do you determine which result rows are duplicates? There are two additional grouping functions you can use in the SELECT
list to help with this:
-
grouping(column [, ...]) — The
grouping
function can be applied to one or more grouping attributes to distinguish super-aggregated rows from regular grouped rows. This can be helpful in distinguishing a "NULL" representing the set of all values in a super-aggregated row from aNULL
value in a regular row. Each argument in this function produces a bit — either1
or0
, where1
means the result row is super-aggregated, and0
means the result row is from a regular grouping. Thegrouping
function returns an integer by treating these bits as a binary number and then converting it to a base-10 integer. -
group_id() — For grouping extension queries that contain duplicate grouping sets, the
group_id
function is used to identify duplicate rows in the output. All unique grouping set output rows will have a<group_id>
value of 0. For each duplicate grouping set detected, thegroup_id
function assigns a<group_id>
number greater than 0. All output rows in a particular duplicate grouping set are identified by the same<group_id>
number.
The HAVING
clause
The optional HAVING
clause has the general form:
HAVING <condition>
where <condition>
is the same as specified for the WHERE
clause.
HAVING
eliminates group rows that do not satisfy the condition. HAVING
is different from WHERE
: WHERE
filters individual rows before the application of GROUP BY
, while HAVING
filters group rows created by GROUP BY
. Each column referenced in <condition>
must unambiguously reference a grouping column, unless the reference appears within an aggregate function or the ungrouped column is functionally dependent on the grouping columns.
The presence of HAVING
turns a query into a grouped query even if there is no GROUP BY
clause. This is the same as what happens when the query contains aggregate functions but no GROUP BY
clause. All of the selected rows are considered to form a single group, and the SELECT
list and HAVING
clause can only reference table columns from within aggregate functions. Such a query will emit a single row if the HAVING
condition is true, zero rows if it is not true.
Currently, FOR NO KEY UPDATE
, FOR UPDATE
, FOR SHARE
, and FOR KEY SHARE
cannot be specified with HAVING
.
The WINDOW
clause
The optional WINDOW
clause specifies the behavior of window functions appearing in the query's SELECT
list or ORDER BY
clause. The WINDOW
clause has the general form:
WINDOW <window_name> AS ( <window_definition> ) [, ...]
where <window_name>
is a name that can be referenced from OVER
clauses or subsequent window definitions, and <window_definition>
is:
[<existing_window_name>]
[PARTITION BY <expression> [, ...]]
[ORDER BY <expression> [ASC | DESC | USING <operator>] [NULLS {FIRST | LAST}] [, ...] ]
[<frame_clause>]
A WINDOW
clause entry does not have to be referenced anywhere, however; if it is not used in the query it is simply ignored. It is possible to use window functions without any WINDOW
clause at all, since a window function call can specify its window definition directly in its OVER
clause. However, the WINDOW
clause saves typing when the same window definition is needed for more than one window function.
For example:
SELECT vendor, rank() OVER (mywindow) FROM sale
GROUP BY vendor
WINDOW mywindow AS (ORDER BY sum(prc*qty));
existing_window_name
If an existing_window_name is specified, it must refer to an earlier entry in the WINDOW
list; the new window copies its partitioning clause from that entry, as well as its ordering clause if any. The new window cannot specify its own PARTITION BY
clause, and it can specify ORDER BY
only if the copied window does not have one. The new window always uses its own frame clause; the copied window must not specify a frame clause.
PARTITION BY
The PARTITION BY
clause organizes the result set into logical groups based on the unique values of the specified expression. The elements of the PARTITION BY
clause are interpreted in much the same fashion as elements of a GROUP BY Clause, except that they are always simple expressions and never the name or number of an output column. Another difference is that these expressions can contain aggregate function calls, which are not allowed in a regular GROUP BY
clause. They are allowed here because windowing occurs after grouping and aggregation. When used with window functions, the functions are applied to each partition independently. For example, if you follow PARTITION BY
with a column name, the result set is partitioned by the distinct values of that column. If omitted, the entire result set is considered one partition.
ORDER BY
Similarly, the elements of the ORDER BY
list are interpreted in much the same fashion as elements of an ORDER BY Clause, except that the expressions are always taken as simple expressions and never the name or number of an output column.
Note The elements of the
ORDER BY
clause define how to sort the rows in each partition of the result set. If omitted, rows are returned in whatever order is most efficient and may vary.
frame_clause
The optional frame_clause defines the window frame for window functions that depend on the frame (not all do). The window frame is a set of related rows for each row of the query (called the current row). The frame_clause can be one of
{ RANGE | ROWS | GROUPS } <frame_start> [ <frame_exclusion> ]
{ RANGE | ROWS | GROUPS } BETWEEN <frame_start> AND <frame_end> [ <frame_exclusion> ]
where <frame_start>
and <frame_end>
can be one of
UNBOUNDED PRECEDING
<offset> PRECEDING
CURRENT ROW
<offset> FOLLOWING
UNBOUNDED FOLLOWING
and <frame_exclusion>
can be one of
EXCLUDE CURRENT ROW
EXCLUDE GROUP
EXCLUDE TIES
EXCLUDE NO OTHERS
If <frame_end>
is omitted it defaults to CURRENT ROW
. Restrictions are that <frame_start>
cannot be UNBOUNDED FOLLOWING
, <frame_end>
cannot be UNBOUNDED PRECEDING
, and the <frame_end>
choice cannot appear earlier in the above list of <frame_start>
and <frame_end>
options than the <frame_start>
choice does — for example RANGE BETWEEN CURRENT ROW AND <offset> PRECEDING
is not allowed.
The default framing option is RANGE UNBOUNDED PRECEDING
, which is the same as RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW
; it sets the frame to be all rows from the partition start up through the current row's last peer (a row that the window's ORDER BY
clause considers equivalent to the current row; all rows are peers if there is no ORDER BY
). In general, UNBOUNDED PRECEDING
means that the frame starts with the first row of the partition, and similarly UNBOUNDED FOLLOWING
means that the frame ends with the last row of the partition, regardless of RANGE
, ROWS
or GROUPS
mode. In ROWS
mode, CURRENT ROW
means that the frame starts or ends with the current row; but in RANGE
or GROUPS
mode it means that the frame starts or ends with the current row's first or last peer in the ORDER BY
ordering. The <offset> PRECEDING
and <offset> FOLLOWING
options vary in meaning depending on the frame mode. In ROWS
mode, the <offset>
is an integer indicating that the frame starts or ends that many rows before or after the current row.
In GROUPS
mode, the <offset>
is an integer indicating that the frame starts or ends that many peer groups before or after the current row's peer group, where a peer group is a group of rows that are equivalent according to the window's ORDER BY
clause. In RANGE
mode, use of an <offset>
option requires that there be exactly one ORDER BY
column in the window definition. Then the frame contains those rows whose ordering column value is no more than <offset>
less than (for PRECEDING
) or more than (for FOLLOWING
) the current row's ordering column value. In these cases the data type of the <offset>
expression depends on the data type of the ordering column. For numeric ordering columns it is typically of the same type as the ordering column, but for datetime ordering columns it is an interval
. In all these cases, the value of the <offset>
must be non-null and non-negative. Also, while the offset does not have to be a simple constant, it cannot contain variables, aggregate functions, or window functions.
The <frame_exclusion>
option allows rows around the current row to be excluded from the frame, even if they would be included according to the frame start and frame end options. EXCLUDE CURRENT ROW
excludes the current row from the frame. EXCLUDE GROUP
excludes the current row and its ordering peers from the frame. EXCLUDE TIES
excludes any peers of the current row from the frame, but not the current row itself. EXCLUDE NO OTHERS
simply specifies explicitly the default behavior of not excluding the current row or its peers.
Beware that the ROWS
mode can produce unpredictable results if the ORDER BY
ordering does not order the rows uniquely. The RANGE
and GROUPS
modes are designed to ensure that rows that are peers in the ORDER BY
ordering are treated alike: all rows of a given peer group will be in the frame or excluded from it.
Use either a ROWS
, RANGE
, or GROUPS
clause to express the bounds of the window. The window bound can be one, many, or all rows of a partition. You can express the bound of the window either in terms of a range of data values offset from the value in the current row (RANGE
), in terms of the number of rows offset from the current row (ROWS
), or in terms of the number of peer groups (GROUPS
). When using the RANGE
or the GROUPS
clause, you must also use an ORDER BY
clause. This is because the calculation performed to produce the window requires that the values be sorted. Additionally, the ORDER BY
clause cannot contain more than one expression, and the expression must result in either a date or a numeric value. When using the ROWS
, RANGE
or GROUPS
clauses, if you specify only a starting row, the current row is used as the last row in the window.
PRECEDING — The PRECEDING
clause defines the first row of the window using the current row as a reference point. The starting row is expressed in terms of the number of rows preceding the current row. For example, in the case of ROWS
framing, 5 PRECEDING
sets the window to start with the fifth row preceding the current row. In the case of RANGE
framing, it sets the window to start with the first row whose ordering column value precedes that of the current row by 5 in the given order. If the specified order is ascending by date, this will be the first row within 5 days before the current row. UNBOUNDED PRECEDING
sets the first row in the window to be the first row in the partition.
BETWEEN — The BETWEEN
clause defines the first and last row of the window, using the current row as a reference point. First and last rows are expressed in terms of the number of rows preceding and following the current row, respectively. For example, BETWEEN 3 PRECEDING AND 5 FOLLOWING
sets the window to start with the third row preceding the current row, and end with the fifth row following the current row. Use BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
to set the first and last rows in the window to be the first and last row in the partition, respectively. This is equivalent to the default behavior if no ROWs
, RANGE
or GROUPS
clause is specified.
FOLLOWING — The FOLLOWING
clause defines the last row of the window using the current row as a reference point. The last row is expressed in terms of the number of rows following the current row. For example, in the case of ROWS
framing, 5 FOLLOWING
sets the window to end with the fifth row following the current row. In the case of RANGE
framing, it sets the window to end with the last row whose ordering column value follows that of the current row by 5 in the given order. If the specified order is ascending by date, this will be the last row within 5 days after the current row. Use UNBOUNDED FOLLOWING
to set the last row in the window to be the last row in the partition.
If you do not specify a ROWS
, a RANGE
or a GROUPS
clause, the window bound starts with the first row in the partition (UNBOUNDED PRECEDING
) and ends with the current row (CURRENT ROW
) if ORDER BY
is used. If an ORDER BY
is not specified, the window starts with the first row in the partition (UNBOUNDED PRECEDING
) and ends with last row in the partition (UNBOUNDED FOLLOWING
).
The purpose of a WINDOW
clause is to specify the behavior of window functions appearing in the query's SELECT List or ORDER BY Clause. These functions can reference the WINDOW
clause entries by name in their OVER
clauses. A WINDOW
clause entry does not have to be referenced anywhere, however; if it is not used in the query it is simply ignored. It is possible to use window functions without any WINDOW
clause at all, since a window function call can specify its window definition directly in its OVER
clause. However, the WINDOW
clause saves typing when the same window definition is needed for more than one window function.
Currently, FOR NO KEY UPDATE
, FOR UPDATE
, FOR SHARE
, and FOR KEY SHARE
cannot be specified with WINDOW
.
The SELECT
list
The SELECT
list (between the key words SELECT
and FROM
) specifies expressions that form the output rows of the SELECT
statement. The expressions can (and usually do) refer to columns computed in the FROM
clause.
An expression in the SELECT
list can be a constant value, a column reference, an operator invocation, a function call, an aggregate expression, a window expression, a scalar subquery, and so on. A number of constructs can be classified as an expression but do not follow any general syntax rules. These generally have the semantics of a function or operator. For information about SQL value expressions and function calls, see Querying Data in the Cloudberry Database Administrator Guide.
Just as in a table, every output column of a SELECT
has a name. In a simple SELECT
this name is just used to label the column for display, but when the SELECT
is a sub-query of a larger query, the name is seen by the larger query as the column name of the virtual table produced by the sub-query. To specify the name to use for an output column, write AS <output_name>
after the column's expression. (You can omit AS
, but only if the desired output name does not match any SQL keyword. For protection against possible future keyword additions, you can always either write AS
or double-quote the output name.) If you do not specify a column name, Cloudberry Database chooses a name automatically. If the column's expression is a simple column reference then the chosen name is the same as that column's name. In more complex cases, a function or type name may be used, or the system may fall back on a generated name such as ?column?
or columnN
.
An output column's name can be used to refer to the column's value in ORDER BY
and GROUP BY
clauses, but not in the WHERE
or HAVING
clauses; there you must specify the expression instead.
Instead of an expression, you can specify *
in the output list as a shorthand for all the columns of the selected rows. Also, you can specify <table_name>.*
as a shorthand for the columns coming from just that table. In these cases it is not possible to specify new names with AS
; the output column names will be the same as the table columns' names.
According to the SQL standard, the expressions in the output list should be computed before applying DISTINCT
, ORDER BY
, or LIMIT
. This is obviously necessary when using DISTINCT
, since otherwise it's not clear what values are being made distinct. However, in many cases it is convenient if output expressions are computed after ORDER BY
and LIMIT
; particularly if the output list contains any volatile or expensive functions. With that behavior, the order of function evaluations is more intuitive and there will not be evaluations corresponding to rows that never appear in the output. Cloudberry Database effectively evaluates output expressions after sorting and limiting, so long as those expressions are not referenced in DISTINCT
, ORDER BY
, or GROUP BY
. (As a counterexample, SELECT f(x) FROM tab ORDER BY 1
clearly must evaluate f(x)
before sorting.) Output expressions that contain set-returning functions are effectively evaluated after sorting and before limiting, so that LIMIT
will act to cut off the output from a set-returning function.
Note Cloudberry Database versions prior to 7 did not provide any guarantees about the timing of evaluation of output expressions versus sorting and limiting; it depended on the form of the chosen query plan.
The DISTINCT
clause
If SELECT DISTINCT
is specified, all duplicate rows are removed from the result set (one row is kept from each group of duplicates). SELECT ALL
specifies the opposite: all rows are kept; that is the default.
SELECT DISTINCT ON ( <expression> [, ...] )
keeps only the first row of each set of rows where the given expressions evaluate to equal. The DISTINCT ON
expressions are interpreted using the same rules as for ORDER BY
(see above). Note that the "first row" of each set is unpredictable unless ORDER BY
is used to ensure that the desired row appears first. For example:
SELECT DISTINCT ON (location) location, time, report
FROM weather_reports
ORDER BY location, time DESC;
retrieves the most recent weather report for each location. But if we had not used ORDER BY
to force descending order of time values for each location, we'd have gotten a report from an unpredictable time for each location.
The DISTINCT ON
expression(s) must match the leftmost ORDER BY
expression(s). The ORDER BY
clause will normally contain additional expression(s) that determine the desired precedence of rows within each DISTINCT ON
group.
Currently, FOR NO KEY UPDATE
, FOR UPDATE
, FOR SHARE
, and FOR KEY SHARE
cannot be specified with DISTINCT
.
The UNION
clause
The UNION
clause has this general form:
<select_statement> UNION [ALL | DISTINCT] <select_statement>
<select_statement>
is any SELECT
statement without an ORDER BY
, LIMIT
, FOR NO KEY UPDATE
, FOR UPDATE
, FOR SHARE
, or FOR KEY SHARE
clause. (ORDER BY
and LIMIT
can be attached to a subquery expression if it is enclosed in parentheses. Without parentheses, these clauses will be taken to apply to the result of the UNION
, not to its right-hand input expression.)
The UNION
operator computes the set union of the rows returned by the involved SELECT
statements. A row is in the set union of two result sets if it appears in at least one of the result sets. The two SELECT
statements that represent the direct operands of the UNION
must produce the same number of columns, and corresponding columns must be of compatible data types.
The result of UNION
does not contain any duplicate rows unless the ALL
option is specified. ALL
prevents elimination of duplicates. (Therefore, UNION ALL
is usually significantly quicker than UNION
; use ALL
when you can.) DISTINCT
can be specified to explicitly specify the default behavior of eliminating duplicate rows.
Multiple UNION
operators in the same SELECT
statement are evaluated left to right, unless otherwise indicated by parentheses.
Currently, FOR NO KEY UPDATE
, FOR UPDATE
, FOR SHARE
, and FOR KEY SHARE
cannot be specified either for a UNION
result or for any input of a UNION
.
The INTERSECT
clause
The INTERSECT
clause has this general form:
<select_statement> INTERSECT [ALL | DISTINCT] <select_statement>
<select_statement>
is any SELECT
statement without an ORDER BY
, LIMIT
, FOR NO KEY UPDATE
, FOR UPDATE
, FOR SHARE
, or FOR KEY SHARE
clause.
The INTERSECT
operator computes the set intersection of the rows returned by the involved SELECT
statements. A row is in the intersection of two result sets if it appears in both result sets.
The result of INTERSECT
does not contain any duplicate rows unless the ALL
option is specified. With ALL
, a row that has <m>
duplicates in the left table and <n>
duplicates in the right table will appear min(<m>, <n>)
times in the result set. DISTINCT
can be written to explicitly specify the default behavior of eliminating duplicate rows.
Multiple INTERSECT
operators in the same SELECT
statement are evaluated left to right, unless parentheses dictate otherwise. INTERSECT
binds more tightly than UNION
. That is, A UNION B INTERSECT C
will be read as A UNION (B INTERSECT C)
.
Currently, FOR NO KEY UPDATE
, FOR UPDATE
, FOR SHARE
, and FOR KEY SHARE
cannot be specified either for an INTERSECT
result or for any input of an INTERSECT
.
The EXCEPT
clause
The EXCEPT
clause has this general form:
<select_statement> EXCEPT [ALL | DISTINCT] <select_statement>
<select_statement>
is any SELECT
statement without an ORDER BY
, LIMIT
, FOR NO KEY UPDATE
, FOR UPDATE
, FOR SHARE
, or FOR KEY SHARE
clause.
The EXCEPT
operator computes the set of rows that are in the result of the left SELECT
statement but not in the result of the right one.
The result of EXCEPT
does not contain any duplicate rows unless the ALL
option is specified. With ALL
, a row that has <m>
duplicates in the left table and <n>
duplicates in the right table will appear max(<m>-<n>,0)
times in the result set. DISTINCT
can be written to explicitly specify the default behavior of eliminating duplicate rows.
Multiple EXCEPT
operators in the same SELECT
statement are evaluated left to right, unless parentheses dictate otherwise. EXCEPT
binds at the same level as UNION
.
Currently, FOR NO KEY UPDATE
, FOR UPDATE
, FOR SHARE
, and FOR KEY SHARE
cannot be specified either for an EXCEPT
result or for any input of an EXCEPT
.
The ORDER BY
clause
The optional ORDER BY
clause has this general form:
ORDER BY <expression> [ASC | DESC | USING <operator>] [NULLS {FIRST | LAST}] [,...]
The ORDER BY
clause causes the result rows to be sorted according to the specified expression(s). If two rows are equal according to the left-most expression, they are compared according to the next expression and so on. If they are equal according to all specified expressions, they are returned in an implementation-dependent order.
Each <expression>
can be the name or ordinal number of an output column (SELECT
list item), or it can be an arbitrary expression formed from input-column values.
The ordinal number refers to the ordinal (left-to-right) position of the output column. This feature makes it possible to define an ordering on the basis of a column that does not have a unique name. This is never absolutely necessary because it is always possible to assign a name to an output column using the AS
clause.
It is also possible to use arbitrary expressions in the ORDER BY
clause, including columns that do not appear in the SELECT
output list. Thus the following statement is valid:
SELECT name FROM distributors ORDER BY code;
A limitation of this feature is that an ORDER BY
clause applying to the result of a UNION
, INTERSECT
, or EXCEPT
clause may only specify an output column name or number, not an expression.
If an ORDER BY
expression is a simple name that matches both an output column name and an input column name, ORDER BY
will interpret it as the output column name. This is the opposite of the choice that GROUP BY
will make in the same situation. This inconsistency is made to be compatible with the SQL standard.
Optionally one may add the key word ASC
(ascending) or DESC
(descending) after any expression in the ORDER BY
clause. If not specified, ASC
is assumed by default. Alternatively, a specific ordering operator name may be specified in the USING
clause. ASC
is usually equivalent to USING <
and DESC
is usually equivalent to USING >
. (But the creator of a user-defined data type can define exactly what the default sort ordering is, and it might correspond to operators with other names.)
If NULLS LAST
is specified, null values sort after all non-null values; if NULLS FIRST
is specified, null values sort before all non-null values. If neither is specified, the default behavior is NULLS LAST
when ASC
is specified or implied, and NULLS FIRST
when DESC
is specified (thus, the default is to act as though nulls are larger than non-nulls). When USING
is specified, the default nulls ordering depends upon whether the operator is a less-than or greater-than operator.
Note that ordering options apply only to the expression they follow; for example ORDER BY x, y DESC
does not mean the same thing as ORDER BY x DESC, y DESC
.
Character-string data is sorted according to the locale-specific collation order that was established when the database was created. You can override this at need by including a COLLATE
clause in the expression, for example ORDER BY mycolumn COLLATE "en_US"
.
Character-string data is sorted according to the collation that applies to the column being sorted. That can be overridden as needed by including a COLLATE
clause in the expression, for example ORDER BY mycolumn COLLATE "en_US"
. For information about defining collations, see CREATE COLLATION.