gooderp18绿色标准版
You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

465 lines
32KB

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