select(2)
NAME
SELECT - retrieve rows from a table or view
SYNOPSIS
SELECT [ ALL | DISTINCT [ ON ( expression [, ...] ) ] ]
* | expression [ AS output_name ] [, ...]
[ FROM from_item [, ...] ]
[ WHERE condition ]
[ GROUP BY expression [, ...] ]
[ HAVING condition [, ...] ]
[ { UNION | INTERSECT | EXCEPT } [ ALL ] select ]
[ ORDER BY expression [ ASC | DESC | USING operator ] [, ...] ]
[ LIMIT { count | ALL } ]
[ OFFSET start ]
[ FOR { UPDATE | SHARE } [ OF table_name [, ...] ] [ NOWAIT ] [...] ]
where from_item can be one of:
[ ONLY ] table_name [ * ] [ [ AS ] alias [ ( column_alias [, ...] ) ] ]
( select ) [ AS ] alias [ ( column_alias [, ...] ) ]
function_name ( [ argument [, ...] ] ) [ AS ] alias [ ( column_alias [, ...] | column_definition [, ...] ) ]
function_name ( [ argument [, ...] ] ) AS ( column_definition [, ...] )
from_item [ NATURAL ] join_type from_item [ ON join_condition | USING ( join_column [, ...] ) ]
DESCRIPTION
SELECT retrieves rows from zero or more tables. The general processing
of SELECT is as follows:
1. All elements in the FROM list are computed. (Each element in
the FROM list is a real or virtual table.) If more than one ele-
ment is specified in the FROM list, they are cross-joined
together. (See FROM Clause [select(5)] below.)
2. If the WHERE clause is specified, all rows that do not satisfy
the condition are eliminated from the output. (See WHERE Clause
[select(5)] below.)
3. If the GROUP BY clause is specified, the output is divided into
groups of rows that match on one or more values. If the HAVING
clause is present, it eliminates groups that do not satisfy the
given condition. (See GROUP BY Clause [select(5)] and HAVING
Clause [select(5)] below.)
4. The actual output rows are computed using the SELECT output
expressions for each selected row. (See SELECT List [select(5)]
below.)
5. Using the operators 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. (See UNION Clause [select(5)], INTERSECT
Clause [select(l)], and EXCEPT Clause [select(5)] below.)
6. If the 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. (See ORDER BY Clause [select(5)] below.)
7. DISTINCT eliminates duplicate rows from the result. DISTINCT ON
eliminates rows that match on all the specified expressions. ALL
(the default) will return all candidate rows, including dupli-
cates. (See DISTINCT Clause [select(5)] below.)
8. If the LIMIT or OFFSET clause is specified, the SELECT statement
only returns a subset of the result rows. (See LIMIT Clause
[select(5)] below.)
9. If FOR UPDATE or FOR SHARE is specified, the SELECT statement
locks the selected rows against concurrent updates. (See FOR
UPDATE/FOR SHARE Clause [select(5)] below.)
You must have SELECT privilege on a table to read its values. The use
of FOR UPDATE or FOR SHARE requires UPDATE privilege as well.
PARAMETERS
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 to restrict the returned rows to a small subset of the Carte-
sian 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, only that table is scanned. If ONLY
is not specified, the table and all its descendant tables (if
any) are scanned. * can be appended to the table name to indi-
cate that descendant tables are to be scanned, but in the cur-
rent version, this is the default behavior. (In releases before
7.1, ONLY was the default behavior.) The default behavior can be
modified by changing the sql_inheritance configuration option.
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 an
alias is provided, it completely hides the actual name of the
table or function; for example given FROM foo AS f, the remain-
der 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 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 [values(5)] command can also be used here.
function_name
Function calls can appear in the FROM clause. (This is espe-
cially useful for functions that return result sets, but any
function can be used.) This acts as though its output were cre-
ated 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 ( col-
umn_name data_type [, ... ] ). The column definition list must
match the actual number and types of columns returned by the
function.
join_type
One of
o [ INNER ] JOIN
o LEFT [ OUTER ] JOIN
o RIGHT [ OUTER ] JOIN
o FULL [ OUTER ] JOIN
o CROSS JOIN
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. Use parentheses if necessary to
determine the order of nesting. In the absence of parentheses, JOINs
nest left-to-right. In any case JOIN binds more tightly than the commas
separating FROM items.
CROSS JOIN and INNER JOIN produce a simple Cartesian product, the same
result as you get from listing the two items at the top level of FROM,
but restricted by the join condition (if any). CROSS JOIN is equiva-
lent to INNER JOIN ON (TRUE), that is, no rows are removed by qualifi-
cation. These join types are just a notational convenience, since they
do nothing you couldn't 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 inputs.
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 equiva-
lent 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.
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 elimi-
nated from the output. A row satisfies the condition if it returns true
when the actual row values are substituted for any variable references.
GROUP BY CLAUSE
The optional GROUP BY clause has the general form
GROUP BY expression [, ...]
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 mak-
ing up each group, producing a separate value for each group (whereas
without GROUP BY, an aggregate produces a single value computed across
all the selected rows). When GROUP BY is present, it is not valid for
the SELECT list expressions to refer to ungrouped columns except within
aggregate functions, since there would be more than one possible value
to return for an ungrouped column.
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 refer-
ence a grouping column, unless the reference appears within an aggre-
gate function.
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.
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. Using the clause AS output_name, another name can be specified
for an output column. This name is primarily used to label the column
for display. It can also 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, one can write
table_name.* as a shorthand for the columns coming from just that ta-
ble.
UNION CLAUSE
The UNION clause has this general form:
select_statement UNION [ ALL ] select_statement
select_statement is any SELECT statement without an ORDER BY, LIMIT,
FOR UPDATE, or FOR SHARE clause. (ORDER BY and LIMIT can be attached
to a subexpression if it is enclosed in parentheses. Without parenthe-
ses, 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 com-
patible data types.
The result of UNION does not contain any duplicate rows unless the ALL
option is specified. ALL prevents elimination of duplicates. (There-
fore, UNION ALL is usually significantly quicker than UNION; use ALL
when you can.)
Multiple UNION operators in the same SELECT statement are evaluated
left to right, unless otherwise indicated by parentheses.
Currently, FOR UPDATE and FOR SHARE may not be specified either for a
UNION result or for any input of a UNION.
INTERSECT CLAUSE
The INTERSECT clause has this general form:
select_statement INTERSECT [ ALL ] select_statement
select_statement is any SELECT statement without an ORDER BY, LIMIT,
FOR UPDATE, or FOR SHARE clause.
The INTERSECT operator computes the set intersection of the rows
returned by the involved SELECT statements. A row is in the intersec-
tion 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.
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 UPDATE and FOR SHARE may not be specified either for an
INTERSECT result or for any input of an INTERSECT.
EXCEPT CLAUSE
The EXCEPT clause has this general form:
select_statement EXCEPT [ ALL ] select_statement
select_statement is any SELECT statement without an ORDER BY, LIMIT,
FOR UPDATE, or FOR 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.
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 UPDATE and FOR SHARE may not be specified either for an
EXCEPT result or for any input of an EXCEPT.
ORDER BY CLAUSE
The optional ORDER BY clause has this general form:
ORDER BY expression [ ASC | DESC | USING operator ] [, ...]
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, the 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 result 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 a result 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 result 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 out-
put column name or number, not an expression.
If an ORDER BY expression is a simple name that matches both a result
column name and an input column name, ORDER BY will interpret it as the
result column name. This is the opposite of the choice that GROUP BY
will make in the same situation. This inconsistency is made to be com-
patible with the SQL standard.
Optionally one may add the key word ASC (ascending) or DESC (descend-
ing) 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.)
The null value sorts higher than any other value. In other words, with
ascending sort order, null values sort at the end, and with descending
sort order, null values sort at the beginning.
Character-string data is sorted according to the locale-specific colla-
tion order that was established when the database cluster was initial-
ized.
DISTINCT CLAUSE
If DISTINCT is specified, all duplicate rows are removed from the
result set (one row is kept from each group of duplicates). ALL speci-
fies the opposite: all rows are kept; that is the default.
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 expres-
sion(s). The ORDER BY clause will normally contain additional expres-
sion(s) that determine the desired precedence of rows within each DIS-
TINCT ON group.
LIMIT CLAUSE
The LIMIT clause consists of two independent sub-clauses:
LIMIT { count | ALL }
OFFSET start
count specifies the maximum number of rows to return, while start spec-
ifies 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.
When using LIMIT, it is a good idea to use an ORDER BY clause that con-
strains 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 planner 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 bug; 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.
FOR UPDATE/FOR SHARE CLAUSE
The FOR UPDATE clause has this form:
FOR UPDATE [ OF table_name [, ...] ] [ NOWAIT ]
The closely related FOR SHARE clause has this form:
FOR SHARE [ OF table_name [, ...] ] [ NOWAIT ]
FOR UPDATE causes the rows retrieved by the SELECT statement to be
locked as though for update. This prevents them from being modified or
deleted by other transactions until the current transaction ends. That
is, other transactions that attempt UPDATE, DELETE, or SELECT FOR
UPDATE of these rows will be blocked until the current transaction
ends. Also, if an UPDATE, DELETE, or SELECT FOR UPDATE from another
transaction has already locked a selected row or rows, SELECT FOR
UPDATE will wait for the other transaction to complete, and will then
lock and return the updated row (or no row, if the row was deleted).
For further discussion see in the documentation.
To prevent the operation from waiting for other transactions to commit,
use the NOWAIT option. SELECT FOR UPDATE NOWAIT reports an error,
rather than waiting, if a selected row cannot be locked immediately.
Note that NOWAIT applies only to the row-level lock(s) -- the required
ROW SHARE table-level lock is still taken in the ordinary way (see in
the documentation). You can use the NOWAIT option of LOCK [lock(5)] if
you need to acquire the table-level lock without waiting.
FOR SHARE behaves similarly, except that it acquires a shared rather
than exclusive lock on each retrieved row. A shared lock blocks other
transactions from performing UPDATE, DELETE, or SELECT FOR UPDATE on
these rows, but it does not prevent them from performing SELECT FOR
SHARE.
If specific tables are named in FOR UPDATE or FOR SHARE, then only rows
coming from those tables are locked; any other tables used in the
SELECT are simply read as usual. A FOR UPDATE or FOR SHARE clause with-
out a table list affects all tables used in the command. If FOR UPDATE
or FOR SHARE is applied to a view or sub-query, it affects all tables
used in the view or sub-query.
Multiple FOR UPDATE and FOR SHARE clauses can be written if it is nec-
essary to specify different locking behavior for different tables. If
the same table is mentioned (or implicitly affected) by both FOR UPDATE
and FOR SHARE clauses, then it is processed as FOR UPDATE. Similarly, a
table is processed as NOWAIT if that is specified in any of the clauses
affecting it.
FOR UPDATE and FOR SHARE cannot be used in contexts where returned rows
can't be clearly identified with individual table rows; for example
they can't be used with aggregation.
Caution: Avoid locking a row and then modifying it within a
later savepoint or PL/pgSQL exception block. A subsequent roll-
back would cause the lock to be lost. For example,
BEGIN;
SELECT * FROM mytable WHERE key = 1 FOR UPDATE;
SAVEPOINT s;
UPDATE mytable SET ... WHERE key = 1;
ROLLBACK TO s;
After the ROLLBACK, the row is effectively unlocked, rather than
returned to its pre-savepoint state of being locked but not mod-
ified. This hazard occurs if a row locked in the current trans-
action is updated or deleted, or if a shared lock is upgraded to
exclusive: in all these cases, the former lock state is forgot-
ten. If the transaction is then rolled back to a state between
the original locking command and the subsequent change, the row
will appear not to be locked at all. This is an implementation
deficiency which will be addressed in a future release of Post-
greSQL.
Caution: It is possible for a SELECT command using both LIMIT
and FOR UPDATE/SHARE clauses to return fewer rows than specified
by LIMIT. This is because LIMIT is applied first. The command
selects the specified number of rows, but might then block try-
ing to obtain lock on one or more of them. Once the SELECT
unblocks, the row might have been deleted or updated so that it
does not meet the query WHERE condition anymore, in which case
it will not be returned.
EXAMPLES
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
title | did | name | date_prod | kind
-------------------+-----+--------------+------------+----------
The Third Man | 101 | British Lion | 1949-12-23 | Drama
The African Queen | 101 | British Lion | 1951-08-11 | Romantic
...
To sum the column len of all films and group the results by kind:
SELECT kind, sum(len) AS total FROM films GROUP BY kind;
kind | total
----------+-------
Action | 07:34
Comedy | 02:58
Drama | 14:28
Musical | 06:42
Romantic | 04:38
To sum the column len of all films, group the results by kind and show
those group totals that are less than 5 hours:
SELECT kind, sum(len) AS total
FROM films
GROUP BY kind
HAVING sum(len) < interval '5 hours';
kind | total
----------+-------
Comedy | 02:58
Romantic | 04:38
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;
did | name
-----+------------------
109 | 20th Century Fox
110 | Bavaria Atelier
101 | British Lion
107 | Columbia
102 | Jean Luc Godard
113 | Luso films
104 | Mosfilm
103 | Paramount
106 | Toho
105 | United Artists
111 | Walt Disney
112 | Warner Bros.
108 | Westward
The next example shows how to obtain the union of the tables distribu-
tors 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.
distributors: actors:
did | name id | name
-----+-------------- ----+----------------
108 | Westward 1 | Woody Allen
111 | Walt Disney 2 | Warren Beatty
112 | Warner Bros. 3 | Walter Matthau
... ...
SELECT distributors.name
FROM distributors
WHERE distributors.name LIKE 'W%'
UNION
SELECT actors.name
FROM actors
WHERE actors.name LIKE 'W%';
name
----------------
Walt Disney
Walter Matthau
Warner Bros.
Warren Beatty
Westward
Woody Allen
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);
did | name
-----+-------------
111 | Walt Disney
CREATE FUNCTION distributors_2(int) RETURNS SETOF record AS $$
SELECT * FROM distributors WHERE did = $1;
$$ LANGUAGE SQL;
SELECT * FROM distributors_2(111) AS (f1 int, f2 text);
f1 | f2
-----+-------------
111 | Walt Disney
COMPATIBILITY
Of course, the SELECT statement is compatible with the SQL standard.
But there are some extensions and some missing features.
OMITTED FROM CLAUSES
PostgreSQL allows one to omit the FROM clause. It has a straightforward
use to compute the results of simple expressions:
SELECT 2+2;
?column?
----------
4
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';
PostgreSQL releases prior to 8.1 would accept queries of this form, and
add an implicit entry to the query's FROM clause for each table refer-
enced by the query. This is no longer the default behavior, because it
does not comply with the SQL standard, and is considered by many to be
error-prone. For compatibility with applications that rely on this
behavior the add_missing_from configuration variable can be enabled.
THE AS KEY WORD
In the SQL standard, the optional key word AS is just noise and can be
omitted without affecting the meaning. The PostgreSQL parser requires
this key word when renaming output columns because the type extensibil-
ity features lead to parsing ambiguities without it. AS is optional in
FROM items, however.
NAMESPACE AVAILABLE TO GROUP BY AND ORDER BY
In the SQL-92 standard, an ORDER BY clause may only use result column
names or numbers, while a GROUP BY clause may only use expressions
based on input column names. PostgreSQL extends each of these clauses
to allow the other choice as well (but it uses the standard's interpre-
tation if there is ambiguity). PostgreSQL also allows both clauses to
specify arbitrary expressions. Note that names appearing in an expres-
sion will always be taken as input-column names, not as result-column
names.
SQL:1999 and later use a slightly different definition which is not
entirely upward compatible with SQL-92. In most cases, however, Post-
greSQL will interpret an ORDER BY or GROUP BY expression the same way
SQL:1999 does.
NONSTANDARD CLAUSES
The clauses DISTINCT ON, LIMIT, and OFFSET are not defined in the SQL
standard.
SQL - Language Statements 2008-06-08 SELECT()
Man(1) output converted with
man2html