3 PostgreSQL documentation
6 <refentry id=
"SQL-INSERT">
8 <refentrytitle id=
"SQL-INSERT-TITLE">INSERT
</refentrytitle>
9 <manvolnum>7</manvolnum>
10 <refmiscinfo>SQL - Language Statements
</refmiscinfo>
14 <refname>INSERT
</refname>
15 <refpurpose>create new rows in a table
</refpurpose>
18 <indexterm zone=
"sql-insert">
19 <primary>INSERT
</primary>
24 INSERT INTO
<replaceable class=
"PARAMETER">table
</replaceable> [ (
<replaceable class=
"PARAMETER">column
</replaceable> [, ...] ) ]
25 { DEFAULT VALUES | VALUES ( {
<replaceable class=
"PARAMETER">expression
</replaceable> | DEFAULT } [, ...] ) [, ...] |
<replaceable class=
"PARAMETER">query
</replaceable> }
26 [ RETURNING * |
<replaceable class=
"parameter">output_expression
</replaceable> [ [ AS ]
<replaceable class=
"parameter">output_name
</replaceable> ] [, ...] ]
31 <title>Description
</title>
34 <command>INSERT
</command> inserts new rows into a table.
35 One can insert one or more rows specified by value expressions,
36 or zero or more rows resulting from a query.
40 The target column names can be listed in any order. If no list of
41 column names is given at all, the default is all the columns of the
42 table in their declared order; or the first
<replaceable>N<
/> column
43 names, if there are only
<replaceable>N<
/> columns supplied by the
44 <literal>VALUES<
/> clause or
<replaceable>query<
/>. The values
45 supplied by the
<literal>VALUES<
/> clause or
<replaceable>query<
/> are
46 associated with the explicit or implicit column list left-to-right.
50 Each column not present in the explicit or implicit column list will be
51 filled with a default value, either its declared default value
52 or null if there is none.
56 If the expression for any column is not of the correct data type,
57 automatic type conversion will be attempted.
61 The optional
<literal>RETURNING<
/> clause causes
<command>INSERT<
/>
62 to compute and return value(s) based on each row actually inserted.
63 This is primarily useful for obtaining values that were supplied by
64 defaults, such as a serial sequence number. However, any expression
65 using the table's columns is allowed. The syntax of the
66 <literal>RETURNING<
/> list is identical to that of the output list
67 of
<command>SELECT<
/>.
71 You must have
<literal>INSERT
</literal> privilege on a table in
72 order to insert into it. If a column list is specified, you only
73 need
<literal>INSERT
</literal> privilege on the listed columns.
74 Use of the
<literal>RETURNING<
/> clause requires
<literal>SELECT<
/>
75 privilege on all columns mentioned in
<literal>RETURNING<
/>.
76 If you use the
<replaceable
77 class=
"PARAMETER">query
</replaceable> clause to insert rows from a
78 query, you of course need to have
<literal>SELECT
</literal> privilege on
79 any table or column used in the query.
84 <title>Parameters
</title>
88 <term><replaceable class=
"PARAMETER">table
</replaceable></term>
91 The name (optionally schema-qualified) of an existing table.
97 <term><replaceable class=
"PARAMETER">column
</replaceable></term>
100 The name of a column in
<replaceable class=
"PARAMETER">table
</replaceable>.
101 The column name can be qualified with a subfield name or array
102 subscript, if needed. (Inserting into only some fields of a
103 composite column leaves the other fields null.)
109 <term><literal>DEFAULT VALUES
</literal></term>
112 All columns will be filled with their default values.
118 <term><replaceable class=
"PARAMETER">expression
</replaceable></term>
121 An expression or value to assign to the corresponding
<replaceable
122 class=
"PARAMETER">column
</replaceable>.
128 <term><literal>DEFAULT
</literal></term>
131 The corresponding
<replaceable>column
</replaceable> will be filled with
138 <term><replaceable class=
"PARAMETER">query
</replaceable></term>
141 A query (
<command>SELECT
</command> statement) that supplies the
142 rows to be inserted. Refer to the
143 <xref linkend=
"sql-select" endterm=
"sql-select-title">
144 statement for a description of the syntax.
150 <term><replaceable class=
"PARAMETER">output_expression
</replaceable></term>
153 An expression to be computed and returned by the
<command>INSERT<
/>
154 command after each row is inserted. The expression can use any
155 column names of the
<replaceable class=
"PARAMETER">table
</replaceable>.
156 Write
<literal>*<
/> to return all columns of the inserted row(s).
162 <term><replaceable class=
"PARAMETER">output_name
</replaceable></term>
165 A name to use for a returned column.
173 <title>Outputs
</title>
176 On successful completion, an
<command>INSERT<
/> command returns a command
179 INSERT
<replaceable>oid
</replaceable> <replaceable class=
"parameter">count
</replaceable>
181 The
<replaceable class=
"parameter">count
</replaceable> is the number
182 of rows inserted. If
<replaceable class=
"parameter">count
</replaceable>
183 is exactly one, and the target table has OIDs, then
184 <replaceable class=
"parameter">oid
</replaceable> is the
185 <acronym>OID
</acronym> assigned to the inserted row. Otherwise
186 <replaceable class=
"parameter">oid
</replaceable> is zero.
190 If the
<command>INSERT<
/> command contains a
<literal>RETURNING<
/>
191 clause, the result will be similar to that of a
<command>SELECT<
/>
192 statement containing the columns and values defined in the
193 <literal>RETURNING<
/> list, computed over the row(s) inserted by the
199 <title>Examples
</title>
202 Insert a single row into table
<literal>films
</literal>:
205 INSERT INTO films VALUES
206 ('UA502', 'Bananas',
105, '
1971-
07-
13', 'Comedy', '
82 minutes');
211 In this example, the
<literal>len
</literal> column is
212 omitted and therefore it will have the default value:
215 INSERT INTO films (code, title, did, date_prod, kind)
216 VALUES ('T_601', 'Yojimbo',
106, '
1961-
06-
16', 'Drama');
221 This example uses the
<literal>DEFAULT
</literal> clause for
222 the date columns rather than specifying a value:
225 INSERT INTO films VALUES
226 ('UA502', 'Bananas',
105, DEFAULT, 'Comedy', '
82 minutes');
227 INSERT INTO films (code, title, did, date_prod, kind)
228 VALUES ('T_601', 'Yojimbo',
106, DEFAULT, 'Drama');
233 To insert a row consisting entirely of default values:
236 INSERT INTO films DEFAULT VALUES;
241 To insert multiple rows using the multirow
<command>VALUES<
/> syntax:
244 INSERT INTO films (code, title, did, date_prod, kind) VALUES
245 ('B6717', 'Tampopo',
110, '
1985-
02-
10', 'Comedy'),
246 ('HG120', 'The Dinner Game',
140, DEFAULT, 'Comedy');
251 This example inserts some rows into table
252 <literal>films
</literal> from a table
<literal>tmp_films
</literal>
253 with the same column layout as
<literal>films
</literal>:
256 INSERT INTO films SELECT * FROM tmp_films WHERE date_prod
< '
2004-
05-
07';
261 This example inserts into array columns:
264 -- Create an empty
3x3 gameboard for noughts-and-crosses
265 INSERT INTO tictactoe (game, board[
1:
3][
1:
3])
266 VALUES (
1, '{{
" ",
" ",
" "},{
" ",
" ",
" "},{
" ",
" ",
" "}}');
267 -- The subscripts in the above example aren't really needed
268 INSERT INTO tictactoe (game, board)
269 VALUES (
2, '{{X,
" ",
" "},{
" ",O,
" "},{
" ",X,
" "}}');
274 Insert a single row into table
<literal>distributors
</literal>, returning
275 the sequence number generated by the
<literal>DEFAULT
</literal> clause:
278 INSERT INTO distributors (did, dname) VALUES (DEFAULT, 'XYZ Widgets')
285 <title>Compatibility
</title>
288 <command>INSERT
</command> conforms to the SQL standard, except that
289 the
<literal>RETURNING<
/> clause is a
290 <productname>PostgreSQL
</productname> extension. Also, the case in
291 which a column name list is omitted, but not all the columns are
292 filled from the
<literal>VALUES<
/> clause or
<replaceable>query<
/>,
293 is disallowed by the standard.
297 Possible limitations of the
<replaceable
298 class=
"PARAMETER">query
</replaceable> clause are documented under
299 <xref linkend=
"sql-select" endterm=
"sql-select-title">.