Retrieves rows from a table or view.
[ 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] [...]]
TABLE { [ ONLY ] <table_name> [ * ] | <with_query_name> }
where with_query: is:
<with_query_name> [( <column_name> [, ...] )] AS ( <select> | <values> | <insert> | <update> | delete )
where from_item can be one of:
[ONLY] <table_name> [ * ] [ [ AS ] <alias> [ ( <column_alias> [, ...] ) ] ]
( <select> ) [ AS ] <alias> [( <column_alias> [, ...] ) ]
with\_query\_name [ [ AS ] <alias> [ ( <column_alias> [, ...] ) ] ]
<function_name> ( [ <argument> [, ...] ] )
[ WITH ORDINALITY ] [ [ AS ] <alias> [ ( <column_alias> [, ...] ) ] ]
<function_name> ( [ <argument> [, ...] ] ) [ AS ] <alias> ( <column_definition> [, ...] )
<function_name> ( [ <argument> [, ...] ] ) AS ( <column_definition> [, ...] )
ROWS FROM( function_name ( [ argument [, ...] ] ) [ AS ( column_definition [, ...] ) ] [, ...] )
[ WITH ORDINALITY ] [ [ AS ] <alias> [ ( <column_alias> [, ...] ) ] ]
<from_item> [ NATURAL ] <join_type> <from_item>
[ ON <join_condition> | USING ( <join_column> [, ...] ) ]
where grouping_element can be one of:
()
<expression>
ROLLUP (<expression> [,...])
CUBE (<expression> [,...])
GROUPING SETS ((<grouping_element> [, ...]))
where window_definition is:
[<existing_window_name>]
[PARTITION BY <expression> [, ...]]
[ORDER BY <expression> [ASC | DESC | USING <operator>]
[NULLS {FIRST | LAST}] [, ...]]
[{ RANGE | ROWS} <frame_start>
| {RANGE | ROWS} BETWEEN <frame_start> AND <frame_end>
where frame_start and frame_end can be one of:
UNBOUNDED PRECEDING
<value> PRECEDING
CURRENT ROW
<value> FOLLOWING
UNBOUNDED FOLLOWING
2When a locking clause is specified (the FOR
clause), the Global Deadlock Detector affects how table rows are locked. See item 12 in Description and see "The Locking Clause" later in this section.
SELECT
retrieves rows from zero or more tables. The general processing of SELECT
is as follows:
WITH
clause are computed. These effectively serve as temporary tables that can be referenced in the FROM
list.FROM
list are computed. (Each element in the FROM
list is a real or virtual table.) If more than one element is specified in the FROM
list, they are cross-joined together.WHERE
clause is specified, all rows that do not satisfy the condition are eliminated from the output.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 the HAVING
clause is present, it eliminates groups that do not satisfy the given condition.SELECT
output expressions for each selected row or row group.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.WINDOW
clause), the output is organized according to the positional (row) or value-based (range) window frame.SELECT
output expressions for each selected row.UNION
, INTERSECT
, and EXCEPT
, the output of more than one SELECT
statement can be combined to form a single result set. The UNION
operator returns all rows that are in one or both of the result sets. The INTERSECT
operator returns all rows that are strictly in both result sets. The EXCEPT
operator returns the rows that are in the first result set but not in the second. In all three cases, duplicate rows are eliminated unless ALL
is specified. The noise word DISTINCT
can be added to explicitly specify eliminating duplicate rows. Notice that DISTINCT
is the default behavior here, even though ALL
is the default for SELECT
itself.ORDER BY
clause is specified, the returned rows are sorted in the specified order. If ORDER BY
is not given, the rows are returned in whatever order the system finds fastest to produce.LIMIT
(or FETCH FIRST
) or OFFSET
clause is specified, the SELECT
statement only returns a subset of the result rows.FOR UPDATE
, FOR NO KEY UPDATE
, FOR SHARE
, or FOR KEY SHARE
is specified, the SELECT
statement locks the entire table against concurrent updates.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).
The WITH Clause
The optional 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
, 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 with_query_name without schema qualification must be specified for each query in the WITH
clause. Optionally, a list of column names can be specified; if the list of column names is omitted, the names are inferred from the subquery. The primary query and the WITH
queries are all (notionally) run at the same time.
If RECURSIVE
is specified, it allows a SELECT
subquery to reference itself by name. Such a subquery has the general 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 only reference sibling WITH
queries that are earlier in the WITH
list.
WITH RECURSIVE
limitations. These items are not supported:
WITH
clause that contains the following in the recursive_term.
DISTINCT
clauseGROUP BY
clauseWITH
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;
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.
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.
See WITH Queries (Common Table Expressions) in the Greenplum Database Administrator Guide for additional information.
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 Greenplum 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, Greenplum Database chooses a name is 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 write out the expression instead.
Instead of an expression, *
can be written in the output list as a shorthand for all the columns of the selected rows. Also, you can write 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.
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.
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:
ONLY
is specified, only that table is scanned. If
ONLY
is not specified, the table and all its descendant tables (if any) are scanned.
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 an alias is provided, 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 an alias is written, a column alias list can also be written to provide substitute names for one or more columns of the table.
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 Greenplum Database.
A with_query is referenced in the FROM
clause by specifying its with_query_name, just as though the name were a table name. The with_query_name cannot contain a schema qualifier. An alias can be provided in the same way as for a table.
FROM
clause. (This is especially useful for functions that return result sets, but any function can be used.) This acts as though its output were created as a temporary table for the duration of this single
SELECT
command. An alias may also be used. If an alias is written, a column alias list can also be written to provide substitute names for one or more attributes of the function's composite return type. 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.
One of:
For the INNER
and OUTER
join types, a join condition must be specified, namely exactly one of NATURAL
, ON join\_condition
, or USING ( join\_column [, ...])
. See below for the meaning. For CROSS JOIN
, none of these clauses may appear.
A JOIN clause combines two FROM
items, which for convenience we will refer 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. In any case JOIN
binds more tightly than the commas separating FROM
-list items.
CROSS JOIN
and INNER JOIN
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). CROSS JOIN
is equivalent to INNER JOIN ON``(TRUE)
, that is, no rows are removed by qualification. These join types are just a notational convenience, since they do nothing you could not do 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).
boolean
(similar to a
WHERE
clause) that specifies which rows in a join are considered to match.
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
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
.
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
will condense into a single row all selected rows that share the same values for the grouped expressions. expression 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.
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 the selected rows.) The set of rows fed to each aggregate function can be further filtered 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. See Aggregate Expressions.
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; see Expression Evaluation Rules.
Greenplum Database has the following additional OLAP grouping extensions (often referred to as supergroups):
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
.
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.
NoteGreenplum Database supports specifying a maximum of 12
CUBE
grouping columns.
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
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 a NULL
value in a regular row. Each argument in this function produces a bit — either 1
or 0
, where 1
means the result row is super-aggregated, and 0
means the result row is from a regular grouping. The grouping
function returns an integer by treating these bits as a binary number and then converting it to a base-10 integer.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, the group_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 WINDOW Clause
The optional WINDOW
clause specifies 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.
For example:
SELECT vendor, rank() OVER (mywindow) FROM sale
GROUP BY vendor
WINDOW mywindow AS (ORDER BY sum(prc*qty));
A WINDOW
clause has this 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>]
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.
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
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.
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. >
Note Columns of data types that lack a coherent ordering, such as
time
, are not good candidates for use in the
ORDER BY
clause of a window specification. Time, with or without time zone, lacks a coherent ordering because addition and subtraction do not have the expected effects. For example, the following is not generally true:
x::time < x::time + '2 hour'::interval
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 } <frame_start>
{ RANGE | ROWS } BETWEEN <frame_start> AND <frame_end>
where frame\_start
and frame\_end
can be one of
UNBOUNDED PRECEDING
value PRECEDING
CURRENT ROW
value FOLLOWING
UNBOUNDED FOLLOWING
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 than the frame\_start
choice — for example RANGE BETWEEN CURRENT ROW AND value 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 ORDER BY
considers equivalent to the current row, or all rows 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
or ROWS
mode). In ROWS
mode, CURRENT ROW
means that the frame starts or ends with the current row; but in RANGE
mode it means that the frame starts or ends with the current row's first or last peer in the ORDER BY
ordering. The value PRECEDING
and value FOLLOWING
cases are currently only allowed in ROWS
mode. They indicate that the frame starts or ends with the row that many rows before or after the current row. value must be an integer expression not containing any variables, aggregate functions, or window functions. The value must not be null or negative; but it can be zero, which selects the current row itself.
Beware that the ROWS
options can produce unpredictable results if the ORDER BY
ordering does not order the rows uniquely. The RANGE
options are designed to ensure that rows that are peers in the ORDER BY
ordering are treated alike; all peer rows will be in the same frame.
Use either a ROWS
or RANGE
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
), or in terms of the number of rows offset from the current row (ROWS
). When using the RANGE
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
or RANGE
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 ROW
or RANGE
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.
ROW
or a
RANGE
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 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 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.
The UNION Clause
The UNION
clause has this general form:
<select_statement> UNION [ALL | DISTINCT] <select_statement>
where 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 written 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>
where 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>
where 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}] [,...]
where 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 ORDER BY
clause causes the result rows to be sorted according to the specified expressions. 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.
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.
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.
The LIMIT Clause
The LIMIT
clause consists of two independent sub-clauses:
LIMIT {<count> | ALL}
OFFSET <start>
where count specifies the maximum number of rows to return, while start specifies the number of rows to skip before starting to return rows. When both are specified, start rows are skipped before starting to count the count
rows to be returned.
If the count
expression evaluates to NULL, it is treated as LIMIT ALL
, that is, no limit. If start
evaluates to NULL, it is treated the same as OFFSET 0
.
SQL:2008 introduced a different syntax to achieve the same result, which Greenplum Database also supports. It is:
OFFSET <start> [ ROW | ROWS ]
FETCH { FIRST | NEXT } [ <count> ] { ROW | ROWS } ONLY
In this syntax, the start or count value is required by the standard to be a literal constant, a parameter, or a variable name; as a Greenplum Database extension, other expressions are allowed, but will generally need to be enclosed in parentheses to avoid ambiguity. If count is omitted in a FETCH
clause, it defaults to 1. ROW
and ROWS
as well as FIRST
and NEXT
are noise words that don't influence the effects of these clauses. According to the standard, the OFFSET
clause must come before the FETCH
clause if both are present; but Greenplum Database allows either order.
When using LIMIT
, it is a good idea to use an ORDER BY
clause that constrains the result rows into a unique order. Otherwise you will get an unpredictable subset of the query's rows — you may be asking for the tenth through twentieth rows, but tenth through twentieth in what ordering? You don't know what ordering unless you specify ORDER BY
.
The query optimizer takes LIMIT
into account when generating a query plan, so you are very likely to get different plans (yielding different row orders) depending on what you use for LIMIT
and OFFSET
. Thus, using different LIMIT/OFFSET
values to select different subsets of a query result will give inconsistent results unless you enforce a predictable result ordering with ORDER BY
. This is not a defect; it is an inherent consequence of the fact that SQL does not promise to deliver the results of a query in any particular order unless ORDER BY
is used to constrain the order.
The Locking Clause
FOR UPDATE
, FOR NO KEY UPDATE
, FOR SHARE
and FOR KEY SHARE
are locking clauses; they affect how SELECT
locks rows as they are obtained from the table.
The locking clause has the general form
FOR <lock_strength> [OF <table_name> [ , ... ] ] [ NOWAIT ]
where lock_strength can be one of
FOR UPDATE
- Locks the table with an EXCLUSIVE
lock.FOR NO KEY UPDATE
- Locks the table with an EXCLUSIVE
lock.FOR SHARE
- Locks the table with a ROW SHARE
lock.FOR KEY SHARE
- Locks the table with a ROW SHARE
lock.NoteBy default Greenplum Database acquires the more restrictive
EXCLUSIVE
lock (rather thanROW EXCLUSIVE
in PostgreSQL) forUPDATE
,DELETE
, andSELECT...FOR UPDATE
operations on heap tables. When the Global Deadlock Detector is enabled the lock mode forUPDATE
andDELETE
operations on heap tables isROW EXCLUSIVE
. See Global Deadlock Detector. Greenplum always holds a table-level lock withSELECT...FOR UPDATE
statements.
For more information on each row-level lock mode, refer to Explicit Locking in the PostgreSQL documentation.
To prevent the operation from waiting for other transactions to commit, use the NOWAIT
option. With NOWAIT
, the statement reports an error, rather than waiting, if a selected row cannot be locked immediately. Note that NOWAIT
only affects whether the SELECT
statement waits to obtain row-level locks. A required table-level lock is always taken in the ordinary way. For example, a SELECT FOR UPDATE NOWAIT
statement will always wait for the required table-level lock; it behaves as if NOWAIT
was omitted. You can use LOCK
with the NOWAIT
option first, if you need to acquire the table-level lock without waiting.
If specific tables are named in a locking clause, then only rows coming from those tables are locked; any other tables used in the SELECT
are simply read as usual. A locking clause without a table list affects all tables used in the statement. If a locking clause is applied to a view or sub-query, it affects all tables used in the view or sub-query. However, these clauses do not apply to WITH
queries referenced by the primary query. If you want row locking to occur within a WITH
query, specify a locking clause within the WITH
query.
Multiple locking clauses can be written if it is necessary to specify different locking behavior for different tables. If the same table is mentioned (or implicitly affected) by both more than one locking clause, then it is processed as if it was only specified by the strongest one. Similarly, a table is processed as NOWAIT
if that is specified in any of the clauses affecting it.
The locking clauses cannot be used in contexts where returned rows cannot be clearly identified with individual table rows; for example they cannot be used with aggregation.
When a locking clause appears at the top level of a SELECT
query, the rows that are locked are exactly those that are returned by the query; in the case of a join query, the rows locked are those that contribute to returned join rows. In addition, rows that satisfied the query conditions as of the query snapshot will be locked, although they will not be returned if they were updated after the snapshot and no longer satisfy the query conditions. If a LIMIT
is used, locking stops once enough rows have been returned to satisfy the limit (but note that rows skipped over by OFFSET
will get locked). Similarly, if a locking clause is used in a cursor's query, only rows actually fetched or stepped past by the cursor will be locked.
When locking clause appears in a sub-SELECT
, the rows locked are those returned to the outer query by the sub-query. This might involve fewer rows than inspection of the sub-query alone would suggest, since conditions from the outer query might be used to optimize execution of the sub-query. For example,
SELECT * FROM (SELECT * FROM mytable FOR UPDATE) ss WHERE col1 = 5;
will lock only rows having col1 = 5
, even though that condition is not textually within the sub-query.
It is possible for a SELECT
command running at the READ COMMITTED
transaction isolation level and using ORDER BY
and a locking clause to return rows out of order. This is because ORDER BY
is applied first. The command sorts the result, but might then block trying to obtain a lock on one or more of the rows. Once the SELECT
unblocks, some of the ordering column values might have been modified, leading to those rows appearing to be out of order (though they are in order in terms of the original column values). This can be worked around at need by placing the FOR UPDATE/SHARE
clause in a sub-query, for example
SELECT * FROM (SELECT * FROM mytable FOR UPDATE) ss ORDER BY column1;
Note that this will result in locking all rows of mytable
, whereas FOR UPDATE
at the top level would lock only the actually returned rows. This can make for a significant performance difference, particularly if the ORDER BY
is combined with LIMIT
or other restrictions. So this technique is recommended only if concurrent updates of the ordering columns are expected and a strictly sorted result is required.
At the REPEATABLE READ
or SERIALIZABLE
transaction isolation level this would cause a serialization failure (with a SQLSTATE
of 40001
), so there is no possibility of receiving rows out of order under these isolation levels.
The command
TABLE <name>
is completely equivalent to
SELECT * FROM <name>
It can be used as a top-level command or as a space-saving syntax variant in parts of complex queries.
To join the table films
with the table distributors
:
SELECT f.title, f.did, d.name, f.date_prod, f.kind FROM
distributors d, films f WHERE f.did = d.did
To sum the column length
of all films and group the results by kind
:
SELECT kind, sum(length) AS total FROM films GROUP BY kind;
To sum the column length
of all films, group the results by kind
and show those group totals that are less than 5 hours:
SELECT kind, sum(length) AS total FROM films GROUP BY kind
HAVING sum(length) < interval '5 hours';
Calculate the subtotals and grand totals of all sales for movie kind
and distributor
.
SELECT kind, distributor, sum(prc*qty) FROM sales
GROUP BY ROLLUP(kind, distributor)
ORDER BY 1,2,3;
Calculate the rank of movie distributors based on total sales:
SELECT distributor, sum(prc*qty),
rank() OVER (ORDER BY sum(prc*qty) DESC)
FROM sale
GROUP BY distributor ORDER BY 2 DESC;
The following two examples are identical ways of sorting the individual results according to the contents of the second column (name
):
SELECT * FROM distributors ORDER BY name;
SELECT * FROM distributors ORDER BY 2;
The next example shows how to obtain the union of the tables distributors
and actors
, restricting the results to those that begin with the letter W
in each table. Only distinct rows are wanted, so the key word ALL
is omitted:
SELECT distributors.name FROM distributors WHERE
distributors.name LIKE 'W%' UNION SELECT actors.name FROM
actors WHERE actors.name LIKE 'W%';
This example shows how to use a function in the FROM
clause, both with and without a column definition list:
CREATE FUNCTION distributors(int) RETURNS SETOF distributors
AS $$ SELECT * FROM distributors WHERE did = $1; $$ LANGUAGE
SQL;
SELECT * FROM distributors(111);
CREATE FUNCTION distributors_2(int) RETURNS SETOF record AS
$$ SELECT * FROM distributors WHERE did = $1; $$ LANGUAGE
SQL;
SELECT * FROM distributors_2(111) AS (dist_id int, dist_name
text);
This example uses a simple WITH
clause:
WITH test AS (
SELECT random() as x FROM generate_series(1, 3)
)
SELECT * FROM test
UNION ALL
SELECT * FROM test;
This example uses the WITH
clause to display 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) 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 example could have been written without the WITH
clause but would have required two levels of nested sub-SELECT
statements.
This example uses the WITH RECURSIVE
clause to find all subordinates (direct or indirect) of the employee Mary, and their level of indirectness, from a table that shows only direct subordinates:
WITH RECURSIVE employee_recursive(distance, employee_name, manager_name) AS (
SELECT 1, employee_name, manager_name
FROM employee
WHERE manager_name = 'Mary'
UNION ALL
SELECT er.distance + 1, e.employee_name, e.manager_name
FROM employee_recursive er, employee e
WHERE er.employee_name = e.manager_name
)
SELECT distance, employee_name FROM employee_recursive;
The typical form of recursive queries: an initial condition, followed by UNION [ALL]
, followed by the recursive part of the query. Be sure that the recursive part of the query will eventually return no tuples, or else the query will loop indefinitely. See WITH Queries (Common Table Expressions)in the Greenplum Database Administrator Guide for more examples.
The SELECT
statement is compatible with the SQL standard, but there are some extensions and some missing features.
Omitted FROM Clauses
Greenplum Database allows one to omit the FROM
clause. It has a straightforward use to compute the results of simple expressions. For example:
SELECT 2+2;
Some other SQL databases cannot do this except by introducing a dummy one-row table from which to do the SELECT
.
Note that if a FROM
clause is not specified, the query cannot reference any database tables. For example, the following query is invalid:
SELECT distributors.* WHERE distributors.name = 'Westward';
In earlier releases, setting a server configuration parameter, add_missing_from, to true allowed Greenplum Database to add an implicit entry to the query's FROM
clause for each table referenced by the query. This is no longer allowed.
Omitting the AS Key Word
In the SQL standard, the optional key word AS
can be omitted before an output column name whenever the new column name is a valid column name (that is, not the same as any reserved keyword). Greenplum Database is slightly more restrictive: AS
is required if the new column name matches any keyword at all, reserved or not. Recommended practice is to use AS
or double-quote output column names, to prevent any possible conflict against future keyword additions.
In FROM
items, both the standard and Greenplum Database allow AS
to be omitted before an alias that is an unreserved keyword. But this is impractical for output column names, because of syntactic ambiguities.
ONLY and Inheritance
The SQL standard requires parentheses around the table name when writing ONLY
, for example:
SELECT * FROM ONLY (tab1), ONLY (tab2) WHERE ...
Greenplum Database considers these parentheses to be optional.
Greenplum Database allows a trailing *
to be written to explicitly specify the non-ONLY
behavior of including child tables. The standard does not allow this.
(These points apply equally to all SQL commands supporting the ONLY
option.)
Namespace Available to GROUP BY and ORDER BY
In the SQL-92 standard, an ORDER BY
clause may only use output column names or numbers, while a GROUP BY
clause may only use expressions based on input column names. Greenplum Database extends each of these clauses to allow the other choice as well (but it uses the standard's interpretation if there is ambiguity). Greenplum Database also allows both clauses to specify arbitrary expressions. Note that names appearing in an expression are always taken as input-column names, not as output column names.
SQL:1999 and later use a slightly different definition which is not entirely upward compatible with SQL-92. In most cases, however, Greenplum Database interprets an ORDER BY
or GROUP BY
expression the same way SQL:1999 does.
Functional Dependencies
Greenplum Database recognizes functional dependency (allowing columns to be omitted from GROUP BY
) only when a table's primary key is included in the GROUP BY
list. The SQL standard specifies additional conditions that should be recognized.
LIMIT and OFFSET
The clauses LIMIT
and OFFSET
are Greenplum Database-specific syntax, also used by MySQL. The SQL:2008 standard has introduced the clauses OFFSET .. FETCH {FIRST|NEXT} ...
for the same functionality, as shown above. This syntax is also used by IBM DB2. (Applications for Oracle frequently use a workaround involving the automatically generated rownum
column, which is not available in Greenplum Database, to implement the effects of these clauses.)
FOR NO KEY UPDATE, FOR UPDATE, FOR SHARE, and FOR KEY SHARE
Although FOR UPDATE
appears in the SQL standard, the standard allows it only as an option of DECLARE CURSOR
. Greenplum Database allows it in any SELECT
query as well as in sub-SELECT
s, but this is an extension. The FOR NO KEY UPDATE
, FOR SHARE
, and FOR KEY SHARE
variants, as well as the NOWAIT
option, do not appear in the standard.
Data-Modifying Statements in WITH
Greenplum Database allows INSERT
, UPDATE
, and DELETE
to be used as WITH
queries. This is not found in the SQL standard.
Nonstandard Clauses
The clause DISTINCT ON
is not defined in the SQL standard.
Limited Use of STABLE and VOLATILE Functions
To prevent data from becoming out-of-sync across the segments in Greenplum Database, any function classified as STABLE
or VOLATILE
cannot be run at the segment database level if it contains SQL or modifies the database in any way. See CREATE FUNCTION for more information.
Parent topic: SQL Commands