doc-exports/docs/dws/dev/dws_06_0237.html
Lu, Huayi e6fa411af0 DWS DEV 830.201 version
Reviewed-by: Pruthi, Vineet <vineet.pruthi@t-systems.com>
Co-authored-by: Lu, Huayi <luhuayi@huawei.com>
Co-committed-by: Lu, Huayi <luhuayi@huawei.com>
2024-05-16 07:24:04 +00:00

231 lines
52 KiB
HTML

<a name="EN-US_TOPIC_0000001188110570"></a><a name="EN-US_TOPIC_0000001188110570"></a>
<h1 class="topictitle1">UPSERT</h1>
<div id="body0000001128647083"><div class="section" id="EN-US_TOPIC_0000001188110570__section96559314154"><h4 class="sectiontitle">Function</h4><p id="EN-US_TOPIC_0000001188110570__p10655173131519"><strong id="EN-US_TOPIC_0000001188110570__b415693812713">UPSERT</strong> inserts rows into a table. When a row duplicates an existing primary key or unique key value, the row will be ignored or updated.</p>
<div class="notice" id="EN-US_TOPIC_0000001188110570__note1511919271218"><span class="noticetitle"><img src="public_sys-resources/notice_3.0-en-us.png"> </span><div class="noticebody"><p id="EN-US_TOPIC_0000001188110570__p1311932101211">The <strong id="EN-US_TOPIC_0000001188110570__b131939102535">UPSERT</strong> syntax is supported only in 8.1.1 and later.</p>
</div></div>
</div>
<div class="section" id="EN-US_TOPIC_0000001188110570__section5184175017112"><h4 class="sectiontitle">Precautions</h4><ul id="EN-US_TOPIC_0000001188110570__ul2184155011113"><li id="EN-US_TOPIC_0000001188110570__li181842508111">When <strong id="EN-US_TOPIC_0000001188110570__b44621024195716">UPSERT </strong>is executed on column-store tables, you are advised to enable the DELTA table. Enabling the DELTA table can effectively prevent small CUs from being generated during UPSERT execution. (A large number of small CUs may cause space expansion and poor query performance.)</li><li id="EN-US_TOPIC_0000001188110570__li5208132813312">In scenarios where <strong id="EN-US_TOPIC_0000001188110570__b1951612269579">UPSERT</strong>, <strong id="EN-US_TOPIC_0000001188110570__b1951682614579">UPDATE</strong>, and <strong id="EN-US_TOPIC_0000001188110570__b185164268578">DELETE </strong>operations are concurrently performed on column-store tables, these operations cannot be concurrently performed because they need to wait for the CU lock. This problem cannot be solved even if the DELTA table is enabled.</li><li id="EN-US_TOPIC_0000001188110570__li51841050151118">Only users with the <strong id="EN-US_TOPIC_0000001188110570__b20840521851">INSERT</strong> or <strong id="EN-US_TOPIC_0000001188110570__b1984013218511">UPDATE</strong> permission on a table can run the <strong id="EN-US_TOPIC_0000001188110570__b884118211858">UPSERT</strong> statement to insert data to or update data in the table.</li><li id="EN-US_TOPIC_0000001188110570__li131844502117">The <strong id="EN-US_TOPIC_0000001188110570__b13709104133717">UPSERT</strong> statement of updating data upon conflict can be executed only when the target table contains a primary key or unique index.</li><li id="EN-US_TOPIC_0000001188110570__li15184195012115">The <strong id="EN-US_TOPIC_0000001188110570__b3653193411419">UPSERT</strong> statement of updating data upon conflict cannot be executed if no unique indexes are available. You can execute the statement only after the indexes are rebuilt.</li><li id="EN-US_TOPIC_0000001188110570__li118465031116">A distributed deadlock may occur, resulting in query hanging.<div class="note" id="EN-US_TOPIC_0000001188110570__note1818415041110"><img src="public_sys-resources/note_3.0-en-us.png"><span class="notetitle"> </span><div class="notebody"><p id="EN-US_TOPIC_0000001188110570__p61851507113">For example, multiple <strong id="EN-US_TOPIC_0000001188110570__b878473375718">UPSERT</strong> statements are executed in batches in a transaction or through JDBC (<strong id="EN-US_TOPIC_0000001188110570__b679193315717">setAutoCommit(false)</strong>). Multiple similar tasks are executed at the same time.</p>
<p id="EN-US_TOPIC_0000001188110570__p618595051116"><strong id="EN-US_TOPIC_0000001188110570__b10951844145511">Possible result</strong>: The update sequences of different threads may vary depending on nodes. As a result, a deadlock may occur when the same row is concurrently updated.</p>
<p id="EN-US_TOPIC_0000001188110570__p518565081112"><strong id="EN-US_TOPIC_0000001188110570__b1962965915559">Solution</strong>:</p>
<ol id="EN-US_TOPIC_0000001188110570__ol13185750111110"><li id="EN-US_TOPIC_0000001188110570__li91851450171115">Decrease the value of the GUC parameter <strong id="EN-US_TOPIC_0000001188110570__b229593317587">lockwait_timeout</strong>. The default value is 20 minutes. A distributed deadlock error will be reported after waiting for <em id="EN-US_TOPIC_0000001188110570__i178399214591">the value of <strong id="EN-US_TOPIC_0000001188110570__b583212275915">lockwait_timeout</strong></em>. You can decrease the value of this parameter to reduce the service waiting time caused by a deadlock.</li><li id="EN-US_TOPIC_0000001188110570__li13185185021115">Ensure that data with the same primary key is imported from only one database connection to the database. <strong id="EN-US_TOPIC_0000001188110570__b107545860815654">UPSERT</strong> statements can be executed concurrently.</li><li id="EN-US_TOPIC_0000001188110570__li16185155001115">Only one <strong id="EN-US_TOPIC_0000001188110570__b164716953015654">UPSERT</strong> statement is executed in each transaction. <strong id="EN-US_TOPIC_0000001188110570__b129048426915654">UPSERT</strong> statements can be executed concurrently.</li><li id="EN-US_TOPIC_0000001188110570__li1318513504112">Multiple <strong id="EN-US_TOPIC_0000001188110570__b1638813236563">UPSERT</strong> statements are executed in a single thread. <strong id="EN-US_TOPIC_0000001188110570__b2057776155716">UPSERT</strong> statements cannot be executed concurrently.</li></ol>
<p id="EN-US_TOPIC_0000001188110570__p1018575071117">In the preceding solution, method 1 can only reduce the waiting time but cannot solve the deadlock problem. If there are <strong id="EN-US_TOPIC_0000001188110570__b114752230715654">UPSERT</strong> statements in the service, you are advised to decrease the value of this parameter. Methods 2, 3, and 4 can solve the deadlock problem, but method 2 is recommended because its performance is better than another two methods.</p>
</div></div>
</li><li id="EN-US_TOPIC_0000001188110570__li518545013116">The distribution column cannot be updated (<strong id="EN-US_TOPIC_0000001188110570__b19108164245812">except when the distribution key is the same as the updated value, the distribution column can be updated</strong>).<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188110570__screen1818585081118"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span>
<span class="normal">3</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">CREATE</span><span class="w"> </span><span class="k">TABLE</span><span class="w"> </span><span class="n">t1</span><span class="p">(</span><span class="n">dist_key</span><span class="w"> </span><span class="nb">int</span><span class="w"> </span><span class="k">PRIMARY</span><span class="w"> </span><span class="k">KEY</span><span class="p">,</span><span class="w"> </span><span class="n">a</span><span class="w"> </span><span class="nb">int</span><span class="p">,</span><span class="w"> </span><span class="n">b</span><span class="w"> </span><span class="nb">int</span><span class="p">);</span>
<span class="k">INSERT</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">t1</span><span class="w"> </span><span class="k">VALUES</span><span class="p">(</span><span class="mi">1</span><span class="p">,</span><span class="mi">2</span><span class="p">,</span><span class="mi">3</span><span class="p">)</span><span class="w"> </span><span class="k">ON</span><span class="w"> </span><span class="n">CONFLICT</span><span class="p">(</span><span class="n">dist_key</span><span class="p">)</span><span class="w"> </span><span class="k">DO</span><span class="w"> </span><span class="k">UPDATE</span><span class="w"> </span><span class="k">SET</span><span class="w"> </span><span class="n">dist_key</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">EXCLUDED</span><span class="p">.</span><span class="n">dist_key</span><span class="p">,</span><span class="w"> </span><span class="n">a</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">EXCLUDED</span><span class="p">.</span><span class="n">a</span><span class="w"> </span><span class="o">+</span><span class="w"> </span><span class="mi">1</span><span class="p">;</span>
<span class="k">INSERT</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">t1</span><span class="w"> </span><span class="k">VALUES</span><span class="p">(</span><span class="mi">1</span><span class="p">,</span><span class="mi">2</span><span class="p">,</span><span class="mi">3</span><span class="p">)</span><span class="w"> </span><span class="k">ON</span><span class="w"> </span><span class="n">CONFLICT</span><span class="p">(</span><span class="n">dist_key</span><span class="p">)</span><span class="w"> </span><span class="k">DO</span><span class="w"> </span><span class="k">UPDATE</span><span class="w"> </span><span class="k">SET</span><span class="w"> </span><span class="n">dist_key</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">dist_key</span><span class="p">,</span><span class="w"> </span><span class="n">a</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">EXCLUDED</span><span class="p">.</span><span class="n">a</span><span class="w"> </span><span class="o">+</span><span class="w"> </span><span class="mi">1</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
</li><li id="EN-US_TOPIC_0000001188110570__li1618618506119">The <strong id="EN-US_TOPIC_0000001188110570__b610215552262">UPSERT</strong> statement cannot be executed on the target table that contains a trigger (with the <strong id="EN-US_TOPIC_0000001188110570__b34238818276">INSERT</strong> or <strong id="EN-US_TOPIC_0000001188110570__b3237161118276">UPDATE</strong> trigger event).</li><li id="EN-US_TOPIC_0000001188110570__li181861750141116">The <strong id="EN-US_TOPIC_0000001188110570__b1637104111301">UPSERT</strong> statement is not supported for updatable views.</li><li id="EN-US_TOPIC_0000001188110570__li118625011119">The <strong id="EN-US_TOPIC_0000001188110570__b6568563815">UPDATE</strong> clause, the <strong id="EN-US_TOPIC_0000001188110570__b8946291164">WHERE</strong> clause of <strong id="EN-US_TOPIC_0000001188110570__b1562171541618">UPDATE</strong>, and the index condition expression should not contain functions that cannot be pushed down.</li><li id="EN-US_TOPIC_0000001188110570__li7186115091120">Unique indexes cannot be deferred.</li><li id="EN-US_TOPIC_0000001188110570__li818655091117">When performing the update operation of <strong id="EN-US_TOPIC_0000001188110570__b187505166209">UPSERT</strong> using <strong id="EN-US_TOPIC_0000001188110570__b3419351141716">INSERT INTO SELECT</strong>, pay attention to the query result sequence of <strong id="EN-US_TOPIC_0000001188110570__b1150918598193">SELECT</strong>. In a distributed environment, if the <strong id="EN-US_TOPIC_0000001188110570__b2748135792419">ORDER BY</strong> statement is not used, the sequence of returned results may be different each time the same <strong id="EN-US_TOPIC_0000001188110570__b352212319250">SELECT</strong> statement is executed. As a result, the execution result of the <strong id="EN-US_TOPIC_0000001188110570__b206881428192515">UPSERT</strong> statement does not meet the expectation.</li><li id="EN-US_TOPIC_0000001188110570__li8186145021113">Multiple updates are not supported. If multiple groups of data conflict, an error is reported (<strong id="EN-US_TOPIC_0000001188110570__b3275171445918">except when the query plan is a PGXC plan</strong>).<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188110570__screen3186165051119"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal"> 1</span>
<span class="normal"> 2</span>
<span class="normal"> 3</span>
<span class="normal"> 4</span>
<span class="normal"> 5</span>
<span class="normal"> 6</span>
<span class="normal"> 7</span>
<span class="normal"> 8</span>
<span class="normal"> 9</span>
<span class="normal">10</span>
<span class="normal">11</span>
<span class="normal">12</span>
<span class="normal">13</span>
<span class="normal">14</span>
<span class="normal">15</span>
<span class="normal">16</span>
<span class="normal">17</span>
<span class="normal">18</span>
<span class="normal">19</span>
<span class="normal">20</span>
<span class="normal">21</span>
<span class="normal">22</span>
<span class="normal">23</span>
<span class="normal">24</span>
<span class="normal">25</span>
<span class="normal">26</span>
<span class="normal">27</span>
<span class="normal">28</span>
<span class="normal">29</span>
<span class="normal">30</span>
<span class="normal">31</span>
<span class="normal">32</span>
<span class="normal">33</span>
<span class="normal">34</span>
<span class="normal">35</span>
<span class="normal">36</span>
<span class="normal">37</span>
<span class="normal">38</span>
<span class="normal">39</span>
<span class="normal">40</span>
<span class="normal">41</span>
<span class="normal">42</span>
<span class="normal">43</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">CREATE</span><span class="w"> </span><span class="k">TABLE</span><span class="w"> </span><span class="n">t1</span><span class="p">(</span><span class="n">id</span><span class="w"> </span><span class="nb">int</span><span class="w"> </span><span class="k">PRIMARY</span><span class="w"> </span><span class="k">KEY</span><span class="p">,</span><span class="w"> </span><span class="n">a</span><span class="w"> </span><span class="nb">int</span><span class="p">,</span><span class="w"> </span><span class="n">b</span><span class="w"> </span><span class="nb">int</span><span class="p">);</span>
<span class="c1">-- Use the stream query plan:</span>
<span class="k">EXPLAIN</span><span class="w"> </span><span class="p">(</span><span class="n">COSTS</span><span class="w"> </span><span class="k">OFF</span><span class="p">)</span><span class="w"> </span><span class="k">INSERT</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">t1</span><span class="w"> </span><span class="k">VALUES</span><span class="p">(</span><span class="mi">1</span><span class="p">,</span><span class="mi">2</span><span class="p">,</span><span class="mi">3</span><span class="p">),(</span><span class="mi">1</span><span class="p">,</span><span class="mi">5</span><span class="p">,</span><span class="mi">6</span><span class="p">)</span><span class="w"> </span><span class="k">ON</span><span class="w"> </span><span class="n">CONFLICT</span><span class="p">(</span><span class="n">id</span><span class="p">)</span><span class="w"> </span><span class="k">DO</span><span class="w"> </span><span class="k">UPDATE</span><span class="w"> </span><span class="k">SET</span><span class="w"> </span><span class="n">a</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">EXCLUDED</span><span class="p">.</span><span class="n">a</span><span class="w"> </span><span class="o">+</span><span class="w"> </span><span class="mi">1</span><span class="p">;</span>
<span class="w"> </span><span class="n">QUERY</span><span class="w"> </span><span class="n">PLAN</span>
<span class="c1">------------------------------------------------</span>
<span class="w"> </span><span class="n">id</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="k">operation</span>
<span class="w"> </span><span class="c1">----+-----------------------------------------</span>
<span class="w"> </span><span class="mi">1</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Streaming</span><span class="w"> </span><span class="p">(</span><span class="k">type</span><span class="p">:</span><span class="w"> </span><span class="n">GATHER</span><span class="p">)</span>
<span class="w"> </span><span class="mi">2</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="k">Insert</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="n">t1</span>
<span class="w"> </span><span class="mi">3</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Streaming</span><span class="p">(</span><span class="k">type</span><span class="p">:</span><span class="w"> </span><span class="n">REDISTRIBUTE</span><span class="p">)</span>
<span class="w"> </span><span class="mi">4</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="k">Values</span><span class="w"> </span><span class="n">Scan</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="ss">&quot;*VALUES*&quot;</span>
<span class="w"> </span><span class="n">Predicate</span><span class="w"> </span><span class="n">Information</span><span class="w"> </span><span class="p">(</span><span class="n">identified</span><span class="w"> </span><span class="k">by</span><span class="w"> </span><span class="n">plan</span><span class="w"> </span><span class="n">id</span><span class="p">)</span>
<span class="w"> </span><span class="c1">---------------------------------------------</span>
<span class="w"> </span><span class="mi">2</span><span class="w"> </span><span class="c1">--Insert on t1</span>
<span class="w"> </span><span class="n">Conflict</span><span class="w"> </span><span class="n">Resolution</span><span class="p">:</span><span class="w"> </span><span class="k">UPDATE</span>
<span class="w"> </span><span class="n">Conflict</span><span class="w"> </span><span class="n">Arbiter</span><span class="w"> </span><span class="n">Indexes</span><span class="p">:</span><span class="w"> </span><span class="n">t1_pkey</span>
<span class="w"> </span><span class="o">======</span><span class="w"> </span><span class="n">Query</span><span class="w"> </span><span class="n">Summary</span><span class="w"> </span><span class="o">=====</span>
<span class="w"> </span><span class="c1">------------------------------</span>
<span class="w"> </span><span class="k">System</span><span class="w"> </span><span class="n">available</span><span class="w"> </span><span class="n">mem</span><span class="p">:</span><span class="w"> </span><span class="mi">819200</span><span class="n">KB</span>
<span class="w"> </span><span class="n">Query</span><span class="w"> </span><span class="k">Max</span><span class="w"> </span><span class="n">mem</span><span class="p">:</span><span class="w"> </span><span class="mi">819200</span><span class="n">KB</span>
<span class="w"> </span><span class="n">Query</span><span class="w"> </span><span class="n">estimated</span><span class="w"> </span><span class="n">mem</span><span class="p">:</span><span class="w"> </span><span class="mi">3104</span><span class="n">KB</span>
<span class="p">(</span><span class="mi">18</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
<span class="k">INSERT</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">t1</span><span class="w"> </span><span class="k">VALUES</span><span class="p">(</span><span class="mi">1</span><span class="p">,</span><span class="mi">2</span><span class="p">,</span><span class="mi">3</span><span class="p">),(</span><span class="mi">1</span><span class="p">,</span><span class="mi">5</span><span class="p">,</span><span class="mi">6</span><span class="p">)</span><span class="w"> </span><span class="k">ON</span><span class="w"> </span><span class="n">CONFLICT</span><span class="p">(</span><span class="n">id</span><span class="p">)</span><span class="w"> </span><span class="k">DO</span><span class="w"> </span><span class="k">UPDATE</span><span class="w"> </span><span class="k">SET</span><span class="w"> </span><span class="n">a</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">EXCLUDED</span><span class="p">.</span><span class="n">a</span><span class="w"> </span><span class="o">+</span><span class="w"> </span><span class="mi">1</span><span class="p">;</span>
<span class="n">ERROR</span><span class="p">:</span><span class="w"> </span><span class="k">INSERT</span><span class="w"> </span><span class="k">ON</span><span class="w"> </span><span class="n">CONFLICT</span><span class="w"> </span><span class="k">DO</span><span class="w"> </span><span class="k">UPDATE</span><span class="w"> </span><span class="n">command</span><span class="w"> </span><span class="n">cannot</span><span class="w"> </span><span class="n">affect</span><span class="w"> </span><span class="k">row</span><span class="w"> </span><span class="n">a</span><span class="w"> </span><span class="k">second</span><span class="w"> </span><span class="k">time</span>
<span class="n">HINT</span><span class="p">:</span><span class="w"> </span><span class="n">Ensure</span><span class="w"> </span><span class="n">that</span><span class="w"> </span><span class="k">no</span><span class="w"> </span><span class="k">rows</span><span class="w"> </span><span class="n">proposed</span><span class="w"> </span><span class="k">for</span><span class="w"> </span><span class="n">insertion</span><span class="w"> </span><span class="n">within</span><span class="w"> </span><span class="n">the</span><span class="w"> </span><span class="n">same</span><span class="w"> </span><span class="n">command</span><span class="w"> </span><span class="n">have</span><span class="w"> </span><span class="n">duplicate</span><span class="w"> </span><span class="n">constrained</span><span class="w"> </span><span class="k">values</span><span class="p">.</span>
<span class="c1">-- Disable the stream plan and generate a PGXC plan:</span>
<span class="k">set</span><span class="w"> </span><span class="n">enable_stream_operator</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="k">off</span><span class="p">;</span>
<span class="k">EXPLAIN</span><span class="w"> </span><span class="p">(</span><span class="n">COSTS</span><span class="w"> </span><span class="k">OFF</span><span class="p">)</span><span class="w"> </span><span class="k">INSERT</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">t1</span><span class="w"> </span><span class="k">VALUES</span><span class="p">(</span><span class="mi">1</span><span class="p">,</span><span class="mi">2</span><span class="p">,</span><span class="mi">3</span><span class="p">),(</span><span class="mi">1</span><span class="p">,</span><span class="mi">5</span><span class="p">,</span><span class="mi">6</span><span class="p">)</span><span class="w"> </span><span class="k">ON</span><span class="w"> </span><span class="n">CONFLICT</span><span class="p">(</span><span class="n">id</span><span class="p">)</span><span class="w"> </span><span class="k">DO</span><span class="w"> </span><span class="k">UPDATE</span><span class="w"> </span><span class="k">SET</span><span class="w"> </span><span class="n">a</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">EXCLUDED</span><span class="p">.</span><span class="n">a</span><span class="w"> </span><span class="o">+</span><span class="w"> </span><span class="mi">1</span><span class="p">;</span>
<span class="w"> </span><span class="n">QUERY</span><span class="w"> </span><span class="n">PLAN</span>
<span class="c1">-----------------------------------------------</span>
<span class="w"> </span><span class="n">id</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="k">operation</span>
<span class="w"> </span><span class="c1">----+----------------------------------</span>
<span class="w"> </span><span class="mi">1</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="k">Insert</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="n">t1</span>
<span class="w"> </span><span class="mi">2</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="k">Values</span><span class="w"> </span><span class="n">Scan</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="ss">&quot;*VALUES*&quot;</span>
<span class="w"> </span><span class="n">Predicate</span><span class="w"> </span><span class="n">Information</span><span class="w"> </span><span class="p">(</span><span class="n">identified</span><span class="w"> </span><span class="k">by</span><span class="w"> </span><span class="n">plan</span><span class="w"> </span><span class="n">id</span><span class="p">)</span>
<span class="w"> </span><span class="c1">---------------------------------------------</span>
<span class="w"> </span><span class="mi">1</span><span class="w"> </span><span class="c1">--Insert on t1</span>
<span class="w"> </span><span class="n">Conflict</span><span class="w"> </span><span class="n">Resolution</span><span class="p">:</span><span class="w"> </span><span class="k">UPDATE</span>
<span class="w"> </span><span class="n">Conflict</span><span class="w"> </span><span class="n">Arbiter</span><span class="w"> </span><span class="n">Indexes</span><span class="p">:</span><span class="w"> </span><span class="n">t1_pkey</span>
<span class="w"> </span><span class="n">Node</span><span class="w"> </span><span class="n">expr</span><span class="p">:</span><span class="w"> </span><span class="n">id</span>
<span class="p">(</span><span class="mi">11</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
<span class="k">INSERT</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">t1</span><span class="w"> </span><span class="k">VALUES</span><span class="p">(</span><span class="mi">1</span><span class="p">,</span><span class="mi">2</span><span class="p">,</span><span class="mi">3</span><span class="p">),(</span><span class="mi">1</span><span class="p">,</span><span class="mi">5</span><span class="p">,</span><span class="mi">6</span><span class="p">)</span><span class="w"> </span><span class="k">ON</span><span class="w"> </span><span class="n">CONFLICT</span><span class="p">(</span><span class="n">id</span><span class="p">)</span><span class="w"> </span><span class="k">DO</span><span class="w"> </span><span class="k">UPDATE</span><span class="w"> </span><span class="k">SET</span><span class="w"> </span><span class="n">a</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">EXCLUDED</span><span class="p">.</span><span class="n">a</span><span class="w"> </span><span class="o">+</span><span class="w"> </span><span class="mi">1</span><span class="p">;</span>
<span class="k">INSERT</span><span class="w"> </span><span class="mi">0</span><span class="w"> </span><span class="mi">2</span>
</pre></div></td></tr></table></div>
</div>
</li></ul>
</div>
<div class="section" id="EN-US_TOPIC_0000001188110570__section128601334191818"><h4 class="sectiontitle">Syntax</h4><p id="EN-US_TOPIC_0000001188110570__p20588194511819">For details, see <a href="dws_06_0236.html#EN-US_TOPIC_0000001233708655__se26969fe97994814b5f45a6173164204">Syntax</a> of <strong id="EN-US_TOPIC_0000001188110570__b122062020181014">INSERT</strong>. The following table describes the syntax of <strong id="EN-US_TOPIC_0000001188110570__b6686131916128">UPSERT</strong>.</p>
<div class="tablenoborder"><a name="EN-US_TOPIC_0000001188110570__table663035101813"></a><a name="table663035101813"></a><table cellpadding="4" cellspacing="0" summary="" id="EN-US_TOPIC_0000001188110570__table663035101813" frame="border" border="1" rules="all"><caption><b>Table 1 </b>UPSERT syntax</caption><thead align="left"><tr id="EN-US_TOPIC_0000001188110570__row261035171818"><th align="left" class="cellrowborder" valign="top" width="20%" id="mcps1.3.3.3.2.4.1.1"><p id="EN-US_TOPIC_0000001188110570__p9611235101812">Syntax</p>
</th>
<th align="left" class="cellrowborder" valign="top" width="50%" id="mcps1.3.3.3.2.4.1.2"><p id="EN-US_TOPIC_0000001188110570__p15611935121816">Update Data Upon Conflict</p>
</th>
<th align="left" class="cellrowborder" valign="top" width="30%" id="mcps1.3.3.3.2.4.1.3"><p id="EN-US_TOPIC_0000001188110570__p36123517186">Ignore Data Upon Conflict</p>
</th>
</tr>
</thead>
<tbody><tr id="EN-US_TOPIC_0000001188110570__row46213581815"><td class="cellrowborder" valign="top" width="20%" headers="mcps1.3.3.3.2.4.1.1 "><p id="EN-US_TOPIC_0000001188110570__p196113359183">Syntax 1: No index is specified.</p>
</td>
<td class="cellrowborder" valign="top" width="50%" headers="mcps1.3.3.3.2.4.1.2 "><pre class="screen" id="EN-US_TOPIC_0000001188110570__screen10798943161918">INSERT INTO ON DUPLICATE KEY UPDATE</pre>
</td>
<td class="cellrowborder" valign="top" width="30%" headers="mcps1.3.3.3.2.4.1.3 "><pre class="screen" id="EN-US_TOPIC_0000001188110570__screen139871862019">INSERT IGNORE
INSERT INTO ON CONFLICT DO NOTHING</pre>
</td>
</tr>
<tr id="EN-US_TOPIC_0000001188110570__row663163591811"><td class="cellrowborder" valign="top" width="20%" headers="mcps1.3.3.3.2.4.1.1 "><p id="EN-US_TOPIC_0000001188110570__p962163521814">Syntax 2: The unique key constraint can be inferred from the specified column name or constraint name.</p>
</td>
<td class="cellrowborder" valign="top" width="50%" headers="mcps1.3.3.3.2.4.1.2 "><pre class="screen" id="EN-US_TOPIC_0000001188110570__screen122585578195">INSERT INTO ON CONFLICT(...) DO UPDATE SET
INSERT INTO ON CONFLICT ON CONSTRAINT con_name DO UPDATE SET</pre>
</td>
<td class="cellrowborder" valign="top" width="30%" headers="mcps1.3.3.3.2.4.1.3 "><pre class="screen" id="EN-US_TOPIC_0000001188110570__screen95451842200">INSERT INTO ON CONFLICT(...) DO NOTHING
INSERT INTO ON CONFLICT ON CONSTRAINT con_name DO NOTHING</pre>
</td>
</tr>
</tbody>
</table>
</div>
</div>
<p id="EN-US_TOPIC_0000001188110570__p10130926123511">In syntax 1, no index is specified. The system checks for conflicts on all primary keys or unique indexes. If a conflict exists, the system ignores or updates the corresponding data.</p>
<p id="EN-US_TOPIC_0000001188110570__p1868482015368">In syntax 2, a specified index is used for conflict check. The primary key or unique index is inferred from the column name, the expression that contains column names, or the constraint name specified in the <strong id="EN-US_TOPIC_0000001188110570__b17702181815615">ON CONFLICT</strong> clause.</p>
<ul id="EN-US_TOPIC_0000001188110570__ul56041217417"><li id="EN-US_TOPIC_0000001188110570__li8686111819410">Unique index inference<p id="EN-US_TOPIC_0000001188110570__p152226442"><a name="EN-US_TOPIC_0000001188110570__li8686111819410"></a><a name="li8686111819410"></a>Syntax 2 infers the primary key or unique index by specifying the column name or constraint name. You can specify a single column name or multiple column names by using an expression, for example, <strong id="EN-US_TOPIC_0000001188110570__b7251201941320">(column1, column2, column3)</strong>.</p>
<p id="EN-US_TOPIC_0000001188110570__p99971411183"><strong id="EN-US_TOPIC_0000001188110570__b1678462110486">collation</strong> and <strong id="EN-US_TOPIC_0000001188110570__b1027722414816">opclass</strong> can be specified when you create an index. Therefore, you can also specify them after the column name for index inference.</p>
<p id="EN-US_TOPIC_0000001188110570__p102579616171"><strong id="EN-US_TOPIC_0000001188110570__b202861305518">COLLATE collation</strong> specifies the collation of a column, and <strong id="EN-US_TOPIC_0000001188110570__b1883654018569">opclass</strong> specifies the name of the operator class. For details, see <a href="dws_06_0165.html">CREATE INDEX</a>.</p>
<div class="p" id="EN-US_TOPIC_0000001188110570__p1914124720227">When inferring the unique index from an expression that includes multiple column names, the system checks whether there is a unique index that exactly contains all the column names specified by <strong id="EN-US_TOPIC_0000001188110570__b181861164712">conflict_target</strong>.<ul id="EN-US_TOPIC_0000001188110570__ul122481958182515"><li id="EN-US_TOPIC_0000001188110570__li320152422615">If <strong id="EN-US_TOPIC_0000001188110570__b096101488">collation</strong> and <strong id="EN-US_TOPIC_0000001188110570__b4405319811">opclass</strong> are not specified, a match is considered found as long as a column has the same name as the specified single column or multiple columns have the same names as those specified by the column expression (regardless of the values of <strong id="EN-US_TOPIC_0000001188110570__b10968355121017">collation</strong> and <strong id="EN-US_TOPIC_0000001188110570__b161141458191012">opclass</strong> specified for the index column).</li><li id="EN-US_TOPIC_0000001188110570__li102481058102511">If <strong id="EN-US_TOPIC_0000001188110570__b12308348111318">collation</strong> and <strong id="EN-US_TOPIC_0000001188110570__b246605017132">opclass</strong> are specified, their values must also match the <strong id="EN-US_TOPIC_0000001188110570__b1325152916147">collation</strong> and <strong id="EN-US_TOPIC_0000001188110570__b12344931171413">opclass</strong> of the index.</li></ul>
</div>
</li><li id="EN-US_TOPIC_0000001188110570__li196101274116"><strong id="EN-US_TOPIC_0000001188110570__b10428175019141">UPDATE</strong> clause</li></ul>
<p id="EN-US_TOPIC_0000001188110570__p44397717254">The <strong id="EN-US_TOPIC_0000001188110570__b92135415148">UPDATE</strong> clause can use <strong id="EN-US_TOPIC_0000001188110570__b658820181520">VALUES(colname)</strong> or <strong id="EN-US_TOPIC_0000001188110570__b67448216155">EXCLUDED.colname</strong> to reference inserted data. <strong id="EN-US_TOPIC_0000001188110570__b4668191219150">EXCLUDED</strong> indicates the rows that should be excluded due to conflicts. An example is as follows:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188110570__screen1749114551418"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span>
<span class="normal">3</span>
<span class="normal">4</span>
<span class="normal">5</span>
<span class="normal">6</span>
<span class="normal">7</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">CREATE</span><span class="w"> </span><span class="k">TABLE</span><span class="w"> </span><span class="n">t1</span><span class="p">(</span><span class="n">id</span><span class="w"> </span><span class="nb">int</span><span class="w"> </span><span class="k">PRIMARY</span><span class="w"> </span><span class="k">KEY</span><span class="p">,</span><span class="w"> </span><span class="n">a</span><span class="w"> </span><span class="nb">int</span><span class="p">,</span><span class="w"> </span><span class="n">b</span><span class="w"> </span><span class="nb">int</span><span class="p">);</span>
<span class="k">INSERT</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">t1</span><span class="w"> </span><span class="k">VALUES</span><span class="p">(</span><span class="mi">1</span><span class="p">,</span><span class="mi">1</span><span class="p">,</span><span class="mi">1</span><span class="p">);</span>
<span class="c1">-- Upon a conflicting row, change the value in column a to the value in column a of the target table plus 1, which, in this example, is (1,2,1).</span>
<span class="k">INSERT</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">t1</span><span class="w"> </span><span class="k">VALUES</span><span class="p">(</span><span class="mi">1</span><span class="p">,</span><span class="mi">10</span><span class="p">,</span><span class="mi">20</span><span class="p">)</span><span class="w"> </span><span class="k">ON</span><span class="w"> </span><span class="n">CONFLICT</span><span class="p">(</span><span class="n">id</span><span class="p">)</span><span class="w"> </span><span class="k">DO</span><span class="w"> </span><span class="k">UPDATE</span><span class="w"> </span><span class="k">SET</span><span class="w"> </span><span class="n">a</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">a</span><span class="w"> </span><span class="o">+</span><span class="w"> </span><span class="mi">1</span><span class="p">;</span>
<span class="c1">-- EXCLUDED.a is used to reference the value of column a that is originally proposed for insertion. In this example, the value is 10.</span>
<span class="c1">-- Upon a conflicting row, change the value of column a to that of the referenced column plus 1. In this example, the value is updated to (1,11,1).</span>
<span class="k">INSERT</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">t1</span><span class="w"> </span><span class="k">VALUES</span><span class="p">(</span><span class="mi">1</span><span class="p">,</span><span class="mi">10</span><span class="p">,</span><span class="mi">20</span><span class="p">)</span><span class="w"> </span><span class="k">ON</span><span class="w"> </span><span class="n">CONFLICT</span><span class="p">(</span><span class="n">id</span><span class="p">)</span><span class="w"> </span><span class="k">DO</span><span class="w"> </span><span class="k">UPDATE</span><span class="w"> </span><span class="k">SET</span><span class="w"> </span><span class="n">a</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">EXCLUDED</span><span class="p">.</span><span class="n">a</span><span class="w"> </span><span class="o">+</span><span class="w"> </span><span class="mi">1</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<ul id="EN-US_TOPIC_0000001188110570__ul174849128396"><li id="EN-US_TOPIC_0000001188110570__li20777357396"><strong id="EN-US_TOPIC_0000001188110570__b1146812276262">WHERE</strong> clause<ul id="EN-US_TOPIC_0000001188110570__ul14512164911391"><li id="EN-US_TOPIC_0000001188110570__li114842124399">The <strong id="EN-US_TOPIC_0000001188110570__b186508542811">WHERE</strong> clause is used to determine whether a specified condition is met when data conflict occurs. If yes, update the conflict data. Otherwise, ignore it.</li><li id="EN-US_TOPIC_0000001188110570__li1894841402">Only syntax 2 of <strong id="EN-US_TOPIC_0000001188110570__b118941656152314">Update Data Upon Conflict</strong> can specify the <strong id="EN-US_TOPIC_0000001188110570__b1941082416108">WHERE</strong> clause, that is, <strong id="EN-US_TOPIC_0000001188110570__b133051424103816">INSERT INTO ON CONFLICT(...) DO UPDATE SET WHERE</strong>.</li></ul>
</li></ul>
<div class="p" id="EN-US_TOPIC_0000001188110570__p1622634944716">Note the following when using the syntax:<ul id="EN-US_TOPIC_0000001188110570__ul124393417478"><li id="EN-US_TOPIC_0000001188110570__li13439041194710">Syntax 1 and syntax 2 described in <a href="#EN-US_TOPIC_0000001188110570__table663035101813">Table 1</a> cannot be used together in the same statement.</li><li id="EN-US_TOPIC_0000001188110570__li1439124116471">The <strong id="EN-US_TOPIC_0000001188110570__b1062956114314">WITH</strong> clause cannot be used at the same time.</li><li id="EN-US_TOPIC_0000001188110570__li12439174117470"><strong id="EN-US_TOPIC_0000001188110570__b1629613121441">INSERT OVERWRITE</strong> cannot be used at the same time.</li><li id="EN-US_TOPIC_0000001188110570__li543912419476">The <strong id="EN-US_TOPIC_0000001188110570__b1695472019319">UPDATE</strong> clause and its <strong id="EN-US_TOPIC_0000001188110570__b167721723137">WHERE</strong> clause do not support subqueries.</li><li id="EN-US_TOPIC_0000001188110570__li1143934117472"><strong id="EN-US_TOPIC_0000001188110570__b947635134419">VALUES(colname)</strong> in the <strong id="EN-US_TOPIC_0000001188110570__b419717376446">UPDATE</strong> clause does not support outer nested functions. That is, the usage similar to <strong id="EN-US_TOPIC_0000001188110570__b18667724479">sqrt(VALUES(colname))</strong> is not supported. To support this function, use the <strong id="EN-US_TOPIC_0000001188110570__b1725811810478">EXCLUDED.colname</strong> syntax.</li><li id="EN-US_TOPIC_0000001188110570__li1440124118474"><strong id="EN-US_TOPIC_0000001188110570__b17180112053214">INSERT INTO ON CONFLICT(...) DO UPDATE</strong> must contain <strong id="EN-US_TOPIC_0000001188110570__b1539117139369">conflict_target</strong>. That is, a column or constraint name must be specified.</li></ul>
</div>
<div class="section" id="EN-US_TOPIC_0000001188110570__section414485520537"><h4 class="sectiontitle">Examples</h4><p id="EN-US_TOPIC_0000001188110570__p15386103875318">Create table <strong id="EN-US_TOPIC_0000001188110570__b114695716569">reason_t2</strong> and insert data into it.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188110570__screen13386638175310"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal"> 1</span>
<span class="normal"> 2</span>
<span class="normal"> 3</span>
<span class="normal"> 4</span>
<span class="normal"> 5</span>
<span class="normal"> 6</span>
<span class="normal"> 7</span>
<span class="normal"> 8</span>
<span class="normal"> 9</span>
<span class="normal">10</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">DROP</span><span class="w"> </span><span class="k">TABLE</span><span class="w"> </span><span class="k">IF</span><span class="w"> </span><span class="k">EXISTS</span><span class="w"> </span><span class="n">reason_t2</span><span class="p">;</span>
<span class="k">CREATE</span><span class="w"> </span><span class="k">TABLE</span><span class="w"> </span><span class="n">reason_t2</span>
<span class="p">(</span>
<span class="w"> </span><span class="n">a</span><span class="w"> </span><span class="nb">int</span><span class="w"> </span><span class="k">primary</span><span class="w"> </span><span class="k">key</span><span class="p">,</span>
<span class="w"> </span><span class="n">b</span><span class="w"> </span><span class="nb">int</span><span class="p">,</span>
<span class="w"> </span><span class="k">c</span><span class="w"> </span><span class="nb">int</span>
<span class="p">);</span>
<span class="k">INSERT</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">reason_t2</span><span class="w"> </span><span class="k">VALUES</span><span class="w"> </span><span class="p">(</span><span class="mi">1</span><span class="p">,</span><span class="w"> </span><span class="mi">2</span><span class="p">,</span><span class="w"> </span><span class="mi">3</span><span class="p">);</span>
<span class="k">SELECT</span><span class="w"> </span><span class="o">*</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">reason_t2</span><span class="w"> </span><span class="k">ORDER</span><span class="w"> </span><span class="k">BY</span><span class="w"> </span><span class="mi">1</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001188110570__p163871938155310">Insert two data records into the table <strong id="EN-US_TOPIC_0000001188110570__b57261713185717">reason_t2</strong>. One data record conflicts and the other does not. Conflicting data is ignored, and non-conflicting data is inserted.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188110570__screen15387203810531"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">INSERT</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">reason_t2</span><span class="w"> </span><span class="k">VALUES</span><span class="w"> </span><span class="p">(</span><span class="mi">1</span><span class="p">,</span><span class="w"> </span><span class="mi">4</span><span class="p">,</span><span class="w"> </span><span class="mi">5</span><span class="p">),(</span><span class="mi">2</span><span class="p">,</span><span class="w"> </span><span class="mi">6</span><span class="p">,</span><span class="w"> </span><span class="mi">7</span><span class="p">)</span><span class="w"> </span><span class="k">ON</span><span class="w"> </span><span class="n">CONFLICT</span><span class="p">(</span><span class="n">a</span><span class="p">)</span><span class="w"> </span><span class="k">DO</span><span class="w"> </span><span class="k">NOTHING</span><span class="p">;</span>
<span class="k">SELECT</span><span class="w"> </span><span class="o">*</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">reason_t2</span><span class="w"> </span><span class="k">ORDER</span><span class="w"> </span><span class="k">BY</span><span class="w"> </span><span class="mi">1</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001188110570__p17387638185315">Insert two data records into the table <strong id="EN-US_TOPIC_0000001188110570__b16420282579">reason_t2</strong>. One data record conflicts and the other does not. Conflicting data is updated, and non-conflicting data is inserted.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188110570__screen17387193810533"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">INSERT</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">reason_t2</span><span class="w"> </span><span class="k">VALUES</span><span class="w"> </span><span class="p">(</span><span class="mi">1</span><span class="p">,</span><span class="w"> </span><span class="mi">4</span><span class="p">,</span><span class="w"> </span><span class="mi">5</span><span class="p">),(</span><span class="mi">3</span><span class="p">,</span><span class="w"> </span><span class="mi">8</span><span class="p">,</span><span class="w"> </span><span class="mi">9</span><span class="p">)</span><span class="w"> </span><span class="k">ON</span><span class="w"> </span><span class="n">CONFLICT</span><span class="p">(</span><span class="n">a</span><span class="p">)</span><span class="w"> </span><span class="k">DO</span><span class="w"> </span><span class="k">UPDATE</span><span class="w"> </span><span class="k">SET</span><span class="w"> </span><span class="n">b</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">EXCLUDED</span><span class="p">.</span><span class="n">b</span><span class="p">,</span><span class="w"> </span><span class="k">c</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">EXCLUDED</span><span class="p">.</span><span class="k">c</span><span class="p">;</span>
<span class="k">SELECT</span><span class="w"> </span><span class="o">*</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">reason_t2</span><span class="w"> </span><span class="k">ORDER</span><span class="w"> </span><span class="k">BY</span><span class="w"> </span><span class="mi">1</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001188110570__p12387738125316">Filter the updated rows.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188110570__screen538711387539"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">INSERT</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">reason_t2</span><span class="w"> </span><span class="k">VALUES</span><span class="w"> </span><span class="p">(</span><span class="mi">2</span><span class="p">,</span><span class="w"> </span><span class="mi">7</span><span class="p">,</span><span class="w"> </span><span class="mi">8</span><span class="p">)</span><span class="w"> </span><span class="k">ON</span><span class="w"> </span><span class="n">CONFLICT</span><span class="w"> </span><span class="p">(</span><span class="n">a</span><span class="p">)</span><span class="w"> </span><span class="k">DO</span><span class="w"> </span><span class="k">UPDATE</span><span class="w"> </span><span class="k">SET</span><span class="w"> </span><span class="n">b</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">excluded</span><span class="p">.</span><span class="n">b</span><span class="p">,</span><span class="w"> </span><span class="k">c</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">excluded</span><span class="p">.</span><span class="k">c</span><span class="w"> </span><span class="k">WHERE</span><span class="w"> </span><span class="n">reason_t2</span><span class="p">.</span><span class="k">c</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="mi">7</span><span class="p">;</span>
<span class="k">SELECT</span><span class="w"> </span><span class="o">*</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">reason_t2</span><span class="w"> </span><span class="k">ORDER</span><span class="w"> </span><span class="k">BY</span><span class="w"> </span><span class="mi">1</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001188110570__p33882386536">Insert data into the table <strong id="EN-US_TOPIC_0000001188110570__b17332174575711">reason_t</strong>. Update the conflicting data and adjust the mapping. That is, update column c to column b and column b to column c.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188110570__screen438893817532"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">INSERT</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">reason_t2</span><span class="w"> </span><span class="k">VALUES</span><span class="w"> </span><span class="p">(</span><span class="mi">1</span><span class="p">,</span><span class="w"> </span><span class="mi">2</span><span class="p">,</span><span class="w"> </span><span class="mi">3</span><span class="p">)</span><span class="w"> </span><span class="k">ON</span><span class="w"> </span><span class="n">CONFLICT</span><span class="w"> </span><span class="p">(</span><span class="n">a</span><span class="p">)</span><span class="w"> </span><span class="k">DO</span><span class="w"> </span><span class="k">UPDATE</span><span class="w"> </span><span class="k">SET</span><span class="w"> </span><span class="n">b</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">excluded</span><span class="p">.</span><span class="k">c</span><span class="p">,</span><span class="w"> </span><span class="k">c</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">excluded</span><span class="p">.</span><span class="n">b</span><span class="p">;</span>
<span class="k">SELECT</span><span class="w"> </span><span class="o">*</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">reason_t2</span><span class="w"> </span><span class="k">ORDER</span><span class="w"> </span><span class="k">BY</span><span class="w"> </span><span class="mi">1</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
</div>
</div>
<div>
<div class="familylinks">
<div class="parentlink"><strong>Parent topic:</strong> <a href="dws_06_0275.html">INSERT and UPSERT</a></div>
</div>
</div>