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