1VALUES(7)                        SQL Commands                        VALUES(7)
2
3
4

NAME

6       VALUES - compute a set of rows
7
8

SYNOPSIS

10       VALUES ( expression [, ...] ) [, ...]
11           [ ORDER BY sort_expression [ ASC | DESC | USING operator ] [, ...] ]
12           [ LIMIT { count | ALL } ]
13           [ OFFSET start [ ROW | ROWS ] ]
14           [ FETCH { FIRST | NEXT } [ count ] { ROW | ROWS } ONLY ]
15
16

DESCRIPTION

18       VALUES  computes  a  row  value or set of row values specified by value
19       expressions. It is most commonly used to generate a ``constant  table''
20       within a larger command, but it can be used on its own.
21
22       When  more  than  one row is specified, all the rows must have the same
23       number of elements. The data types of the resulting table's columns are
24       determined  by  combining the explicit or inferred types of the expres‐
25       sions appearing in that column, using the same rules as for UNION  (see
26       in the documentation).
27
28       Within  larger  commands, VALUES is syntactically allowed anywhere that
29       SELECT is. Because it is treated like a SELECT by the  grammar,  it  is
30       possible  to use the ORDER BY, LIMIT (or equivalently FETCH FIRST), and
31       OFFSET clauses with a VALUES command.
32

PARAMETERS

34       expression
35              A constant or expression to compute and insert at the  indicated
36              place  in  the  resulting  table (set of rows). In a VALUES list
37              appearing at the top level of an INSERT, an  expression  can  be
38              replaced  by  DEFAULT  to indicate that the destination column's
39              default value should be inserted. DEFAULT cannot  be  used  when
40              VALUES appears in other contexts.
41
42       sort_expression
43              An  expression  or  integer  constant indicating how to sort the
44              result rows. This expression can refer to  the  columns  of  the
45              VALUES  result  as  column1,  column2, etc. For more details see
46              ORDER BY Clause [select(7)].
47
48       operator
49              A sorting operator. For details see ORDER BY Clause [select(7)].
50
51       count  The maximum number of rows to  return.  For  details  see  LIMIT
52              Clause [select(7)].
53
54       start  The  number of rows to skip before starting to return rows.  For
55              details see LIMIT Clause [select(7)].
56

NOTES

58       VALUES lists with very large numbers of rows should be avoided, as  you
59       might  encounter  out-of-memory  failures  or poor performance.  VALUES
60       appearing within INSERT is a special case (because the  desired  column
61       types  are  known  from  the  INSERT's  target  table,  and need not be
62       inferred by scanning the VALUES list), so it can  handle  larger  lists
63       than are practical in other contexts.
64

EXAMPLES

66       A bare VALUES command:
67
68       VALUES (1, 'one'), (2, 'two'), (3, 'three');
69
70       This  will  return  a  table of two columns and three rows. It's effec‐
71       tively equivalent to:
72
73       SELECT 1 AS column1, 'one' AS column2
74       UNION ALL
75       SELECT 2, 'two'
76       UNION ALL
77       SELECT 3, 'three';
78
79
80       More usually, VALUES is used within a larger  SQL  command.   The  most
81       common use is in INSERT:
82
83       INSERT INTO films (code, title, did, date_prod, kind)
84           VALUES ('T_601', 'Yojimbo', 106, '1961-06-16', 'Drama');
85
86
87       In  the  context  of INSERT, entries of a VALUES list can be DEFAULT to
88       indicate that the column default should be used here instead of  speci‐
89       fying a value:
90
91       INSERT INTO films VALUES
92           ('UA502', 'Bananas', 105, DEFAULT, 'Comedy', '82 minutes'),
93           ('T_601', 'Yojimbo', 106, DEFAULT, 'Drama', DEFAULT);
94
95
96       VALUES  can also be used where a sub-SELECT might be written, for exam‐
97       ple in a FROM clause:
98
99       SELECT f.*
100         FROM films f, (VALUES('MGM', 'Horror'), ('UA', 'Sci-Fi')) AS t (studio, kind)
101         WHERE f.studio = t.studio AND f.kind = t.kind;
102
103       UPDATE employees SET salary = salary * v.increase
104         FROM (VALUES(1, 200000, 1.2), (2, 400000, 1.4)) AS v (depno, target, increase)
105         WHERE employees.depno = v.depno AND employees.sales >= v.target;
106
107       Note that an AS clause is required  when  VALUES  is  used  in  a  FROM
108       clause,  just  as  is  true  for SELECT. It is not required that the AS
109       clause specify names for all the columns, but it's good practice to  do
110       so.   (The default column names for VALUES are column1, column2, etc in
111       PostgreSQL, but these names might be different in other  database  sys‐
112       tems.)
113
114       When VALUES is used in INSERT, the values are all automatically coerced
115       to the data type of the corresponding  destination  column.  When  it's
116       used  in  other  contexts, it might be necessary to specify the correct
117       data type. If the entries are all quoted  literal  constants,  coercing
118       the first is sufficient to determine the assumed type for all:
119
120       SELECT * FROM machines
121       WHERE ip_address IN (VALUES('192.168.0.1'::inet), ('192.168.0.10'), ('192.168.1.43'));
122
123
124              Tip:  For  simple  IN tests, it's better to rely on the list-of-
125              scalars form of IN than to write a VALUES query as shown  above.
126              The  list  of  scalars method requires less writing and is often
127              more efficient.
128
129

COMPATIBILITY

131       VALUES conforms to the SQL standard.  LIMIT and OFFSET  are  PostgreSQL
132       extensions; see also under SELECT [select(7)].
133

SEE ALSO

135       INSERT [insert(7)], SELECT [select(7)]
136
137
138
139SQL - Language Statements         2014-02-17                         VALUES(7)
Impressum