postgresql/doc/src/sgml/ref/select.sgml
Bruce Momjian 1aab783b59 Implement TODO item:
* Change LIMIT val,val to offset,limit to match MySQL

Documentation updates too.
2001-09-23 03:39:01 +00:00

1072 lines
36 KiB
Plaintext

<!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/select.sgml,v 1.47 2001/09/23 03:39:01 momjian Exp $
Postgres documentation
-->
<refentry id="SQL-SELECT">
<refmeta>
<refentrytitle id="sql-select-title">SELECT</refentrytitle>
<refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta>
<refnamediv>
<refname>
SELECT
</refname>
<refpurpose>
retrieve rows from a table or view
</refpurpose></refnamediv>
<refsynopsisdiv>
<refsynopsisdivinfo>
<date>2000-12-11</date>
</refsynopsisdivinfo>
<synopsis>
SELECT [ ALL | DISTINCT [ ON ( <replaceable class="PARAMETER">expression</replaceable> [, ...] ) ] ]
* | <replaceable class="PARAMETER">expression</replaceable> [ AS <replaceable class="PARAMETER">output_name</replaceable> ] [, ...]
[ FROM <replaceable class="PARAMETER">from_item</replaceable> [, ...] ]
[ WHERE <replaceable class="PARAMETER">condition</replaceable> ]
[ GROUP BY <replaceable class="PARAMETER">expression</replaceable> [, ...] ]
[ HAVING <replaceable class="PARAMETER">condition</replaceable> [, ...] ]
[ { UNION | INTERSECT | EXCEPT [ ALL ] } <replaceable class="PARAMETER">select</replaceable> ]
[ ORDER BY <replaceable class="PARAMETER">expression</replaceable> [ ASC | DESC | USING <replaceable class="PARAMETER">operator</replaceable> ] [, ...] ]
[ FOR UPDATE [ OF <replaceable class="PARAMETER">tablename</replaceable> [, ...] ] ]
[ LIMIT [ <replaceable class="PARAMETER">start</replaceable> , ] { <replaceable class="PARAMETER">count</replaceable> | ALL } ]
[ OFFSET <replaceable class="PARAMETER">start</replaceable> ]
where <replaceable class="PARAMETER">from_item</replaceable> can be:
[ ONLY ] <replaceable class="PARAMETER">table_name</replaceable> [ * ]
[ [ AS ] <replaceable class="PARAMETER">alias</replaceable> [ ( <replaceable class="PARAMETER">column_alias_list</replaceable> ) ] ]
|
( <replaceable class="PARAMETER">select</replaceable> )
[ AS ] <replaceable class="PARAMETER">alias</replaceable> [ ( <replaceable class="PARAMETER">column_alias_list</replaceable> ) ]
|
<replaceable class="PARAMETER">from_item</replaceable> [ NATURAL ] <replaceable class="PARAMETER">join_type</replaceable> <replaceable class="PARAMETER">from_item</replaceable>
[ ON <replaceable class="PARAMETER">join_condition</replaceable> | USING ( <replaceable class="PARAMETER">join_column_list</replaceable> ) ]
</synopsis>
<refsect2 id="R2-SQL-SELECT-1">
<refsect2info>
<date>2000-12-11</date>
</refsect2info>
<title>
Inputs
</title>
<para>
<variablelist>
<varlistentry>
<term><replaceable class="PARAMETER">expression</replaceable></term>
<listitem>
<para>
The name of a table's column or an expression.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">output_name</replaceable></term>
<listitem>
<para>
Specifies another name for an output column using
the AS clause. 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 the
<replaceable class="PARAMETER">output_name</replaceable>
cannot be used in the WHERE or HAVING clauses; write out the
expression instead.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">from_item</replaceable></term>
<listitem>
<para>
A table reference, sub-SELECT, or JOIN clause. See below for details.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">condition</replaceable></term>
<listitem>
<para>
A boolean expression giving a result of true or false.
See the WHERE and HAVING clause descriptions below.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">select</replaceable></term>
<listitem>
<para>
A select statement with all features except the ORDER BY, FOR UPDATE,
and LIMIT clauses (even those can be used when the select is
parenthesized).
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
<para>
FROM items can contain:
<variablelist>
<varlistentry>
<term><replaceable class="PARAMETER">table_name</replaceable></term>
<listitem>
<para>
The name 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 indicate that descendant tables are to be scanned,
but in the current version, this is the default behavior.
(In releases before 7.1, ONLY was the default behavior.)
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">alias</replaceable></term>
<listitem>
<para>
A substitute name for the preceding
<replaceable class="PARAMETER">table_name</replaceable>.
An alias is used for brevity or to eliminate ambiguity for self-joins
(where the same table is scanned multiple times). 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.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">select</replaceable></term>
<listitem>
<para>
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 <emphasis>must</emphasis>
be provided for it.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">join_type</replaceable></term>
<listitem>
<para>
One of
<command>[ INNER ] JOIN</command>,
<command>LEFT [ OUTER ] JOIN</command>,
<command>RIGHT [ OUTER ] JOIN</command>,
<command>FULL [ OUTER ] JOIN</command>, or
<command>CROSS JOIN</command>.
For INNER and OUTER join types, exactly one of NATURAL,
ON <replaceable class="PARAMETER">join_condition</replaceable>, or
USING ( <replaceable class="PARAMETER">join_column_list</replaceable> )
must appear. For CROSS JOIN, none of these items may appear.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">join_condition</replaceable></term>
<listitem>
<para>
A qualification condition. This is similar to the WHERE condition
except that it only applies to the two from_items being joined in
this JOIN clause.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">join_column_list</replaceable></term>
<listitem>
<para>
A USING column list ( a, b, ... ) is shorthand for the ON condition
left_table.a = right_table.a AND left_table.b = right_table.b ...
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
<refsect2 id="R2-SQL-SELECT-2">
<refsect2info>
<date>1998-09-24</date>
</refsect2info>
<title>
Outputs
</title>
<para>
<variablelist>
<varlistentry>
<term>Rows</term>
<listitem>
<para>
The complete set of rows resulting from the query specification.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
<returnvalue><replaceable>count</replaceable></returnvalue>
</term>
<listitem>
<para>
The count of rows returned by the query.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
</refsynopsisdiv>
<refsect1 id="R1-SQL-SELECT-1">
<refsect1info>
<date>2000-12-11</date>
</refsect1info>
<title>
Description
</title>
<para>
<command>SELECT</command> will return rows from one or more tables.
Candidates for selection are rows which satisfy the WHERE condition;
if WHERE is omitted, all rows are candidates.
(See <xref linkend="sql-where" endterm="sql-where-title">.)
</para>
<para>
Actually, the returned rows are not directly the rows produced by the
FROM/WHERE/GROUP BY/HAVING clauses; rather, the output rows are formed
by computing the SELECT output expressions for each selected row.
<command>*</command> can be written in the output list as a shorthand
for all the columns of the selected rows. Also, one can write
<replaceable class="PARAMETER">table_name</replaceable><command>.*</command>
as a shorthand for the columns coming from just that table.
</para>
<para>
<command>DISTINCT</command> will eliminate duplicate rows from the
result.
<command>ALL</command> (the default) will return all candidate rows,
including duplicates.
</para>
<para>
<command>DISTINCT ON</command> eliminates rows that match on all the
specified expressions, keeping only the first row of each set of
duplicates. The DISTINCT ON expressions are interpreted using the
same rules as for ORDER BY items; see below.
Note that the <quote>first row</quote> of each set is unpredictable
unless <command>ORDER BY</command> is used to ensure that the desired
row appears first. For example,
<programlisting>
SELECT DISTINCT ON (location) location, time, report
FROM weatherReports
ORDER BY location, time DESC;
</programlisting>
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 of unpredictable age
for each location.
</para>
<para>
The GROUP BY clause allows a user to divide a table
into groups of rows that match on one or more values.
(See <xref linkend="sql-groupby" endterm="sql-groupby-title">.)
</para>
<para>
The HAVING clause allows selection of only those groups of rows
meeting the specified condition.
(See <xref linkend="sql-having" endterm="sql-having-title">.)
</para>
<para>
The ORDER BY clause causes the returned rows to be sorted in a specified
order. If ORDER BY is not given, the rows are returned in whatever order
the system finds cheapest to produce.
(See <xref linkend="sql-orderby" endterm="sql-orderby-title">.)
</para>
<para>
SELECT queries can be combined using UNION, INTERSECT, and EXCEPT
operators. Use parentheses if necessary to determine the ordering
of these operators.
</para>
<para>
The UNION operator computes the collection of rows
returned by the queries involved.
Duplicate rows are eliminated unless ALL is specified.
(See <xref linkend="sql-union" endterm="sql-union-title">.)
</para>
<para>
The INTERSECT operator computes the rows that are common to both queries.
Duplicate rows are eliminated unless ALL is specified.
(See <xref linkend="sql-intersect" endterm="sql-intersect-title">.)
</para>
<para>
The EXCEPT operator computes the rows returned by the first query but
not the second query.
Duplicate rows are eliminated unless ALL is specified.
(See <xref linkend="sql-except" endterm="sql-except-title">.)
</para>
<para>
The FOR UPDATE clause allows the SELECT statement to perform
exclusive locking of selected rows.
</para>
<para>
The LIMIT clause allows a subset of the rows produced by the query
to be returned to the user.
(See <xref linkend="sql-limit" endterm="sql-limit-title">.)
</para>
<para>
You must have SELECT privilege to a table to read its values
(See the <command>GRANT</command>/<command>REVOKE</command> statements).
</para>
<refsect2 id="SQL-FROM">
<refsect2info>
<date>2000-12-11</date>
</refsect2info>
<title id="sql-from-title">
FROM Clause
</title>
<para>
The FROM clause specifies one or more source tables for the SELECT.
If multiple sources are specified, the result is conceptually the
Cartesian product of all the rows in all the sources --- but usually
qualification conditions are added to restrict the returned rows to
a small subset of the Cartesian product.
</para>
<para>
When a FROM item is a simple table name, it implicitly includes rows
from sub-tables (inheritance children) of the table.
<command>ONLY</command> will
suppress rows from sub-tables of the table. Before
<Productname>Postgres</Productname> 7.1,
this was the default result, and adding sub-tables was done
by appending <command>*</command> to the table name.
This old behaviour is available via the command
<command>SET SQL_Inheritance TO OFF;</command>
</para>
<para>
A FROM item can also be a parenthesized sub-SELECT (note that an
alias clause is required for a sub-SELECT!). This is an extremely
handy feature since it's the only way to get multiple levels of
grouping, aggregation, or sorting in a single query.
</para>
<para>
Finally, a FROM item can be a JOIN clause, which combines two simpler
FROM items. (Use parentheses if necessary to determine the order
of nesting.)
</para>
<para>
A CROSS JOIN or INNER JOIN is a simple Cartesian product,
the same as you get from listing the two items at the top level of FROM.
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 couldn't do with plain FROM and
WHERE.
</para>
<para>
LEFT OUTER JOIN returns all rows in the qualified Cartesian product
(i.e., all combined rows that pass its ON condition), plus one copy of each
row in the left-hand table for which there was no right-hand row that
passed the ON condition. This left-hand row is extended to the full
width of the joined table by inserting NULLs for the right-hand columns.
Note that only the JOIN's own ON or USING condition is considered while
deciding which rows have matches. Outer ON or WHERE conditions are
applied afterwards.
</para>
<para>
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.
</para>
<para>
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).
</para>
<para>
For all the JOIN types except CROSS JOIN, you must write exactly one of
ON <replaceable class="PARAMETER">join_condition</replaceable>,
USING ( <replaceable class="PARAMETER">join_column_list</replaceable> ),
or NATURAL. ON is the most general case: you can write any qualification
expression involving the two tables to be joined.
A USING column list ( a, b, ... ) is shorthand for the ON condition
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 similarly-named columns in the tables.
</para>
</refsect2>
<refsect2 id="SQL-WHERE">
<refsect2info>
<date>2000-03-15</date>
</refsect2info>
<title id="sql-where-title">
WHERE Clause
</title>
<para>
The optional WHERE condition has the general form:
<synopsis>
WHERE <replaceable class="PARAMETER">boolean_expr</replaceable>
</synopsis>
<replaceable class="PARAMETER">boolean_expr</replaceable>
can consist of any expression which evaluates to a boolean value.
In many cases, this expression will be:
<synopsis>
<replaceable class="PARAMETER">expr</replaceable> <replaceable class="PARAMETER">cond_op</replaceable> <replaceable class="PARAMETER">expr</replaceable>
</synopsis>
or
<synopsis>
<replaceable class="PARAMETER">log_op</replaceable> <replaceable class="PARAMETER">expr</replaceable>
</synopsis>
where <replaceable class="PARAMETER">cond_op</replaceable>
can be one of: =, &lt;, &lt;=, &gt;, &gt;= or &lt;&gt;,
a conditional operator like ALL, ANY, IN, LIKE, or a
locally defined operator,
and <replaceable class="PARAMETER">log_op</replaceable> can be one
of: AND, OR, NOT.
SELECT will ignore all rows for which the WHERE condition does not return
TRUE.
</para>
</refsect2>
<refsect2 id="SQL-GROUPBY">
<refsect2info>
<date>2000-03-15</date>
</refsect2info>
<title id="sql-groupby-title">
GROUP BY Clause
</title>
<para>
GROUP BY specifies a grouped table derived by the application
of this clause:
<synopsis>
GROUP BY <replaceable class="PARAMETER">expression</replaceable> [, ...]
</synopsis>
</para>
<para>
GROUP BY will condense into a single row all selected rows that share the
same values for the grouped columns. Aggregate functions, if any,
are computed across all rows making 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
output expression(s) to refer to
ungrouped columns except within aggregate functions, since there
would be more than one possible value to return for an ungrouped column.
</para>
<para>
A GROUP BY item can be an input column name, or the name or ordinal
number of an output column (SELECT expression), or it can be 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.
</para>
</refsect2>
<refsect2 id="SQL-HAVING">
<refsect2info>
<date>2000-03-15</date>
</refsect2info>
<title id="sql-having-title">
HAVING Clause
</title>
<para>
The optional HAVING condition has the general form:
<synopsis>
HAVING <replaceable class="PARAMETER">boolean_expr</replaceable>
</synopsis>
where <replaceable class="PARAMETER">boolean_expr</replaceable> is the same
as specified for the WHERE clause.
</para>
<para>
HAVING specifies a grouped table derived by the elimination
of group rows that do not satisfy the
<replaceable class="PARAMETER">boolean_expr</replaceable>.
HAVING is different from WHERE:
WHERE filters individual rows before application of GROUP BY,
while HAVING filters group rows created by GROUP BY.
</para>
<para>
Each column referenced in
<replaceable class="PARAMETER">boolean_expr</replaceable> shall unambiguously
reference a grouping column, unless the reference appears within an
aggregate function.
</para>
</refsect2>
<refsect2 id="SQL-ORDERBY">
<refsect2info>
<date>2000-03-15</date>
</refsect2info>
<title id="sql-orderby-title">
ORDER BY Clause
</title>
<para>
<synopsis>
ORDER BY <replaceable class="PARAMETER">expression</replaceable> [ ASC | DESC | USING <replaceable class="PARAMETER">operator</replaceable> ] [, ...]
</synopsis></para>
<para>
An ORDER BY item can be the name or ordinal
number of an output column (SELECT expression), or it can be an arbitrary
expression formed from input-column values. In case of ambiguity, an
ORDER BY name will be interpreted as an output-column name.
</para>
<para>
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 proper name.
This is never absolutely necessary because it is always possible
to assign a name to a result column using the AS clause, e.g.:
<programlisting>
SELECT title, date_prod + 1 AS newlen FROM films ORDER BY newlen;
</programlisting></para>
<para>
It is also possible to ORDER BY
arbitrary expressions (an extension to SQL92),
including fields that do not appear in the
SELECT result list.
Thus the following statement is legal:
<programlisting>
SELECT name FROM distributors ORDER BY code;
</programlisting>
A limitation of this feature is that an ORDER BY clause applying to the
result of a UNION, INTERSECT, or EXCEPT query may only specify an output
column name or number, not an expression.
</para>
<para>
Note that if an ORDER BY item 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
mandated by the SQL92 standard.
</para>
<para>
Optionally one may add the keyword DESC (descending)
or ASC (ascending) after each column name in the ORDER BY clause.
If not specified, ASC is assumed by default. Alternatively, a
specific ordering operator name may be specified. ASC is equivalent
to USING &lt; and DESC is equivalent to USING &gt;.
</para>
</refsect2>
<refsect2 id="SQL-UNION">
<refsect2info>
<date>2000-12-11</date>
</refsect2info>
<title id="sql-union-title">
UNION Clause
</title>
<para>
<synopsis>
<replaceable class="PARAMETER">table_query</replaceable> UNION [ ALL ] <replaceable class="PARAMETER">table_query</replaceable>
[ ORDER BY <replaceable class="PARAMETER">expression</replaceable> [ ASC | DESC | USING <replaceable class="PARAMETER">operator</replaceable> ] [, ...] ]
[ LIMIT [ <replaceable class="PARAMETER">start</replaceable> , ] { <replaceable class="PARAMETER">count</replaceable> | ALL } ]
[ OFFSET <replaceable class="PARAMETER">start</replaceable> ]
</synopsis>
where
<replaceable class="PARAMETER">table_query</replaceable>
specifies any select expression without an ORDER BY, FOR UPDATE,
or LIMIT clause. (ORDER BY and LIMIT can be attached to a sub-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.)
</para>
<para>
The UNION operator computes the collection (set union) of the rows
returned by the queries involved.
The two SELECTs that represent the direct operands of the UNION must
produce the same number of columns, and corresponding columns must be
of compatible data types.
</para>
<para>
The result of UNION does not contain any duplicate rows
unless the ALL option is specified. ALL prevents elimination of
duplicates.
</para>
<para>
Multiple UNION operators in the same SELECT statement are
evaluated left to right, unless otherwise indicated by parentheses.
</para>
<para>
Currently, FOR UPDATE may not be specified either for a UNION result
or for the inputs of a UNION.
</para>
</refsect2>
<refsect2 id="SQL-INTERSECT">
<refsect2info>
<date>2000-12-11</date>
</refsect2info>
<title id="sql-intersect-title">
INTERSECT Clause
</title>
<para>
<synopsis>
<replaceable class="PARAMETER">table_query</replaceable> INTERSECT [ ALL ] <replaceable class="PARAMETER">table_query</replaceable>
[ ORDER BY <replaceable class="PARAMETER">expression</replaceable> [ ASC | DESC | USING <replaceable class="PARAMETER">operator</replaceable> ] [, ...] ]
[ LIMIT [ <replaceable class="PARAMETER">start</replaceable> , ] { <replaceable class="PARAMETER">count</replaceable> | ALL } ]
[ OFFSET <replaceable class="PARAMETER">start</replaceable> ]
</synopsis>
where
<replaceable class="PARAMETER">table_query</replaceable>
specifies any select expression without an ORDER BY, FOR UPDATE,
or LIMIT clause.
</para>
<para>
INTERSECT is similar to UNION, except that it produces only rows that
appear in both query outputs, rather than rows that appear in either.
</para>
<para>
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 L and n duplicates in R will appear min(m,n) times.
</para>
<para>
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) unless otherwise specified by parentheses.
</para>
</refsect2>
<refsect2 id="SQL-EXCEPT">
<refsect2info>
<date>2000-12-11</date>
</refsect2info>
<title id="sql-except-title">
EXCEPT Clause
</title>
<para>
<synopsis>
<replaceable class="PARAMETER">table_query</replaceable> EXCEPT [ ALL ] <replaceable class="PARAMETER">table_query</replaceable>
[ ORDER BY <replaceable class="PARAMETER">expression</replaceable> [ ASC | DESC | USING <replaceable class="PARAMETER">operator</replaceable> ] [, ...] ]
[ LIMIT [ <replaceable class="PARAMETER">start</replaceable> , ] { <replaceable class="PARAMETER">count</replaceable> | ALL } ]
[ OFFSET <replaceable class="PARAMETER">start</replaceable> ]
</synopsis>
where
<replaceable class="PARAMETER">table_query</replaceable>
specifies any select expression without an ORDER BY, FOR UPDATE,
or LIMIT clause.
</para>
<para>
EXCEPT is similar to UNION, except that it produces only rows that
appear in the left query's output but not in the right query's output.
</para>
<para>
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 L and n duplicates in R will appear max(m-n,0) times.
</para>
<para>
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.
</para>
</refsect2>
<refsect2 id="SQL-LIMIT">
<refsect2info>
<date>2000-02-20</date>
</refsect2info>
<title id="sql-limit-title">
LIMIT Clause
</title>
<para>
<synopsis>
LIMIT [ <replaceable class="PARAMETER">start</replaceable> , ] { <replaceable class="PARAMETER">count</replaceable> | ALL }
OFFSET <replaceable class="PARAMETER">start</replaceable>
</synopsis>
where
<replaceable class="PARAMETER">count</replaceable> specifies the
maximum number of rows to return, and
<replaceable class="PARAMETER">start</replaceable> specifies the
number of rows to skip before starting to return rows.
</para>
<para>
LIMIT allows you to retrieve just a portion of the rows that are generated
by the rest of the query. If a limit count is given, no more than that
many rows will be returned. If an offset is given, that many rows will
be skipped before starting to return rows.
</para>
<para>
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.
</para>
<para>
As of <productname>Postgres</productname> 7.0, 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 <emphasis>will give inconsistent results</emphasis> 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.
</para>
</refsect2>
</refsect1>
<refsect1 id="R1-SQL-SELECT-2">
<title>
Usage
</title>
<para>
To join the table <literal>films</literal> with the table
<literal>distributors</literal>:
<programlisting>
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
Une Femme est une Femme | 102 | Jean Luc Godard | 1961-03-12 | Romantic
Vertigo | 103 | Paramount | 1958-11-14 | Action
Becket | 103 | Paramount | 1964-02-03 | Drama
48 Hrs | 103 | Paramount | 1982-10-22 | Action
War and Peace | 104 | Mosfilm | 1967-02-12 | Drama
West Side Story | 105 | United Artists | 1961-01-03 | Musical
Bananas | 105 | United Artists | 1971-07-13 | Comedy
Yojimbo | 106 | Toho | 1961-06-16 | Drama
There's a Girl in my Soup | 107 | Columbia | 1970-06-11 | Comedy
Taxi Driver | 107 | Columbia | 1975-05-15 | Action
Absence of Malice | 107 | Columbia | 1981-11-15 | Action
Storia di una donna | 108 | Westward | 1970-08-15 | Romantic
The King and I | 109 | 20th Century Fox | 1956-08-11 | Musical
Das Boot | 110 | Bavaria Atelier | 1981-11-11 | Drama
Bed Knobs and Broomsticks | 111 | Walt Disney | | Musical
(17 rows)
</programlisting>
</para>
<para>
To sum the column <literal>len</literal> of all films and group
the results by <literal>kind</literal>:
<programlisting>
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
(5 rows)
</programlisting>
</para>
<para>
To sum the column <literal>len</literal> of all films, group
the results by <literal>kind</literal> and show those group totals
that are less than 5 hours:
<programlisting>
SELECT kind, SUM(len) AS total
FROM films
GROUP BY kind
HAVING SUM(len) < INTERVAL '5 hour';
kind | total
----------+-------
Comedy | 02:58
Romantic | 04:38
(2 rows)
</programlisting>
</para>
<para>
The following two examples are identical ways of sorting the individual
results according to the contents of the second column
(<literal>name</literal>):
<programlisting>
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
(13 rows)
</programlisting>
</para>
<para>
This example shows how to obtain the union of the tables
<literal>distributors</literal> and
<literal>actors</literal>, restricting the results to those that begin
with letter W in each table. Only distinct rows are wanted, so the
ALL keyword is omitted:
<programlisting>
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
</programlisting>
</para>
</refsect1>
<refsect1 id="R1-SQL-SELECT-3">
<title>
Compatibility
</title>
<refsect2 id="R2-SQL-SELECT-4">
<refsect2info>
<date>1998-09-24</date>
</refsect2info>
<title>
<acronym>Extensions</acronym>
</title>
<para>
<productname>Postgres</productname> allows one to omit
the <command>FROM</command> clause from a query. This feature
was retained from the original PostQuel query language. It has
a straightforward use to compute the results of simple constant
expressions:
<programlisting>
SELECT 2+2;
?column?
----------
4
</programlisting>
Some other DBMSes cannot do this except by introducing a dummy one-row
table to do the select from. A less obvious use is to abbreviate a
normal select from one or more tables:
<programlisting>
SELECT distributors.* WHERE distributors.name = 'Westward';
did | name
-----+----------
108 | Westward
</programlisting>
This works because an implicit FROM item is added for each table that is
referenced in the query but not mentioned in FROM. While this is a convenient
shorthand, it's easy to misuse. For example, the query
<programlisting>
SELECT distributors.* FROM distributors d;
</programlisting>
is probably a mistake; most likely the user meant
<programlisting>
SELECT d.* FROM distributors d;
</programlisting>
rather than the unconstrained join
<programlisting>
SELECT distributors.* FROM distributors d, distributors distributors;
</programlisting>
that he will actually get. To help detect this sort of mistake,
<Productname>Postgres</Productname> 7.1
and later will warn if the implicit-FROM feature is used in a query that also
contains an explicit FROM clause.
</para>
</refsect2>
<refsect2 id="R2-SQL-SELECT-5">
<refsect2info>
<date>1998-09-24</date>
</refsect2info>
<title>
<acronym>SQL92</acronym>
</title>
<para>
</para>
<refsect3 id="R3-SQL-SELECT-1">
<refsect3info>
<date>1998-04-15</date>
</refsect3info>
<title>
SELECT Clause
</title>
<para>
In the <acronym>SQL92</acronym> standard, the optional keyword <literal>AS</>
is just noise and can be
omitted without affecting the meaning.
The <productname>Postgres</productname> parser requires this keyword when
renaming output columns because the type extensibility features lead to
parsing ambiguities
in this context. <literal>AS</literal> is optional in FROM items, however.</para>
<para>
The DISTINCT ON phrase is not part of <acronym>SQL92</acronym>.
Nor are LIMIT and OFFSET.
</para>
<para>
In <acronym>SQL92</acronym>, an ORDER BY clause may only use result
column names or numbers, while a GROUP BY clause may only use input
column names.
<productname>Postgres</productname> extends each of these clauses to
allow the other choice as well (but it uses the standard's interpretation
if there is ambiguity).
<productname>Postgres</productname> also allows both clauses to specify
arbitrary expressions. Note that names appearing in an expression will
always be taken as input-column names, not as result-column names.
</para>
</refsect3>
<refsect3 id="R3-SQL-UNION-1">
<refsect3info>
<date>1998-09-24</date>
</refsect3info>
<title>
UNION/INTERSECT/EXCEPT Clause
</title>
<para>
The <acronym>SQL92</acronym> syntax for UNION/INTERSECT/EXCEPT allows an
additional CORRESPONDING BY option:
<synopsis>
<replaceable class="PARAMETER">table_query</replaceable> UNION [ALL]
[CORRESPONDING [BY (<replaceable class="PARAMETER">column</replaceable> [,...])]]
<replaceable class="PARAMETER">table_query</replaceable>
</synopsis></para>
<para>
The CORRESPONDING BY clause is not supported by
<productname>Postgres</productname>.
</para>
</refsect3>
</refsect2>
</refsect1>
</refentry>
<!-- Keep this comment at the end of the file
Local variables:
mode: sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"../reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:"/usr/lib/sgml/catalog"
sgml-local-ecat-files:nil
End:
-->