1INSERT(7) PostgreSQL 10.7 Documentation INSERT(7)
2
3
4
6 INSERT - create new rows in a table
7
9 [ WITH [ RECURSIVE ] with_query [, ...] ]
10 INSERT INTO table_name [ AS alias ] [ ( column_name [, ...] ) ]
11 [ OVERRIDING { SYSTEM | USER} VALUE ]
12 { DEFAULT VALUES | VALUES ( { expression | DEFAULT } [, ...] ) [, ...] | query }
13 [ ON CONFLICT [ conflict_target ] conflict_action ]
14 [ RETURNING * | output_expression [ [ AS ] output_name ] [, ...] ]
15
16 where conflict_target can be one of:
17
18 ( { index_column_name | ( index_expression ) } [ COLLATE collation ] [ opclass ] [, ...] ) [ WHERE index_predicate ]
19 ON CONSTRAINT constraint_name
20
21 and conflict_action is one of:
22
23 DO NOTHING
24 DO UPDATE SET { column_name = { expression | DEFAULT } |
25 ( column_name [, ...] ) = [ ROW ] ( { expression | DEFAULT } [, ...] ) |
26 ( column_name [, ...] ) = ( sub-SELECT )
27 } [, ...]
28 [ WHERE condition ]
29
31 INSERT inserts new rows into a table. One can insert one or more rows
32 specified by value expressions, or zero or more rows resulting from a
33 query.
34
35 The target column names can be listed in any order. If no list of
36 column names is given at all, the default is all the columns of the
37 table in their declared order; or the first N column names, if there
38 are only N columns supplied by the VALUES clause or query. The values
39 supplied by the VALUES clause or query are associated with the explicit
40 or implicit column list left-to-right.
41
42 Each column not present in the explicit or implicit column list will be
43 filled with a default value, either its declared default value or null
44 if there is none.
45
46 If the expression for any column is not of the correct data type,
47 automatic type conversion will be attempted.
48
49 ON CONFLICT can be used to specify an alternative action to raising a
50 unique constraint or exclusion constraint violation error. (See ON
51 CONFLICT Clause below.)
52
53 The optional RETURNING clause causes INSERT to compute and return
54 value(s) based on each row actually inserted (or updated, if an ON
55 CONFLICT DO UPDATE clause was used). This is primarily useful for
56 obtaining values that were supplied by defaults, such as a serial
57 sequence number. However, any expression using the table's columns is
58 allowed. The syntax of the RETURNING list is identical to that of the
59 output list of SELECT. Only rows that were successfully inserted or
60 updated will be returned. For example, if a row was locked but not
61 updated because an ON CONFLICT DO UPDATE ... WHERE clause condition was
62 not satisfied, the row will not be returned.
63
64 You must have INSERT privilege on a table in order to insert into it.
65 If ON CONFLICT DO UPDATE is present, UPDATE privilege on the table is
66 also required.
67
68 If a column list is specified, you only need INSERT privilege on the
69 listed columns. Similarly, when ON CONFLICT DO UPDATE is specified, you
70 only need UPDATE privilege on the column(s) that are listed to be
71 updated. However, ON CONFLICT DO UPDATE also requires SELECT privilege
72 on any column whose values are read in the ON CONFLICT DO UPDATE
73 expressions or condition.
74
75 Use of the RETURNING clause requires SELECT privilege on all columns
76 mentioned in RETURNING. If you use the query clause to insert rows from
77 a query, you of course need to have SELECT privilege on any table or
78 column used in the query.
79
81 Inserting
82 This section covers parameters that may be used when only inserting new
83 rows. Parameters exclusively used with the ON CONFLICT clause are
84 described separately.
85
86 with_query
87 The WITH clause allows you to specify one or more subqueries that
88 can be referenced by name in the INSERT query. See Section 7.8 and
89 SELECT(7) for details.
90
91 It is possible for the query (SELECT statement) to also contain a
92 WITH clause. In such a case both sets of with_query can be
93 referenced within the query, but the second one takes precedence
94 since it is more closely nested.
95
96 table_name
97 The name (optionally schema-qualified) of an existing table.
98
99 alias
100 A substitute name for table_name. When an alias is provided, it
101 completely hides the actual name of the table. This is particularly
102 useful when ON CONFLICT DO UPDATE targets a table named excluded,
103 since that will otherwise be taken as the name of the special table
104 representing rows proposed for insertion.
105
106 column_name
107 The name of a column in the table named by table_name. The column
108 name can be qualified with a subfield name or array subscript, if
109 needed. (Inserting into only some fields of a composite column
110 leaves the other fields null.) When referencing a column with ON
111 CONFLICT DO UPDATE, do not include the table's name in the
112 specification of a target column. For example, INSERT INTO
113 table_name ... ON CONFLICT DO UPDATE SET table_name.col = 1 is
114 invalid (this follows the general behavior for UPDATE).
115
116 OVERRIDING SYSTEM VALUE
117 Without this clause, it is an error to specify an explicit value
118 (other than DEFAULT) for an identity column defined as GENERATED
119 ALWAYS. This clause overrides that restriction.
120
121 OVERRIDING USER VALUE
122 If this clause is specified, then any values supplied for identity
123 columns defined as GENERATED BY DEFAULT are ignored and the default
124 sequence-generated values are applied.
125
126 This clause is useful for example when copying values between
127 tables. Writing INSERT INTO tbl2 OVERRIDING USER VALUE SELECT *
128 FROM tbl1 will copy from tbl1 all columns that are not identity
129 columns in tbl2 while values for the identity columns in tbl2 will
130 be generated by the sequences associated with tbl2.
131
132 DEFAULT VALUES
133 All columns will be filled with their default values. (An
134 OVERRIDING clause is not permitted in this form.)
135
136 expression
137 An expression or value to assign to the corresponding column.
138
139 DEFAULT
140 The corresponding column will be filled with its default value.
141
142 query
143 A query (SELECT statement) that supplies the rows to be inserted.
144 Refer to the SELECT(7) statement for a description of the syntax.
145
146 output_expression
147 An expression to be computed and returned by the INSERT command
148 after each row is inserted or updated. The expression can use any
149 column names of the table named by table_name. Write * to return
150 all columns of the inserted or updated row(s).
151
152 output_name
153 A name to use for a returned column.
154
155 ON CONFLICT Clause
156 The optional ON CONFLICT clause specifies an alternative action to
157 raising a unique violation or exclusion constraint violation error. For
158 each individual row proposed for insertion, either the insertion
159 proceeds, or, if an arbiter constraint or index specified by
160 conflict_target is violated, the alternative conflict_action is taken.
161 ON CONFLICT DO NOTHING simply avoids inserting a row as its alternative
162 action. ON CONFLICT DO UPDATE updates the existing row that conflicts
163 with the row proposed for insertion as its alternative action.
164
165 conflict_target can perform unique index inference. When performing
166 inference, it consists of one or more index_column_name columns and/or
167 index_expression expressions, and an optional index_predicate. All
168 table_name unique indexes that, without regard to order, contain
169 exactly the conflict_target-specified columns/expressions are inferred
170 (chosen) as arbiter indexes. If an index_predicate is specified, it
171 must, as a further requirement for inference, satisfy arbiter indexes.
172 Note that this means a non-partial unique index (a unique index without
173 a predicate) will be inferred (and thus used by ON CONFLICT) if such an
174 index satisfying every other criteria is available. If an attempt at
175 inference is unsuccessful, an error is raised.
176
177 ON CONFLICT DO UPDATE guarantees an atomic INSERT or UPDATE outcome;
178 provided there is no independent error, one of those two outcomes is
179 guaranteed, even under high concurrency. This is also known as UPSERT —
180 “UPDATE or INSERT”.
181
182 conflict_target
183 Specifies which conflicts ON CONFLICT takes the alternative action
184 on by choosing arbiter indexes. Either performs unique index
185 inference, or names a constraint explicitly. For ON CONFLICT DO
186 NOTHING, it is optional to specify a conflict_target; when omitted,
187 conflicts with all usable constraints (and unique indexes) are
188 handled. For ON CONFLICT DO UPDATE, a conflict_target must be
189 provided.
190
191 conflict_action
192 conflict_action specifies an alternative ON CONFLICT action. It can
193 be either DO NOTHING, or a DO UPDATE clause specifying the exact
194 details of the UPDATE action to be performed in case of a conflict.
195 The SET and WHERE clauses in ON CONFLICT DO UPDATE have access to
196 the existing row using the table's name (or an alias), and to rows
197 proposed for insertion using the special excluded table. SELECT
198 privilege is required on any column in the target table where
199 corresponding excluded columns are read.
200
201 Note that the effects of all per-row BEFORE INSERT triggers are
202 reflected in excluded values, since those effects may have
203 contributed to the row being excluded from insertion.
204
205 index_column_name
206 The name of a table_name column. Used to infer arbiter indexes.
207 Follows CREATE INDEX format. SELECT privilege on index_column_name
208 is required.
209
210 index_expression
211 Similar to index_column_name, but used to infer expressions on
212 table_name columns appearing within index definitions (not simple
213 columns). Follows CREATE INDEX format. SELECT privilege on any
214 column appearing within index_expression is required.
215
216 collation
217 When specified, mandates that corresponding index_column_name or
218 index_expression use a particular collation in order to be matched
219 during inference. Typically this is omitted, as collations usually
220 do not affect whether or not a constraint violation occurs. Follows
221 CREATE INDEX format.
222
223 opclass
224 When specified, mandates that corresponding index_column_name or
225 index_expression use particular operator class in order to be
226 matched during inference. Typically this is omitted, as the
227 equality semantics are often equivalent across a type's operator
228 classes anyway, or because it's sufficient to trust that the
229 defined unique indexes have the pertinent definition of equality.
230 Follows CREATE INDEX format.
231
232 index_predicate
233 Used to allow inference of partial unique indexes. Any indexes that
234 satisfy the predicate (which need not actually be partial indexes)
235 can be inferred. Follows CREATE INDEX format. SELECT privilege on
236 any column appearing within index_predicate is required.
237
238 constraint_name
239 Explicitly specifies an arbiter constraint by name, rather than
240 inferring a constraint or index.
241
242 condition
243 An expression that returns a value of type boolean. Only rows for
244 which this expression returns true will be updated, although all
245 rows will be locked when the ON CONFLICT DO UPDATE action is taken.
246 Note that condition is evaluated last, after a conflict has been
247 identified as a candidate to update.
248
249 Note that exclusion constraints are not supported as arbiters with ON
250 CONFLICT DO UPDATE. In all cases, only NOT DEFERRABLE constraints and
251 unique indexes are supported as arbiters.
252
253 INSERT with an ON CONFLICT DO UPDATE clause is a “deterministic”
254 statement. This means that the command will not be allowed to affect
255 any single existing row more than once; a cardinality violation error
256 will be raised when this situation arises. Rows proposed for insertion
257 should not duplicate each other in terms of attributes constrained by
258 an arbiter index or constraint.
259
260 Tip
261 It is often preferable to use unique index inference rather than
262 naming a constraint directly using ON CONFLICT ON CONSTRAINT
263 constraint_name. Inference will continue to work correctly when
264 the underlying index is replaced by another more or less equivalent
265 index in an overlapping way, for example when using CREATE UNIQUE
266 INDEX ... CONCURRENTLY before dropping the index being replaced.
267
269 On successful completion, an INSERT command returns a command tag of
270 the form
271
272 INSERT oid count
273
274 The count is the number of rows inserted or updated. If count is
275 exactly one, and the target table has OIDs, then oid is the OID
276 assigned to the inserted row. The single row must have been inserted
277 rather than updated. Otherwise oid is zero.
278
279 If the INSERT command contains a RETURNING clause, the result will be
280 similar to that of a SELECT statement containing the columns and values
281 defined in the RETURNING list, computed over the row(s) inserted or
282 updated by the command.
283
285 If the specified table is a partitioned table, each row is routed to
286 the appropriate partition and inserted into it. If the specified table
287 is a partition, an error will occur if one of the input rows violates
288 the partition constraint.
289
291 Insert a single row into table films:
292
293 INSERT INTO films VALUES
294 ('UA502', 'Bananas', 105, '1971-07-13', 'Comedy', '82 minutes');
295
296 In this example, the len column is omitted and therefore it will have
297 the default value:
298
299 INSERT INTO films (code, title, did, date_prod, kind)
300 VALUES ('T_601', 'Yojimbo', 106, '1961-06-16', 'Drama');
301
302 This example uses the DEFAULT clause for the date columns rather than
303 specifying a value:
304
305 INSERT INTO films VALUES
306 ('UA502', 'Bananas', 105, DEFAULT, 'Comedy', '82 minutes');
307 INSERT INTO films (code, title, did, date_prod, kind)
308 VALUES ('T_601', 'Yojimbo', 106, DEFAULT, 'Drama');
309
310 To insert a row consisting entirely of default values:
311
312 INSERT INTO films DEFAULT VALUES;
313
314 To insert multiple rows using the multirow VALUES syntax:
315
316 INSERT INTO films (code, title, did, date_prod, kind) VALUES
317 ('B6717', 'Tampopo', 110, '1985-02-10', 'Comedy'),
318 ('HG120', 'The Dinner Game', 140, DEFAULT, 'Comedy');
319
320 This example inserts some rows into table films from a table tmp_films
321 with the same column layout as films:
322
323 INSERT INTO films SELECT * FROM tmp_films WHERE date_prod < '2004-05-07';
324
325 This example inserts into array columns:
326
327 -- Create an empty 3x3 gameboard for noughts-and-crosses
328 INSERT INTO tictactoe (game, board[1:3][1:3])
329 VALUES (1, '{{" "," "," "},{" "," "," "},{" "," "," "}}');
330 -- The subscripts in the above example aren't really needed
331 INSERT INTO tictactoe (game, board)
332 VALUES (2, '{{X," "," "},{" ",O," "},{" ",X," "}}');
333
334 Insert a single row into table distributors, returning the sequence
335 number generated by the DEFAULT clause:
336
337 INSERT INTO distributors (did, dname) VALUES (DEFAULT, 'XYZ Widgets')
338 RETURNING did;
339
340 Increment the sales count of the salesperson who manages the account
341 for Acme Corporation, and record the whole updated row along with
342 current time in a log table:
343
344 WITH upd AS (
345 UPDATE employees SET sales_count = sales_count + 1 WHERE id =
346 (SELECT sales_person FROM accounts WHERE name = 'Acme Corporation')
347 RETURNING *
348 )
349 INSERT INTO employees_log SELECT *, current_timestamp FROM upd;
350
351 Insert or update new distributors as appropriate. Assumes a unique
352 index has been defined that constrains values appearing in the did
353 column. Note that the special excluded table is used to reference
354 values originally proposed for insertion:
355
356 INSERT INTO distributors (did, dname)
357 VALUES (5, 'Gizmo Transglobal'), (6, 'Associated Computing, Inc')
358 ON CONFLICT (did) DO UPDATE SET dname = EXCLUDED.dname;
359
360 Insert a distributor, or do nothing for rows proposed for insertion
361 when an existing, excluded row (a row with a matching constrained
362 column or columns after before row insert triggers fire) exists.
363 Example assumes a unique index has been defined that constrains values
364 appearing in the did column:
365
366 INSERT INTO distributors (did, dname) VALUES (7, 'Redline GmbH')
367 ON CONFLICT (did) DO NOTHING;
368
369 Insert or update new distributors as appropriate. Example assumes a
370 unique index has been defined that constrains values appearing in the
371 did column. WHERE clause is used to limit the rows actually updated
372 (any existing row not updated will still be locked, though):
373
374 -- Don't update existing distributors based in a certain ZIP code
375 INSERT INTO distributors AS d (did, dname) VALUES (8, 'Anvil Distribution')
376 ON CONFLICT (did) DO UPDATE
377 SET dname = EXCLUDED.dname || ' (formerly ' || d.dname || ')'
378 WHERE d.zipcode <> '21201';
379
380 -- Name a constraint directly in the statement (uses associated
381 -- index to arbitrate taking the DO NOTHING action)
382 INSERT INTO distributors (did, dname) VALUES (9, 'Antwerp Design')
383 ON CONFLICT ON CONSTRAINT distributors_pkey DO NOTHING;
384
385 Insert new distributor if possible; otherwise DO NOTHING. Example
386 assumes a unique index has been defined that constrains values
387 appearing in the did column on a subset of rows where the is_active
388 Boolean column evaluates to true:
389
390 -- This statement could infer a partial unique index on "did"
391 -- with a predicate of "WHERE is_active", but it could also
392 -- just use a regular unique constraint on "did"
393 INSERT INTO distributors (did, dname) VALUES (10, 'Conrad International')
394 ON CONFLICT (did) WHERE is_active DO NOTHING;
395
397 INSERT conforms to the SQL standard, except that the RETURNING clause
398 is a PostgreSQL extension, as is the ability to use WITH with INSERT,
399 and the ability to specify an alternative action with ON CONFLICT.
400 Also, the case in which a column name list is omitted, but not all the
401 columns are filled from the VALUES clause or query, is disallowed by
402 the standard.
403
404 The SQL standard specifies that OVERRIDING SYSTEM VALUE can only be
405 specified if an identity column that is generated always exists.
406 PostgreSQL allows the clause in any case and ignores it if it is not
407 applicable.
408
409 Possible limitations of the query clause are documented under
410 SELECT(7).
411
412
413
414PostgreSQL 10.7 2019 INSERT(7)