summaryrefslogtreecommitdiffstats
path: root/doc/src/sgml/ref/values.sgml
blob: 4bf7bfdffee74e423834a0f6b8339f737e4e0ef4 (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
<!--
doc/src/sgml/ref/values.sgml
PostgreSQL documentation
-->

<refentry id="sql-values">
 <indexterm zone="sql-values">
  <primary>VALUES</primary>
 </indexterm>

 <refmeta>
  <refentrytitle>VALUES</refentrytitle>
  <manvolnum>7</manvolnum>
  <refmiscinfo>SQL - Language Statements</refmiscinfo>
 </refmeta>

 <refnamediv>
  <refname>VALUES</refname>
  <refpurpose>compute a set of rows</refpurpose>
 </refnamediv>

 <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> [ ROW | ROWS ] ]
    [ FETCH { FIRST | NEXT } [ <replaceable class="parameter">count</replaceable> ] { ROW | ROWS } ONLY ]
</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</quote> 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</literal>
   (see <xref linkend="typeconv-union-case"/>).
  </para>

  <para>
   Within larger commands, <command>VALUES</command> is syntactically allowed
   anywhere that <command>SELECT</command> is.  Because it is treated like a
   <command>SELECT</command> by the grammar, it is possible to use
   the <literal>ORDER BY</literal>, <literal>LIMIT</literal> (or
   equivalently <literal>FETCH FIRST</literal>),
   and <literal>OFFSET</literal> clauses with a
   <command>VALUES</command> 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</command> list
      appearing at the top level of an <command>INSERT</command>, 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</command> 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 can refer to the columns of the
      <command>VALUES</command> result as <literal>column1</literal>, <literal>column2</literal>,
      etc.  For more details see
      <xref linkend="sql-orderby"/>
      in the <xref linkend="sql-select"/> documentation.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="parameter">operator</replaceable></term>
    <listitem>
     <para>
      A sorting operator.  For details see
      <xref linkend="sql-orderby"/>
      in the <xref linkend="sql-select"/> documentation.
     </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"/>
      in the <xref linkend="sql-select"/> documentation.
     </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"/>
      in the <xref linkend="sql-select"/> documentation.
     </para>
    </listitem>
   </varlistentry>
  </variablelist>
 </refsect1>

 <refsect1>
  <title>Notes</title>

  <para>
   <command>VALUES</command> lists with very large numbers of rows should be avoided,
   as you might encounter out-of-memory failures or poor performance.
   <command>VALUES</command> appearing within <command>INSERT</command> is a special case
   (because the desired column types are known from the <command>INSERT</command>'s
   target table, and need not be inferred by scanning the <command>VALUES</command>
   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> 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</command> is used within a larger SQL command.
   The most common use is in <command>INSERT</command>:

<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</command>, entries of a <command>VALUES</command> 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</command> can also be used where a sub-<command>SELECT</command> might
   be written, for example in a <literal>FROM</literal> 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</literal> clause is required when <command>VALUES</command>
   is used in a <literal>FROM</literal> clause, just as is true for
   <command>SELECT</command>.  It is not required that the <literal>AS</literal> clause
   specify names for all the columns, but it's good practice to do so.
   (The default column names for <command>VALUES</command> are <literal>column1</literal>,
   <literal>column2</literal>, etc. in <productname>PostgreSQL</productname>, but
   these names might be different in other database systems.)
  </para>

  <para>
   When <command>VALUES</command> is used in <command>INSERT</command>, the values are all
   automatically coerced to the data type of the corresponding destination
   column.  When it's used in other contexts, it might be necessary to specify
   the correct data type.  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</literal> tests, it's better to rely on the
    <link linkend="functions-comparisons-in-scalar">list-of-scalars</link>
    form of <literal>IN</literal> than to write a <command>VALUES</command>
    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.
   <literal>LIMIT</literal> and <literal>OFFSET</literal> are
   <productname>PostgreSQL</productname> extensions; see also
   under <xref linkend="sql-select"/>.
  </para>
 </refsect1>

 <refsect1>
  <title>See Also</title>

  <simplelist type="inline">
   <member><xref linkend="sql-insert"/></member>
   <member><xref linkend="sql-select"/></member>
  </simplelist>
 </refsect1>
</refentry>