1INSERT(7) PostgreSQL 14.3 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 If this clause is specified, then any values supplied for identity
118 columns will override the default sequence-generated values.
119
120 For an identity column defined as GENERATED ALWAYS, it is an error
121 to insert an explicit value (other than DEFAULT) without specifying
122 either OVERRIDING SYSTEM VALUE or OVERRIDING USER VALUE. (For an
123 identity column defined as GENERATED BY DEFAULT, OVERRIDING SYSTEM
124 VALUE is the normal behavior and specifying it does nothing, but
125 PostgreSQL allows it as an extension.)
126
127 OVERRIDING USER VALUE
128 If this clause is specified, then any values supplied for identity
129 columns are ignored and the default sequence-generated values are
130 applied.
131
132 This clause is useful for example when copying values between
133 tables. Writing INSERT INTO tbl2 OVERRIDING USER VALUE SELECT *
134 FROM tbl1 will copy from tbl1 all columns that are not identity
135 columns in tbl2 while values for the identity columns in tbl2 will
136 be generated by the sequences associated with tbl2.
137
138 DEFAULT VALUES
139 All columns will be filled with their default values, as if DEFAULT
140 were explicitly specified for each column. (An OVERRIDING clause is
141 not permitted in this form.)
142
143 expression
144 An expression or value to assign to the corresponding column.
145
146 DEFAULT
147 The corresponding column will be filled with its default value. An
148 identity column will be filled with a new value generated by the
149 associated sequence. For a generated column, specifying this is
150 permitted but merely specifies the normal behavior of computing the
151 column from its generation expression.
152
153 query
154 A query (SELECT statement) that supplies the rows to be inserted.
155 Refer to the SELECT(7) statement for a description of the syntax.
156
157 output_expression
158 An expression to be computed and returned by the INSERT command
159 after each row is inserted or updated. The expression can use any
160 column names of the table named by table_name. Write * to return
161 all columns of the inserted or updated row(s).
162
163 output_name
164 A name to use for a returned column.
165
166 ON CONFLICT Clause
167 The optional ON CONFLICT clause specifies an alternative action to
168 raising a unique violation or exclusion constraint violation error. For
169 each individual row proposed for insertion, either the insertion
170 proceeds, or, if an arbiter constraint or index specified by
171 conflict_target is violated, the alternative conflict_action is taken.
172 ON CONFLICT DO NOTHING simply avoids inserting a row as its alternative
173 action. ON CONFLICT DO UPDATE updates the existing row that conflicts
174 with the row proposed for insertion as its alternative action.
175
176 conflict_target can perform unique index inference. When performing
177 inference, it consists of one or more index_column_name columns and/or
178 index_expression expressions, and an optional index_predicate. All
179 table_name unique indexes that, without regard to order, contain
180 exactly the conflict_target-specified columns/expressions are inferred
181 (chosen) as arbiter indexes. If an index_predicate is specified, it
182 must, as a further requirement for inference, satisfy arbiter indexes.
183 Note that this means a non-partial unique index (a unique index without
184 a predicate) will be inferred (and thus used by ON CONFLICT) if such an
185 index satisfying every other criteria is available. If an attempt at
186 inference is unsuccessful, an error is raised.
187
188 ON CONFLICT DO UPDATE guarantees an atomic INSERT or UPDATE outcome;
189 provided there is no independent error, one of those two outcomes is
190 guaranteed, even under high concurrency. This is also known as UPSERT —
191 “UPDATE or INSERT”.
192
193 conflict_target
194 Specifies which conflicts ON CONFLICT takes the alternative action
195 on by choosing arbiter indexes. Either performs unique index
196 inference, or names a constraint explicitly. For ON CONFLICT DO
197 NOTHING, it is optional to specify a conflict_target; when omitted,
198 conflicts with all usable constraints (and unique indexes) are
199 handled. For ON CONFLICT DO UPDATE, a conflict_target must be
200 provided.
201
202 conflict_action
203 conflict_action specifies an alternative ON CONFLICT action. It can
204 be either DO NOTHING, or a DO UPDATE clause specifying the exact
205 details of the UPDATE action to be performed in case of a conflict.
206 The SET and WHERE clauses in ON CONFLICT DO UPDATE have access to
207 the existing row using the table's name (or an alias), and to rows
208 proposed for insertion using the special excluded table. SELECT
209 privilege is required on any column in the target table where
210 corresponding excluded columns are read.
211
212 Note that the effects of all per-row BEFORE INSERT triggers are
213 reflected in excluded values, since those effects may have
214 contributed to the row being excluded from insertion.
215
216 index_column_name
217 The name of a table_name column. Used to infer arbiter indexes.
218 Follows CREATE INDEX format. SELECT privilege on index_column_name
219 is required.
220
221 index_expression
222 Similar to index_column_name, but used to infer expressions on
223 table_name columns appearing within index definitions (not simple
224 columns). Follows CREATE INDEX format. SELECT privilege on any
225 column appearing within index_expression is required.
226
227 collation
228 When specified, mandates that corresponding index_column_name or
229 index_expression use a particular collation in order to be matched
230 during inference. Typically this is omitted, as collations usually
231 do not affect whether or not a constraint violation occurs. Follows
232 CREATE INDEX format.
233
234 opclass
235 When specified, mandates that corresponding index_column_name or
236 index_expression use particular operator class in order to be
237 matched during inference. Typically this is omitted, as the
238 equality semantics are often equivalent across a type's operator
239 classes anyway, or because it's sufficient to trust that the
240 defined unique indexes have the pertinent definition of equality.
241 Follows CREATE INDEX format.
242
243 index_predicate
244 Used to allow inference of partial unique indexes. Any indexes that
245 satisfy the predicate (which need not actually be partial indexes)
246 can be inferred. Follows CREATE INDEX format. SELECT privilege on
247 any column appearing within index_predicate is required.
248
249 constraint_name
250 Explicitly specifies an arbiter constraint by name, rather than
251 inferring a constraint or index.
252
253 condition
254 An expression that returns a value of type boolean. Only rows for
255 which this expression returns true will be updated, although all
256 rows will be locked when the ON CONFLICT DO UPDATE action is taken.
257 Note that condition is evaluated last, after a conflict has been
258 identified as a candidate to update.
259
260 Note that exclusion constraints are not supported as arbiters with ON
261 CONFLICT DO UPDATE. In all cases, only NOT DEFERRABLE constraints and
262 unique indexes are supported as arbiters.
263
264 INSERT with an ON CONFLICT DO UPDATE clause is a “deterministic”
265 statement. This means that the command will not be allowed to affect
266 any single existing row more than once; a cardinality violation error
267 will be raised when this situation arises. Rows proposed for insertion
268 should not duplicate each other in terms of attributes constrained by
269 an arbiter index or constraint.
270
271 Note that it is currently not supported for the ON CONFLICT DO UPDATE
272 clause of an INSERT applied to a partitioned table to update the
273 partition key of a conflicting row such that it requires the row be
274 moved to a new partition.
275
276 Tip
277 It is often preferable to use unique index inference rather than
278 naming a constraint directly using ON CONFLICT ON CONSTRAINT
279 constraint_name. Inference will continue to work correctly when
280 the underlying index is replaced by another more or less equivalent
281 index in an overlapping way, for example when using CREATE UNIQUE
282 INDEX ... CONCURRENTLY before dropping the index being replaced.
283
285 On successful completion, an INSERT command returns a command tag of
286 the form
287
288 INSERT oid count
289
290 The count is the number of rows inserted or updated. oid is always 0
291 (it used to be the OID assigned to the inserted row if count was
292 exactly one and the target table was declared WITH OIDS and 0
293 otherwise, but creating a table WITH OIDS is not supported anymore).
294
295 If the INSERT command contains a RETURNING clause, the result will be
296 similar to that of a SELECT statement containing the columns and values
297 defined in the RETURNING list, computed over the row(s) inserted or
298 updated by the command.
299
301 If the specified table is a partitioned table, each row is routed to
302 the appropriate partition and inserted into it. If the specified table
303 is a partition, an error will occur if one of the input rows violates
304 the partition constraint.
305
307 Insert a single row into table films:
308
309 INSERT INTO films VALUES
310 ('UA502', 'Bananas', 105, '1971-07-13', 'Comedy', '82 minutes');
311
312 In this example, the len column is omitted and therefore it will have
313 the default value:
314
315 INSERT INTO films (code, title, did, date_prod, kind)
316 VALUES ('T_601', 'Yojimbo', 106, '1961-06-16', 'Drama');
317
318 This example uses the DEFAULT clause for the date columns rather than
319 specifying a value:
320
321 INSERT INTO films VALUES
322 ('UA502', 'Bananas', 105, DEFAULT, 'Comedy', '82 minutes');
323 INSERT INTO films (code, title, did, date_prod, kind)
324 VALUES ('T_601', 'Yojimbo', 106, DEFAULT, 'Drama');
325
326 To insert a row consisting entirely of default values:
327
328 INSERT INTO films DEFAULT VALUES;
329
330 To insert multiple rows using the multirow VALUES syntax:
331
332 INSERT INTO films (code, title, did, date_prod, kind) VALUES
333 ('B6717', 'Tampopo', 110, '1985-02-10', 'Comedy'),
334 ('HG120', 'The Dinner Game', 140, DEFAULT, 'Comedy');
335
336 This example inserts some rows into table films from a table tmp_films
337 with the same column layout as films:
338
339 INSERT INTO films SELECT * FROM tmp_films WHERE date_prod < '2004-05-07';
340
341 This example inserts into array columns:
342
343 -- Create an empty 3x3 gameboard for noughts-and-crosses
344 INSERT INTO tictactoe (game, board[1:3][1:3])
345 VALUES (1, '{{" "," "," "},{" "," "," "},{" "," "," "}}');
346 -- The subscripts in the above example aren't really needed
347 INSERT INTO tictactoe (game, board)
348 VALUES (2, '{{X," "," "},{" ",O," "},{" ",X," "}}');
349
350 Insert a single row into table distributors, returning the sequence
351 number generated by the DEFAULT clause:
352
353 INSERT INTO distributors (did, dname) VALUES (DEFAULT, 'XYZ Widgets')
354 RETURNING did;
355
356 Increment the sales count of the salesperson who manages the account
357 for Acme Corporation, and record the whole updated row along with
358 current time in a log table:
359
360 WITH upd AS (
361 UPDATE employees SET sales_count = sales_count + 1 WHERE id =
362 (SELECT sales_person FROM accounts WHERE name = 'Acme Corporation')
363 RETURNING *
364 )
365 INSERT INTO employees_log SELECT *, current_timestamp FROM upd;
366
367 Insert or update new distributors as appropriate. Assumes a unique
368 index has been defined that constrains values appearing in the did
369 column. Note that the special excluded table is used to reference
370 values originally proposed for insertion:
371
372 INSERT INTO distributors (did, dname)
373 VALUES (5, 'Gizmo Transglobal'), (6, 'Associated Computing, Inc')
374 ON CONFLICT (did) DO UPDATE SET dname = EXCLUDED.dname;
375
376 Insert a distributor, or do nothing for rows proposed for insertion
377 when an existing, excluded row (a row with a matching constrained
378 column or columns after before row insert triggers fire) exists.
379 Example assumes a unique index has been defined that constrains values
380 appearing in the did column:
381
382 INSERT INTO distributors (did, dname) VALUES (7, 'Redline GmbH')
383 ON CONFLICT (did) DO NOTHING;
384
385 Insert or update new distributors as appropriate. Example assumes a
386 unique index has been defined that constrains values appearing in the
387 did column. WHERE clause is used to limit the rows actually updated
388 (any existing row not updated will still be locked, though):
389
390 -- Don't update existing distributors based in a certain ZIP code
391 INSERT INTO distributors AS d (did, dname) VALUES (8, 'Anvil Distribution')
392 ON CONFLICT (did) DO UPDATE
393 SET dname = EXCLUDED.dname || ' (formerly ' || d.dname || ')'
394 WHERE d.zipcode <> '21201';
395
396 -- Name a constraint directly in the statement (uses associated
397 -- index to arbitrate taking the DO NOTHING action)
398 INSERT INTO distributors (did, dname) VALUES (9, 'Antwerp Design')
399 ON CONFLICT ON CONSTRAINT distributors_pkey DO NOTHING;
400
401 Insert new distributor if possible; otherwise DO NOTHING. Example
402 assumes a unique index has been defined that constrains values
403 appearing in the did column on a subset of rows where the is_active
404 Boolean column evaluates to true:
405
406 -- This statement could infer a partial unique index on "did"
407 -- with a predicate of "WHERE is_active", but it could also
408 -- just use a regular unique constraint on "did"
409 INSERT INTO distributors (did, dname) VALUES (10, 'Conrad International')
410 ON CONFLICT (did) WHERE is_active DO NOTHING;
411
413 INSERT conforms to the SQL standard, except that the RETURNING clause
414 is a PostgreSQL extension, as is the ability to use WITH with INSERT,
415 and the ability to specify an alternative action with ON CONFLICT.
416 Also, the case in which a column name list is omitted, but not all the
417 columns are filled from the VALUES clause or query, is disallowed by
418 the standard.
419
420 The SQL standard specifies that OVERRIDING SYSTEM VALUE can only be
421 specified if an identity column that is generated always exists.
422 PostgreSQL allows the clause in any case and ignores it if it is not
423 applicable.
424
425 Possible limitations of the query clause are documented under
426 SELECT(7).
427
428
429
430PostgreSQL 14.3 2022 INSERT(7)