Commit b5b1eb80 authored by Tom Lane's avatar Tom Lane

Documentation for VALUES lists. Joe Conway and Tom Lane

parent 5f04ce31
<!-- $PostgreSQL: pgsql/doc/src/sgml/dml.sgml,v 1.13 2006/02/18 23:14:45 neilc Exp $ --> <!-- $PostgreSQL: pgsql/doc/src/sgml/dml.sgml,v 1.14 2006/09/18 19:54:01 tgl Exp $ -->
<chapter id="dml"> <chapter id="dml">
<title>Data Manipulation</title> <title>Data Manipulation</title>
...@@ -93,6 +93,16 @@ INSERT INTO products DEFAULT VALUES; ...@@ -93,6 +93,16 @@ INSERT INTO products DEFAULT VALUES;
</programlisting> </programlisting>
</para> </para>
<para>
You can insert multiple rows in a single command:
<programlisting>
INSERT INTO products (product_no, name, price) VALUES
(1, 'Cheese', 9.99),
(2, 'Bread', 1.99),
(3, 'Milk', 2.99);
</programlisting>
</para>
<tip> <tip>
<para> <para>
When inserting a lot of data at the same time, considering using When inserting a lot of data at the same time, considering using
......
<!-- $PostgreSQL: pgsql/doc/src/sgml/queries.sgml,v 1.35 2006/02/18 23:14:45 neilc Exp $ --> <!-- $PostgreSQL: pgsql/doc/src/sgml/queries.sgml,v 1.36 2006/09/18 19:54:01 tgl Exp $ -->
<chapter id="queries"> <chapter id="queries">
<title>Queries</title> <title>Queries</title>
...@@ -104,7 +104,7 @@ SELECT random(); ...@@ -104,7 +104,7 @@ SELECT random();
produce a virtual table that provides the rows that are passed to produce a virtual table that provides the rows that are passed to
the select list to compute the output rows of the query. the select list to compute the output rows of the query.
</para> </para>
<sect2 id="queries-from"> <sect2 id="queries-from">
<title>The <literal>FROM</literal> Clause</title> <title>The <literal>FROM</literal> Clause</title>
...@@ -253,12 +253,12 @@ FROM <replaceable>table_reference</replaceable> <optional>, <replaceable>table_r ...@@ -253,12 +253,12 @@ FROM <replaceable>table_reference</replaceable> <optional>, <replaceable>table_r
<para> <para>
<indexterm> <indexterm>
<primary>join</primary> <primary>join</primary>
<secondary>natural</secondary> <secondary>natural</secondary>
</indexterm> </indexterm>
<indexterm> <indexterm>
<primary>natural join</primary> <primary>natural join</primary>
</indexterm> </indexterm>
Finally, <literal>NATURAL</> is a shorthand form of Finally, <literal>NATURAL</> is a shorthand form of
<literal>USING</>: it forms a <literal>USING</> list <literal>USING</>: it forms a <literal>USING</> list
consisting of exactly those column names that appear in both consisting of exactly those column names that appear in both
...@@ -511,33 +511,36 @@ SELECT * FROM some_very_long_table_name s JOIN another_fairly_long_name a ON s.i ...@@ -511,33 +511,36 @@ SELECT * FROM some_very_long_table_name s JOIN another_fairly_long_name a ON s.i
<programlisting> <programlisting>
SELECT * FROM my_table AS m WHERE my_table.a &gt; 5; SELECT * FROM my_table AS m WHERE my_table.a &gt; 5;
</programlisting> </programlisting>
is not valid SQL syntax. What will actually happen (this is a is not valid according to the SQL standard. In
<productname>PostgreSQL</productname> extension to the standard) <productname>PostgreSQL</productname> this will draw an error if the
is that an implicit table reference is added to the <xref linkend="guc-add-missing-from"> configuration variable is
<literal>off</>. If it is <literal>on</>, an implicit table reference
will be added to the
<literal>FROM</literal> clause, so the query is processed as if <literal>FROM</literal> clause, so the query is processed as if
it were written as it were written as
<programlisting> <programlisting>
SELECT * FROM my_table AS m, my_table AS my_table WHERE my_table.a &gt; 5; SELECT * FROM my_table AS m, my_table AS my_table WHERE my_table.a &gt; 5;
</programlisting> </programlisting>
which will result in a cross join, which is usually not what you That will result in a cross join, which is usually not what you want.
want.
</para> </para>
<para> <para>
Table aliases are mainly for notational convenience, but it is Table aliases are mainly for notational convenience, but it is
necessary to use them when joining a table to itself, e.g., necessary to use them when joining a table to itself, e.g.,
<programlisting> <programlisting>
SELECT * FROM my_table AS a CROSS JOIN my_table AS b ... SELECT * FROM people AS mother JOIN people AS child ON mother.id = child.mother_id;
</programlisting> </programlisting>
Additionally, an alias is required if the table reference is a Additionally, an alias is required if the table reference is a
subquery (see <xref linkend="queries-subqueries">). subquery (see <xref linkend="queries-subqueries">).
</para> </para>
<para> <para>
Parentheses are used to resolve ambiguities. The following Parentheses are used to resolve ambiguities. In the following example,
statement will assign the alias <literal>b</literal> to the the first statement assigns the alias <literal>b</literal> to the second
result of the join, unlike the previous example: instance of <literal>my_table</>, but the second statement assigns the
alias to the result of the join:
<programlisting> <programlisting>
SELECT * FROM my_table AS a CROSS JOIN my_table AS b ...
SELECT * FROM (my_table AS a CROSS JOIN my_table) AS b ... SELECT * FROM (my_table AS a CROSS JOIN my_table) AS b ...
</programlisting> </programlisting>
</para> </para>
...@@ -592,6 +595,17 @@ FROM (SELECT * FROM table1) AS alias_name ...@@ -592,6 +595,17 @@ FROM (SELECT * FROM table1) AS alias_name
reduced to a plain join, arise when the subquery involves reduced to a plain join, arise when the subquery involves
grouping or aggregation. grouping or aggregation.
</para> </para>
<para>
A subquery can also be a <command>VALUES</> list:
<programlisting>
FROM (VALUES ('anne', 'smith'), ('bob', 'jones'), ('joe', 'blow'))
AS names(first, last)
</programlisting>
Again, a table alias is required. Assigning alias names to the columns
of the <command>VALUES</> list is optional, but is good practice.
For more information see <xref linkend="queries-values">.
</para>
</sect3> </sect3>
<sect3 id="queries-tablefunctions"> <sect3 id="queries-tablefunctions">
...@@ -814,7 +828,7 @@ SELECT <replaceable>select_list</replaceable> ...@@ -814,7 +828,7 @@ SELECT <replaceable>select_list</replaceable>
(3 rows) (3 rows)
</screen> </screen>
</para> </para>
<para> <para>
In the second query, we could not have written <literal>SELECT * In the second query, we could not have written <literal>SELECT *
FROM test1 GROUP BY x</literal>, because there is no single value FROM test1 GROUP BY x</literal>, because there is no single value
...@@ -1194,7 +1208,7 @@ SELECT DISTINCT ON (<replaceable>expression</replaceable> <optional>, <replaceab ...@@ -1194,7 +1208,7 @@ SELECT DISTINCT ON (<replaceable>expression</replaceable> <optional>, <replaceab
<indexterm zone="queries-order"> <indexterm zone="queries-order">
<primary>ORDER BY</primary> <primary>ORDER BY</primary>
</indexterm> </indexterm>
<para> <para>
After a query has produced an output table (after the select list After a query has produced an output table (after the select list
has been processed) it can optionally be sorted. If sorting is not has been processed) it can optionally be sorted. If sorting is not
...@@ -1335,4 +1349,74 @@ SELECT <replaceable>select_list</replaceable> ...@@ -1335,4 +1349,74 @@ SELECT <replaceable>select_list</replaceable>
</para> </para>
</sect1> </sect1>
<sect1 id="queries-values">
<title><literal>VALUES</literal> Lists</title>
<indexterm zone="queries-values">
<primary>VALUES</primary>
</indexterm>
<para>
<literal>VALUES</> provides a way to generate a <quote>constant table</>
that can be used in a query without having to actually create and populate
a table on-disk. The syntax is
<synopsis>
VALUES ( <replaceable class="PARAMETER">expression</replaceable> [, ...] ) [, ...]
</synopsis>
Each parenthesized list of expressions generates a row in the table.
The lists must all have the same number of elements (i.e., the number
of columns in the table), and corresponding entries in each list must
have compatible datatypes. The actual datatype assigned to each column
of the result is determined using the same rules as for <literal>UNION</>
(see <xref linkend="typeconv-union-case">).
</para>
<para>
As an example,
<programlisting>
VALUES (1, 'one'), (2, 'two'), (3, 'three');
</programlisting>
will return a table of two columns and three rows. It's effectively
equivalent to
<programlisting>
SELECT 1 AS column1, 'one' AS column2
UNION ALL
SELECT 2, 'two'
UNION ALL
SELECT 3, 'three';
</programlisting>
By default, <productname>PostgreSQL</productname> assigns the names
<literal>column1</>, <literal>column2</>, etc. to the columns of a
<literal>VALUES</> table. The column names are not specified by the
SQL standard and different database systems do it differently, so
it's usually better to override the default names with a table alias
list.
</para>
<para>
Syntactically, <literal>VALUES</> followed by expression lists is
treated as equivalent to
<synopsis>
SELECT <replaceable>select_list</replaceable> FROM <replaceable>table_expression</replaceable>
</synopsis>
and can appear anywhere a <literal>SELECT</> can. For example, you can
use it as an arm of a <literal>UNION</>, or attach a
<replaceable>sort_specification</replaceable> (<literal>ORDER BY</>,
<literal>LIMIT</>, and/or <literal>OFFSET</>) to it. <literal>VALUES</>
is most commonly used as the data source in an <command>INSERT</> command,
and next most commonly as a subquery.
</para>
<para>
For more information see <xref linkend="sql-values"
endterm="sql-values-title">.
</para>
</sect1>
</chapter> </chapter>
<!-- <!--
$PostgreSQL: pgsql/doc/src/sgml/ref/allfiles.sgml,v 1.67 2005/11/21 12:49:30 alvherre Exp $ $PostgreSQL: pgsql/doc/src/sgml/ref/allfiles.sgml,v 1.68 2006/09/18 19:54:01 tgl Exp $
PostgreSQL documentation PostgreSQL documentation
Complete list of usable sgml source files in this directory. Complete list of usable sgml source files in this directory.
--> -->
...@@ -116,6 +116,7 @@ Complete list of usable sgml source files in this directory. ...@@ -116,6 +116,7 @@ Complete list of usable sgml source files in this directory.
<!entity unlisten system "unlisten.sgml"> <!entity unlisten system "unlisten.sgml">
<!entity update system "update.sgml"> <!entity update system "update.sgml">
<!entity vacuum system "vacuum.sgml"> <!entity vacuum system "vacuum.sgml">
<!entity values system "values.sgml">
<!-- applications and utilities --> <!-- applications and utilities -->
<!entity clusterdb system "clusterdb.sgml"> <!entity clusterdb system "clusterdb.sgml">
......
<!-- <!--
$PostgreSQL: pgsql/doc/src/sgml/ref/copy.sgml,v 1.76 2006/09/16 00:30:17 momjian Exp $ $PostgreSQL: pgsql/doc/src/sgml/ref/copy.sgml,v 1.77 2006/09/18 19:54:01 tgl Exp $
PostgreSQL documentation PostgreSQL documentation
--> -->
...@@ -107,7 +107,9 @@ COPY { <replaceable class="parameter">tablename</replaceable> [ ( <replaceable c ...@@ -107,7 +107,9 @@ COPY { <replaceable class="parameter">tablename</replaceable> [ ( <replaceable c
<term><replaceable class="parameter">query</replaceable></term> <term><replaceable class="parameter">query</replaceable></term>
<listitem> <listitem>
<para> <para>
A <command>SELECT</> query whose results are to be copied. A <xref linkend="sql-select" endterm="sql-select-title"> or
<xref linkend="sql-values" endterm="sql-values-title"> command
whose results are to be copied.
Note that parentheses are required around the query. Note that parentheses are required around the query.
</para> </para>
</listitem> </listitem>
......
<!-- <!--
$PostgreSQL: pgsql/doc/src/sgml/ref/create_table_as.sgml,v 1.35 2006/09/16 00:30:17 momjian Exp $ $PostgreSQL: pgsql/doc/src/sgml/ref/create_table_as.sgml,v 1.36 2006/09/18 19:54:01 tgl Exp $
PostgreSQL documentation PostgreSQL documentation
--> -->
...@@ -34,9 +34,8 @@ CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } ] TABLE <replaceable>table_name ...@@ -34,9 +34,8 @@ CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } ] TABLE <replaceable>table_name
<para> <para>
<command>CREATE TABLE AS</command> creates a table and fills it <command>CREATE TABLE AS</command> creates a table and fills it
with data computed by a <command>SELECT</command> command or an with data computed by a <command>SELECT</command> command.
<command>EXECUTE</command> that runs a prepared The table columns have the
<command>SELECT</command> command. The table columns have the
names and data types associated with the output columns of the names and data types associated with the output columns of the
<command>SELECT</command> (except that you can override the column <command>SELECT</command> (except that you can override the column
names by giving an explicit list of new column names). names by giving an explicit list of new column names).
...@@ -196,12 +195,10 @@ CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } ] TABLE <replaceable>table_name ...@@ -196,12 +195,10 @@ CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } ] TABLE <replaceable>table_name
<term><replaceable>query</replaceable></term> <term><replaceable>query</replaceable></term>
<listitem> <listitem>
<para> <para>
A query statement (that is, a <command>SELECT</command> command A <xref linkend="sql-select" endterm="sql-select-title"> or
or an <command>EXECUTE</command> command that runs a prepared <xref linkend="sql-values" endterm="sql-values-title"> command,
<command>SELECT</command> command). Refer to <xref or an <xref linkend="sql-execute" endterm="sql-execute-title"> command
linkend="sql-select" endterm="sql-select-title"> or <xref that runs a prepared <command>SELECT</> or <command>VALUES</> query.
linkend="sql-execute" endterm="sql-execute-title">,
respectively, for a description of the allowed syntax.
</para> </para>
</listitem> </listitem>
</varlistentry> </varlistentry>
...@@ -326,6 +323,7 @@ CREATE TEMP TABLE films_recent WITH (OIDS) ON COMMIT DROP AS ...@@ -326,6 +323,7 @@ CREATE TEMP TABLE films_recent WITH (OIDS) ON COMMIT DROP AS
<member><xref linkend="sql-execute" endterm="sql-execute-title"></member> <member><xref linkend="sql-execute" endterm="sql-execute-title"></member>
<member><xref linkend="sql-select" endterm="sql-select-title"></member> <member><xref linkend="sql-select" endterm="sql-select-title"></member>
<member><xref linkend="sql-selectinto" endterm="sql-selectinto-title"></member> <member><xref linkend="sql-selectinto" endterm="sql-selectinto-title"></member>
<member><xref linkend="sql-values" endterm="sql-values-title"></member>
</simplelist> </simplelist>
</refsect1> </refsect1>
......
<!-- <!--
$PostgreSQL: pgsql/doc/src/sgml/ref/create_view.sgml,v 1.32 2006/09/16 00:30:17 momjian Exp $ $PostgreSQL: pgsql/doc/src/sgml/ref/create_view.sgml,v 1.33 2006/09/18 19:54:01 tgl Exp $
PostgreSQL documentation PostgreSQL documentation
--> -->
...@@ -99,13 +99,9 @@ CREATE [ OR REPLACE ] [ TEMP | TEMPORARY ] VIEW <replaceable class="PARAMETER">n ...@@ -99,13 +99,9 @@ CREATE [ OR REPLACE ] [ TEMP | TEMPORARY ] VIEW <replaceable class="PARAMETER">n
<term><replaceable class="parameter">query</replaceable></term> <term><replaceable class="parameter">query</replaceable></term>
<listitem> <listitem>
<para> <para>
A query (that is, a <command>SELECT</> statement) which will A <xref linkend="sql-select" endterm="sql-select-title"> or
provide the columns and rows of the view. <xref linkend="sql-values" endterm="sql-values-title"> command
</para> which will provide the columns and rows of the view.
<para>
Refer to <xref linkend="sql-select" endterm="sql-select-title">
for more information about valid queries.
</para> </para>
</listitem> </listitem>
</varlistentry> </varlistentry>
......
<!-- <!--
$PostgreSQL: pgsql/doc/src/sgml/ref/declare.sgml,v 1.38 2006/09/16 00:30:18 momjian Exp $ $PostgreSQL: pgsql/doc/src/sgml/ref/declare.sgml,v 1.39 2006/09/18 19:54:01 tgl Exp $
PostgreSQL documentation PostgreSQL documentation
--> -->
...@@ -157,10 +157,9 @@ DECLARE <replaceable class="parameter">name</replaceable> [ BINARY ] [ INSENSITI ...@@ -157,10 +157,9 @@ DECLARE <replaceable class="parameter">name</replaceable> [ BINARY ] [ INSENSITI
<term><replaceable class="parameter">query</replaceable></term> <term><replaceable class="parameter">query</replaceable></term>
<listitem> <listitem>
<para> <para>
A <command>SELECT</> command that will provide the rows to be A <xref linkend="sql-select" endterm="sql-select-title"> or
returned by the cursor. Refer to <xref linkend="sql-select" <xref linkend="sql-values" endterm="sql-values-title"> command
endterm="sql-select-title"> for further information about valid which will provide the rows to be returned by the cursor.
queries.
</para> </para>
</listitem> </listitem>
</varlistentry> </varlistentry>
......
<!-- <!--
$PostgreSQL: pgsql/doc/src/sgml/ref/explain.sgml,v 1.37 2006/09/16 00:30:18 momjian Exp $ $PostgreSQL: pgsql/doc/src/sgml/ref/explain.sgml,v 1.38 2006/09/18 19:54:01 tgl Exp $
PostgreSQL documentation PostgreSQL documentation
--> -->
...@@ -121,8 +121,8 @@ ROLLBACK; ...@@ -121,8 +121,8 @@ ROLLBACK;
<listitem> <listitem>
<para> <para>
Any <command>SELECT</>, <command>INSERT</>, <command>UPDATE</>, Any <command>SELECT</>, <command>INSERT</>, <command>UPDATE</>,
<command>DELETE</>, <command>EXECUTE</>, or <command>DECLARE</> <command>DELETE</>, <command>VALUES</>, <command>EXECUTE</>, or
statement, whose execution plan you wish to see. <command>DECLARE</> statement, whose execution plan you wish to see.
</para> </para>
</listitem> </listitem>
</varlistentry> </varlistentry>
......
<!-- <!--
$PostgreSQL: pgsql/doc/src/sgml/ref/insert.sgml,v 1.32 2006/09/16 00:30:18 momjian Exp $ $PostgreSQL: pgsql/doc/src/sgml/ref/insert.sgml,v 1.33 2006/09/18 19:54:01 tgl Exp $
PostgreSQL documentation PostgreSQL documentation
--> -->
...@@ -31,8 +31,8 @@ INSERT INTO <replaceable class="PARAMETER">table</replaceable> [ ( <replaceable ...@@ -31,8 +31,8 @@ INSERT INTO <replaceable class="PARAMETER">table</replaceable> [ ( <replaceable
<para> <para>
<command>INSERT</command> inserts new rows into a table. <command>INSERT</command> inserts new rows into a table.
One can insert rows specified by value expressions, One can insert one or more rows specified by value expressions,
or rows computed as a result of a query. or zero or more rows resulting from a query.
</para> </para>
<para> <para>
...@@ -67,8 +67,9 @@ INSERT INTO <replaceable class="PARAMETER">table</replaceable> [ ( <replaceable ...@@ -67,8 +67,9 @@ INSERT INTO <replaceable class="PARAMETER">table</replaceable> [ ( <replaceable
</para> </para>
<para> <para>
You must have <literal>INSERT</literal> privilege to a table in You must have <literal>INSERT</literal> privilege on a table in
order to insert into it. If you use the <replaceable order to insert into it, and <literal>SELECT</> privilege on it to
use <literal>RETURNING</>. If you use the <replaceable
class="PARAMETER">query</replaceable> clause to insert rows from a class="PARAMETER">query</replaceable> clause to insert rows from a
query, you also need to have <literal>SELECT</literal> privilege on query, you also need to have <literal>SELECT</literal> privilege on
any table used in the query. any table used in the query.
...@@ -232,6 +233,16 @@ INSERT INTO films DEFAULT VALUES; ...@@ -232,6 +233,16 @@ INSERT INTO films DEFAULT VALUES;
</programlisting> </programlisting>
</para> </para>
<para>
To insert multiple rows using the multi-row <command>VALUES</> syntax:
<programlisting>
INSERT INTO films (code, title, did, date_prod, kind) VALUES
('B6717', 'Tampopo', 110, '1985-02-10', 'Comedy'),
('HG120', 'The Dinner Game', 140, DEFAULT, 'Comedy');
</programlisting>
</para>
<para> <para>
This example inserts some rows into table This example inserts some rows into table
<literal>films</literal> from a table <literal>tmp_films</literal> <literal>films</literal> from a table <literal>tmp_films</literal>
......
<!-- <!--
$PostgreSQL: pgsql/doc/src/sgml/ref/prepare.sgml,v 1.20 2006/09/16 00:30:19 momjian Exp $ $PostgreSQL: pgsql/doc/src/sgml/ref/prepare.sgml,v 1.21 2006/09/18 19:54:01 tgl Exp $
PostgreSQL documentation PostgreSQL documentation
--> -->
...@@ -116,7 +116,7 @@ PREPARE <replaceable class="PARAMETER">name</replaceable> [ (<replaceable class= ...@@ -116,7 +116,7 @@ PREPARE <replaceable class="PARAMETER">name</replaceable> [ (<replaceable class=
<listitem> <listitem>
<para> <para>
Any <command>SELECT</>, <command>INSERT</>, <command>UPDATE</>, Any <command>SELECT</>, <command>INSERT</>, <command>UPDATE</>,
or <command>DELETE</> statement. <command>DELETE</>, or <command>VALUES</> statement.
</para> </para>
</listitem> </listitem>
</varlistentry> </varlistentry>
......
<!-- <!--
$PostgreSQL: pgsql/doc/src/sgml/ref/select.sgml,v 1.92 2006/09/16 00:30:20 momjian Exp $ $PostgreSQL: pgsql/doc/src/sgml/ref/select.sgml,v 1.93 2006/09/18 19:54:01 tgl Exp $
PostgreSQL documentation PostgreSQL documentation
--> -->
...@@ -226,7 +226,9 @@ where <replaceable class="parameter">from_item</replaceable> can be one of: ...@@ -226,7 +226,9 @@ where <replaceable class="parameter">from_item</replaceable> can be one of:
this single <command>SELECT</command> command. Note that the this single <command>SELECT</command> command. Note that the
sub-<command>SELECT</command> must be surrounded by sub-<command>SELECT</command> must be surrounded by
parentheses, and an alias <emphasis>must</emphasis> be parentheses, and an alias <emphasis>must</emphasis> be
provided for it. provided for it. A
<xref linkend="sql-values" endterm="sql-values-title"> command
can also be used here.
</para> </para>
</listitem> </listitem>
</varlistentry> </varlistentry>
......
<!--
$PostgreSQL: pgsql/doc/src/sgml/ref/values.sgml,v 1.1 2006/09/18 19:54:01 tgl Exp $
PostgreSQL documentation
-->
<refentry id="SQL-VALUES">
<refmeta>
<refentrytitle id="SQL-VALUES-TITLE">VALUES</refentrytitle>
<refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta>
<refnamediv>
<refname>VALUES</refname>
<refpurpose>compute a set of rows</refpurpose>
</refnamediv>
<indexterm zone="sql-values">
<primary>VALUES</primary>
</indexterm>
<refsynopsisdiv>
<synopsis>
VALUES ( <replaceable class="PARAMETER">expression</replaceable> [, ...] ) [, ...]
[ ORDER BY <replaceable class="parameter">sort_expression</replaceable> [ ASC | DESC | USING <replaceable class="parameter">operator</replaceable> ] [, ...] ]
[ LIMIT { <replaceable class="parameter">count</replaceable> | ALL } ]
[ OFFSET <replaceable class="parameter">start</replaceable> ]
</synopsis>
</refsynopsisdiv>
<refsect1>
<title>Description</title>
<para>
<command>VALUES</command> computes a row value or set of row values
specified by value expressions. It is most commonly used to generate
a <quote>constant table</> within a larger command, but it can be
used on its own.
</para>
<para>
When more than one row is specified, all the rows must have the same
number of elements. The data types of the resulting table's columns are
determined by combining the explicit or inferred types of the expressions
appearing in that column, using the same rules as for <literal>UNION</>
(see <xref linkend="typeconv-union-case">).
</para>
<para>
Within larger commands, <command>VALUES</> is syntactically allowed
anywhere that <command>SELECT</> is. Because it is treated like a
<command>SELECT</> by the grammar, it is possible to use the <literal>ORDER
BY</>, <literal>LIMIT</>, and <literal>OFFSET</> clauses with a
<command>VALUES</> command.
</para>
</refsect1>
<refsect1>
<title>Parameters</title>
<variablelist>
<varlistentry>
<term><replaceable class="PARAMETER">expression</replaceable></term>
<listitem>
<para>
A constant or expression to compute and insert at the indicated place
in the resulting table (set of rows). In a <command>VALUES</> list
appearing at the top level of an <command>INSERT</>, an
<replaceable class="PARAMETER">expression</replaceable> can be replaced
by <literal>DEFAULT</literal> to indicate that the destination column's
default value should be inserted. <literal>DEFAULT</literal> cannot
be used when <command>VALUES</> appears in other contexts.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">sort_expression</replaceable></term>
<listitem>
<para>
An expression or integer constant indicating how to sort the result
rows. This expression may refer to the columns of the
<command>VALUES</> result as <literal>column1</>, <literal>column2</>,
etc. For more details see
<xref linkend="sql-orderby" endterm="sql-orderby-title">.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">operator</replaceable></term>
<listitem>
<para>
A sorting operator. For details see
<xref linkend="sql-orderby" endterm="sql-orderby-title">.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">count</replaceable></term>
<listitem>
<para>
The maximum number of rows to return. For details see
<xref linkend="sql-limit" endterm="sql-limit-title">.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">start</replaceable></term>
<listitem>
<para>
The number of rows to skip before starting to return rows.
For details see
<xref linkend="sql-limit" endterm="sql-limit-title">.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Notes</title>
<para>
<command>VALUES</> lists with very large numbers of rows should be avoided,
as you may encounter out-of-memory failures or poor performance.
<command>VALUES</> appearing within <command>INSERT</> is a special case
(because the desired column types are known from the <command>INSERT</>'s
target table, and need not be inferred by scanning the <command>VALUES</>
list), so it can handle larger lists than are practical in other contexts.
</para>
</refsect1>
<refsect1>
<title>Examples</title>
<para>
A bare <command>VALUES</> command:
<programlisting>
VALUES (1, 'one'), (2, 'two'), (3, 'three');
</programlisting>
This will return a table of two columns and three rows. It's effectively
equivalent to
<programlisting>
SELECT 1 AS column1, 'one' AS column2
UNION ALL
SELECT 2, 'two'
UNION ALL
SELECT 3, 'three';
</programlisting>
</para>
<para>
More usually, <command>VALUES</> is used within a larger SQL command.
The most common use is in <command>INSERT</>:
<programlisting>
INSERT INTO films (code, title, did, date_prod, kind)
VALUES ('T_601', 'Yojimbo', 106, '1961-06-16', 'Drama');
</programlisting>
</para>
<para>
In the context of <command>INSERT</>, entries of a <command>VALUES</> list
can be <literal>DEFAULT</literal> to indicate that the column default
should be used here instead of specifying a value:
<programlisting>
INSERT INTO films VALUES
('UA502', 'Bananas', 105, DEFAULT, 'Comedy', '82 minutes'),
('T_601', 'Yojimbo', 106, DEFAULT, 'Drama', DEFAULT);
</programlisting>
</para>
<para>
<command>VALUES</> can also be used where a sub-<command>SELECT</> might
be written, for example in a <literal>FROM</> clause:
<programlisting>
SELECT f.*
FROM films f, (VALUES('MGM', 'Horror'), ('UA', 'Sci-Fi')) AS t (studio, kind)
WHERE f.studio = t.studio AND f.kind = t.kind;
UPDATE employees SET salary = salary * v.increase
FROM (VALUES(1, 200000, 1.2), (2, 400000, 1.4)) AS v (depno, target, increase)
WHERE employees.depno = v.depno AND employees.sales &gt;= v.target;
</programlisting>
Note that an <literal>AS</> clause is required when <command>VALUES</>
is used in a <literal>FROM</> clause, just as is true for
<command>SELECT</>. It is not required that the <literal>AS</> clause
specify names for all the columns, but it's good practice to do so.
(The default column names for <command>VALUES</> are <literal>column1</>,
<literal>column2</>, etc in <productname>PostgreSQL</productname>, but
these names might be different in other database systems.)
</para>
<para>
When <command>VALUES</> is used in <command>INSERT</>, the values are all
automatically coerced to the datatype of the corresponding destination
column. When it's used in other contexts, it may be necessary to specify
the correct datatype. If the entries are all quoted literal constants,
coercing the first is sufficient to determine the assumed type for all:
<programlisting>
SELECT * FROM machines
WHERE ip_address IN (VALUES('192.168.0.1'::inet), ('192.168.0.10'), ('192.168.1.43'));
</programlisting>
</para>
<tip>
<para>
For simple <literal>IN</> tests, it's better to rely on the
list-of-scalars form of <literal>IN</> than to write a <command>VALUES</>
query as shown above. The list of scalars method requires less writing
and is often more efficient.
</para>
</tip>
</refsect1>
<refsect1>
<title>Compatibility</title>
<para>
<command>VALUES</command> conforms to the SQL standard, except that
<literal>LIMIT</literal> and <literal>OFFSET</literal> are
<productname>PostgreSQL</productname> extensions.
</para>
</refsect1>
<refsect1>
<title>See Also</title>
<simplelist type="inline">
<member><xref linkend="sql-insert" endterm="sql-insert-title"></member>
<member><xref linkend="sql-select" endterm="sql-select-title"></member>
</simplelist>
</refsect1>
</refentry>
<!-- $PostgreSQL: pgsql/doc/src/sgml/reference.sgml,v 1.59 2006/09/16 00:30:15 momjian Exp $ --> <!-- $PostgreSQL: pgsql/doc/src/sgml/reference.sgml,v 1.60 2006/09/18 19:54:01 tgl Exp $ -->
<part id="reference"> <part id="reference">
<title>Reference</title> <title>Reference</title>
...@@ -144,6 +144,7 @@ ...@@ -144,6 +144,7 @@
&unlisten; &unlisten;
&update; &update;
&vacuum; &vacuum;
&values;
</reference> </reference>
......
<!-- $PostgreSQL: pgsql/doc/src/sgml/typeconv.sgml,v 1.47 2006/09/16 00:30:16 momjian Exp $ --> <!-- $PostgreSQL: pgsql/doc/src/sgml/typeconv.sgml,v 1.48 2006/09/18 19:54:01 tgl Exp $ -->
<chapter Id="typeconv"> <chapter Id="typeconv">
<title>Type Conversion</title> <title>Type Conversion</title>
...@@ -798,6 +798,11 @@ padding spaces. ...@@ -798,6 +798,11 @@ padding spaces.
<secondary>determination of result type</secondary> <secondary>determination of result type</secondary>
</indexterm> </indexterm>
<indexterm zone="typeconv-union-case">
<primary>VALUES</primary>
<secondary>determination of result type</secondary>
</indexterm>
<indexterm zone="typeconv-union-case"> <indexterm zone="typeconv-union-case">
<primary>GREATEST</primary> <primary>GREATEST</primary>
<secondary>determination of result type</secondary> <secondary>determination of result type</secondary>
...@@ -814,8 +819,8 @@ types to become a single result set. The resolution algorithm is ...@@ -814,8 +819,8 @@ types to become a single result set. The resolution algorithm is
applied separately to each output column of a union query. The applied separately to each output column of a union query. The
<literal>INTERSECT</> and <literal>EXCEPT</> constructs resolve <literal>INTERSECT</> and <literal>EXCEPT</> constructs resolve
dissimilar types in the same way as <literal>UNION</>. The dissimilar types in the same way as <literal>UNION</>. The
<literal>CASE</>, <literal>ARRAY</>, <function>GREATEST</> and <literal>CASE</>, <literal>ARRAY</>, <literal>VALUES</>,
<function>LEAST</> constructs use the identical <function>GREATEST</> and <function>LEAST</> constructs use the identical
algorithm to match up their component expressions and select a result algorithm to match up their component expressions and select a result
data type. data type.
</para> </para>
......
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment