postgresql/doc/src/sgml/ref/select.sgml
Thomas G. Lockhart 7fcbc5ddf0 Fix markup to include all closing tags.
Required by newest versions of DocBook and style sheets.
1999-04-06 15:41:20 +00:00

773 lines
22 KiB
Plaintext

<refentry id="SQL-SELECT">
<refmeta>
<refentrytitle>
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>1998-09-24</date>
</refsynopsisdivinfo>
<synopsis>
SELECT [ALL|DISTINCT [ON <replaceable class="PARAMETER">column</replaceable>] ]
<replaceable class="PARAMETER">expression</replaceable> [ AS <replaceable class="PARAMETER">name</replaceable> ] [, ...]
[ INTO [TEMP] [TABLE] <replaceable class="PARAMETER">new_table</replaceable> ]
[ FROM <replaceable class="PARAMETER">table</replaceable> [<replaceable class="PARAMETER">alias</replaceable> ] [, ...] ]
[ WHERE <replaceable class="PARAMETER">condition</replaceable> ]
[ GROUP BY <replaceable class="PARAMETER">column</replaceable> [, ...] ]
[ HAVING <replaceable class="PARAMETER">condition</replaceable> [, ...] ]
[ { UNION [ALL] | INTERSECT | EXCEPT } <replaceable class="PARAMETER">select</replaceable> ]
[ ORDER BY <replaceable class="PARAMETER">column</replaceable> [ ASC | DESC ] [, ...] ]
</synopsis>
<refsect2 id="R2-SQL-SELECT-1">
<refsect2info>
<date>1998-09-24</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">name</replaceable>
</term>
<listitem>
<para>
Specifies another name for a column or an expression using
the AS clause. <replaceable class="PARAMETER">name</replaceable>
cannot be used in the WHERE
condition. It can, however, be referenced in associated
ORDER BY or GROUP BY clauses.
</para>
</listitem>
</varlistentry>
<VARLISTENTRY>
<TERM>
TEMP
</TERM>
<LISTITEM>
<PARA>
The table is created unique to this session, and is
automatically dropped on session exit.
</PARA>
</LISTITEM>
</VARLISTENTRY>
<varlistentry>
<term>
<replaceable class="PARAMETER">new_table</replaceable>
</term>
<listitem>
<para>
If the INTO TABLE clause is specified, the result of the
query will be stored in another table with the indicated
name.
If <replaceable class="PARAMETER">new_table</replaceable> does
not exist, it will be created automatically.
Refer to <command>SELECT INTO</command> for more information.
<note>
<para>
The <command>CREATE TABLE AS</command> statement will also
create a new table from a select query.
</para>
</note>
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
<replaceable class="PARAMETER">table</replaceable>
</term>
<listitem>
<para>
The name of an existing table referenced by the FROM clause.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
<replaceable class="PARAMETER">alias</replaceable>
</term>
<listitem>
<para>
An alternate name for the preceding
<replaceable class="PARAMETER">table</replaceable>.
It is used for brevity or to eliminate ambiguity for joins
within a single table.
</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 clause.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
<replaceable class="PARAMETER">column</replaceable>
</term>
<listitem>
<para>
The name of a table's column.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
<replaceable class="PARAMETER">select</replaceable>
</term>
<listitem>
<para>
A select statement with all features except the ORDER BY clause.
</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>1998-09-24</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.</para>
<para>
<command>DISTINCT</command> will eliminate all duplicate rows from the
selection.
<command>DISTINCT ON <replaceable class="PARAMETER">column</replaceable></command> will eliminate all duplicates in the specified column; this is
equivalent to using <command>GROUP BY <replaceable class="PARAMETER">column</replaceable></command>. <command>ALL</command> will return all candidate rows,
including duplicates.</para>
<para>
The GROUP BY clause allows a user to divide a table
conceptually into groups. (See GROUP BY clause).</para>
<para>
The HAVING clause specifies a grouped table derived by the
elimination of groups from the result of the previously
specified clause. (See HAVING clause).</para>
<para>
The ORDER BY clause allows a user to specify that he/she
wishes the rows sorted according to the ASCending or
DESCending mode operator. (See ORDER BY clause)</para>
<para>
The UNION clause allows the result to be the collection of rows
returned by the queries involved. (See UNION clause).</para>
<para>
The INTERSECT give you the rows that are common to both queries.
(See INTERSECT clause).</para>
<para>
The EXCEPT give you the rows in the upper query not in the lower query.
(See EXCEPT clause).</para>
<para>
You must have SELECT privilege to a table to read its values
(See <command>GRANT</command>/<command>REVOKE</command> statements).
</para>
<refsect2 id="R2-SQL-WHERE-2">
<refsect2info>
<date>1998-09-24</date>
</refsect2info>
<title>
WHERE Clause
</title>
<para>
The optional WHERE condition has the general form:
<synopsis>
WHERE <replaceable class="PARAMETER">expr</replaceable> <replaceable class="PARAMETER">cond_op</replaceable> <replaceable class="PARAMETER">expr</replaceable> [ <replaceable class="PARAMETER">log_op</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, et cetera or a
locally-defined operator,
and <replaceable class="PARAMETER">log_op</replaceable> can be one
of: AND, OR, NOT.
The comparison returns either TRUE or FALSE and all
instances will be discarded
if the expression evaluates to FALSE.
</para>
</refsect2>
<refsect2 id="R2-SQL-GROUPBY-2">
<refsect2info>
<date>1998-09-24</date>
</refsect2info>
<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">column</replaceable> [, ...]
</synopsis></para>
<para>
GROUP BY will condense into a single row all rows that share the same values for the
grouped columns; aggregates return values derived from all rows that make up the group. The value returned for an ungrouped
and unaggregated column is dependent on the order in which rows happen to be read from the database.
</para>
</refsect2>
<refsect2 id="R2-SQL-HAVING-2">
<refsect2info>
<date>1998-09-24</date>
</refsect2info>
<title>
HAVING Clause
</title>
<para>
The optional HAVING condition has the general form:
<synopsis>
HAVING <replaceable class="PARAMETER">cond_expr</replaceable>
</synopsis>
where <replaceable class="PARAMETER">cond_expr</replaceable> is the same
as specified for the WHERE clause.</para>
<para>
HAVING specifies a grouped table derived by the elimination
of groups from the result of the previously specified clause
that do not meet the <replaceable class="PARAMETER">cond_expr</replaceable>.</para>
<para>
Each column referenced in
<replaceable class="PARAMETER">cond_expr</replaceable> shall unambiguously
reference a grouping column.
</para>
</refsect2>
<refsect2 id="R2-SQL-ORDERBYCLAUSE-2">
<refsect2info>
<date>1998-09-24</date>
</refsect2info>
<title>
ORDER BY Clause
</title>
<para>
<synopsis>
ORDER BY <replaceable class="PARAMETER">column</replaceable> [ ASC | DESC ] [, ...]
</synopsis></para>
<para>
<replaceable class="PARAMETER">column</replaceable> can be either a column
name or an ordinal number.</para>
<para>
The ordinal numbers refers to the ordinal (left-to-right) position
of the 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
assign a name
to a calculated column using the AS clause, e.g.:
<programlisting>
SELECT title, date_prod + 1 AS newlen FROM films ORDER BY newlen;
</programlisting></para>
<para>
From release 6.4 of PostgreSQL, the columns in the ORDER BY clause do not need to appear in the SELECT clause.
Thus the following statement is now legal:
<programlisting>
SELECT name FROM distributors ORDER BY code;
</programlisting></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.</para>
</refsect2>
<refsect2 id="R2-SQL-UNION-2">
<refsect2info>
<date>1998-09-24</date>
</refsect2info>
<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">column</replaceable> [ ASC | DESC ] [, ...] ]
</synopsis>
where
<replaceable class="PARAMETER">table_query</replaceable>
specifies any select expression without an ORDER BY clause.</para>
<para>
The UNION clause allows the result to be the collection of rows
returned by the queries involved. (See UNION clause).
The two tables that represent the direct operands of the UNION must
have the same number of columns, and corresponding columns must be
of compatible data types.</para>
<para>
By default, the result of UNION does not contain any duplicate rows
unless the ALL clause is specified.</para>
<para>
Multiple UNION operators in the same SELECT statement are
evaluated left to right.
Note that the ALL keyword is not global in nature, being
applied only for the current pair of table results.</para>
</refsect2>
<refsect2 id="R2-SQL-INTERSECT-2">
<refsect2info>
<date>1998-09-24</date>
</refsect2info>
<title>
INTERSECT Clause
</title>
<para>
<synopsis>
<replaceable class="PARAMETER">table_query</replaceable> INTERSECT <replaceable class="PARAMETER">table_query</replaceable>
[ ORDER BY <replaceable class="PARAMETER">column</replaceable> [ ASC | DESC ] [, ...] ]
</synopsis>
where
<replaceable class="PARAMETER">table_query</replaceable>
specifies any select expression without an ORDER BY clause.</para>
<para>
The INTERSECT clause allows the result to be all rows that are
common to the involved queries. (See INTERSECT clause).
The two tables that represent the direct operands of the INTERSECT must
have the same number of columns, and corresponding columns must be
of compatible data types.</para>
<para>
Multiple INTERSECT operators in the same SELECT statement are
evaluated left to right.
</para>
</refsect2>
<refsect2 id="R2-SQL-EXCEPT-2">
<refsect2info>
<date>1998-09-24</date>
</refsect2info>
<title>
EXCEPT Clause
</title>
<para>
<synopsis>
<replaceable class="PARAMETER">table_query</replaceable> EXCEPT <replaceable class="PARAMETER">table_query</replaceable>
[ ORDER BY <replaceable class="PARAMETER">column</replaceable> [ ASC | DESC ] [, ...] ]
</synopsis>
where
<replaceable class="PARAMETER">table_query</replaceable>
specifies any select expression without an ORDER BY clause.</para>
<para>
The EXCEPT clause allows the result to be rows from the upper query
that are not in the lower query. (See EXCEPT clause).
The two tables that represent the direct operands of the EXCEPT must
have the same number of columns, and corresponding columns must be
of compatible data types.</para>
<para>
Multiple EXCEPT operators in the same SELECT statement are
evaluated left to right.
</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>:
</para>
<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
</programlisting>
<para>
To sum the column <literal>len</literal> of all films and group
the results by <literal>kind</literal>:
</para>
<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
</programlisting>
<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:
</para>
<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
</programlisting>
<para>
The following two examples are identical ways of sorting the individual
results according to the contents of the second column
(<literal>name</literal>):
</para>
<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
</programlisting>
<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 to be used, so the
ALL keyword is omitted:
</para>
<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>
</refsect1>
<refsect1 id="R1-SQL-SELECT-3">
<title>
Compatibility
</title>
<para>
</para>
<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:
<programlisting>
SELECT distributors.* WHERE name = 'Westwood';
did|name
---+----------------
108|Westward
</programlisting>
</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 "AS"
is just noise and can be
omitted without affecting the meaning.
The <productname>Postgres</productname> parser requires this keyword when
renaming columns because the type extensibility features lead to
parsing ambiguities
in this context.</para>
<para>
In the <acronym>SQL92</acronym> standard, the new column name
specified in an
"AS" clause may be referenced in GROUP BY and HAVING clauses.
This is not currently
allowed in <productname>Postgres</productname>.
</para>
<para>
The DISTINCT ON phrase is not part of <acronym>SQL92</acronym>.
</para>
</refsect3>
<refsect3 id="R3-SQL-UNION-1">
<refsect3info>
<date>1998-09-24</date>
</refsect3info>
<title>
UNION Clause
</title>
<para>
The <acronym>SQL92</acronym> syntax for UNION allows an
additional CORRESPONDING BY clause:
<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>
<refentry id="SQL-SELECTINTO">
<refmeta>
<refentrytitle>
SELECT INTO
</refentrytitle>
<refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta>
<refnamediv>
<refname>
SELECT INTO
</refname>
<refpurpose>
Create a new table from an existing table or view
</refpurpose></refnamediv>
<refsynopsisdiv>
<refsynopsisdivinfo>
<date>1998-09-22</date>
</refsynopsisdivinfo>
<synopsis>
SELECT [ ALL | DISTINCT ] <replaceable class="PARAMETER">expression</replaceable> [ AS <replaceable class="PARAMETER">name</replaceable> ] [, ...]
INTO [TEMP] [ TABLE ] <replaceable class="PARAMETER">new_table</replaceable> ]
[ FROM <replaceable class="PARAMETER">table</replaceable> [<replaceable class="PARAMETER">alias</replaceable>] [, ...] ]
[ WHERE <replaceable class="PARAMETER">condition</replaceable> ]
[ GROUP BY <replaceable class="PARAMETER">column</replaceable> [, ...] ]
[ HAVING <replaceable class="PARAMETER">condition</replaceable> [, ...] ]
[ { UNION [ALL] | INTERSECT | EXCEPT } <replaceable class="PARAMETER">select</replaceable>]
[ ORDER BY <replaceable class="PARAMETER">column</replaceable> [ ASC | DESC ] [, ...] ]
</synopsis>
<refsect2 id="R2-SQL-SELECTINTO-1">
<refsect2info>
<date>1998-09-22</date>
</refsect2info>
<title>
Inputs
</title>
<para>
All input fields are described in detail for SELECT.
</para>
</refsect2>
<refsect2 id="R2-SQL-SELECTINTO-2">
<refsect2info>
<date>1998-09-22</date>
</refsect2info>
<title>
Outputs
</title>
<para>
All output fields are described in detail for SELECT.
</para>
</refsect2>
</refsynopsisdiv>
<refsect1 id="R1-SQL-SELECTINTO-1">
<refsect1info>
<date>1998-09-22</date>
</refsect1info>
<title>
Description
</title>
<para>
SELECT INTO creates a new table from the results of a query. Typically, this
query draws data from an existing table, but any SQL query is allowed.
<note>
<para>
CREATE TABLE AS is functionally equivalent to the SELECT INTO command.
</para>
</note>
</para>
</refsect1>
</refentry>
<!-- Keep this comment at the end of the file
Local variables:
mode: sgml
sgml-omittag:t
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:
-->