Database Research & Development

  • Home
  • NoSQL
    • NoSQL
    • Cassandra
  • Databases
    • Database Theory
    • Database Designing
    • SQL Server Coding Standards
    • SQL Server
    • PostgreSQL
    • MySQL
    • Greenplum
    • Linux
  • Interviews
    • SQL Server Interviews
    • MySQL Interviews
    • SQL Puzzles
  • DBA Scripts
    • SQL Server DBA Scripts
    • PostgreSQL DBA Scripts
    • MySQL DBA Scripts
    • Greenplum DBA Scripts
  • Home
  • Blog Archives !
  • (: Laugh@dbrnd :)
  • Contact Me !
sqlserverinterviews
Home 2016 August PostgreSQL 9.5: Insert IF not Exists, Update IF Exists (Insert ON CONFLICT option)

PostgreSQL 9.5: Insert IF not Exists, Update IF Exists (Insert ON CONFLICT option)

This article is half-done without your Comment! *** Please share your thoughts via Comment ***

After a long time of waiting, PostgreSQL 9.5 introduced INSERT ON CONFLICT [DO UPDATE] [DO NOTHING].

This option basically helps to perform DML actions like, Insert IF not Exists, Update IF Exists.

Previously, we have to use upsert or merge statement to do this kind of operation. I have also published an article on it.

PostgreSQL: Insert – Update or Upsert – Merge using writable CTE

This newly option has two varieties:

  • INSERT ON CONFLICT DO UPDATE: If record matched, it is updated with the new data value.
  • INSERT ON CONFLICT DO NOTHING: If record matched, it skips the record or error.

Below is a full demonstration of this:

Create a table with sample data:

1
2
3
4
5
6
7
8
9
CREATE TABLE tbl_Employee
(
EmpID INT PRIMARY KEY
,EmpName CHARACTER VARYING
);
 
INSERT INTO tbl_Employee
VALUES (1,'Anvesh'),(2,'Roy'),(3,'Lee')
,(4,'Nivu'),(5,'Rajesh'),(6,'Nupur');

Insert one more row with option INSERT ON CONFLICT DO UPDATE:

Using this option, if a conflict occurs then it will update the mentioned data.
Here, I have use “Excluded” table which is special table and contains the row-to-be-inserted.

1
2
3
4
INSERT INTO tbl_Employee
VALUES (7,'Ramu')
ON CONFLICT (EmpID)
DO UPDATE SET EmpName = Excluded.EmpName;
Try to update last inserted EmpName, using option INSERT ON CONFLICT DO UPDATE:
1
2
3
4
INSERT INTO tbl_Employet
VALUES (7,'Mahi')
ON CONFLICT (EmpID)
DO UPDATE SET EmpName = Excluded.EmpName;
Try to insert duplicate EmpID record, using option INSERT ON DO NOTHING:
Using this option, if conflict occurs then it will not take any action or any error.
1
2
3
4
5
6
7
8
9
INSERT INTO tbl_Employee
VALUES (8,'Noor')
ON CONFLICT (EmpID)
DO NOTHING;
 
INSERT INTO tbl_Employee
VALUES (8,'Noor')
ON CONFLICT (EmpID)
DO NOTHING;
Check the result:
1
2
3
4
5
6
7
8
9
10
11
12
13
14
SELECT *FROM tbl_Employee;
 
/*
EmpID EmpName
-----------------
1 Anvesh
2 Roy
3 Lee
4 Nivu
5 Rajesh
6 Nupur
7 Mahi
8 Noor
*/
Aug 15, 2016Anvesh Patel
PostgreSQL 9.5: Using FOR UPDATE SKIP LOCKED Option SELECT only Committed RecordsPostgreSQL: Why New User can access all Databases without any Grants
Comments: 6
  1. OmarBenSalem
    October 23, 2017 at 8:48 am

    What I don’t understand is when I use this:
    BEGIN

    INSERT INTO alerts VALUES (alertname,desk,creationdate)

    ON CONFLICT (alertname)
    DO UPDATE SET desk = alerts.desk;

    END;

    and that my table is empty, nothing happens, but when there are some values within the table, this does the trick.
    The question is, how to do insert if there is no value in the table and update if there is a conflit
    Thanks!

    • Anvesh Patel
      Anvesh Patel
      October 23, 2017 at 7:18 pm

      This trick is for existing data check, for the empty table you can execute simple INSERT and next time you can use this trick. I will also check one more time and will try to find other solution.

    • Muhammad Waqas
      January 9, 2019 at 3:53 pm

      In my case it’s working all fine. I ‘m using 2 tables, “customer_stage” as source and “customer” as target. “customer_stage” table has 6 rows and “customer” table is empty initially. After executing following statement all the 6 records from “customer_stage” are inserted to “customer” table:

      INSERT INTO customer (cust_id, name, address)
      SELECT cust_id, name, address
      FROM customer_stage
      ON CONFLICT (cust_id) DO UPDATE
      SET address = excluded.address;

      As your comment is too much old and I’ve tried it today, there are chances that ON CONFLICT clause might have got some improvements.

  2. Martín Calvo
    October 31, 2018 at 5:25 pm

    Great tip… Thanks a lot!
    Worked smoothly for me!

  3. Muhammad Waqas
    January 9, 2019 at 3:55 pm

    @OmarBenSalem
    In my case it’s working all fine. I ‘m using 2 tables, “customer_stage” as source and “customer” as target. “customer_stage” table has 6 rows and “customer” table is empty initially. After executing following statement all the 6 records from “customer_stage” are inserted to “customer” table:

    INSERT INTO customer (cust_id, name, address)
    SELECT cust_id, name, address
    FROM customer_stage
    ON CONFLICT (cust_id) DO UPDATE
    SET address = excluded.address;

    As your comment is too much old and I’ve tried it today, there are chances that ON CONFLICT clause might have got some improvements.

  4. Bea
    January 10, 2019 at 6:35 am

    Thanks!

Anvesh Patel
Anvesh Patel

Database Engineer

August 15, 2016 PostgreSQLAnvesh Patel, database, database research and development, dbrnd, insert if not exists, INSERT ON CONFLICT DO NOTHING, INSERT ON CONFLICT DO UPDATE, plpgsql, Postgres Query, postgresql, postgresql 9.5, PostgreSQL Administrator, PostgreSQL Error, PostgreSQL Programming, PostgreSQL Tips and Tricks, UPDATE IF EXISTS
About Me!

I'm Anvesh Patel, a Database Engineer certified by Oracle and IBM. I'm working as a Database Architect, Database Optimizer, Database Administrator, Database Developer. Providing the best articles and solutions for different problems in the best manner through my blogs is my passion. I have more than six years of experience with various RDBMS products like MSSQL Server, PostgreSQL, MySQL, Greenplum and currently learning and doing research on BIGData and NoSQL technology. -- Hyderabad, India.

About DBRND !

dbrnd

This is a personal blog (www.dbrnd.com).

Any views or opinions represented in this blog are personal and belong solely to the blog owner and do not represent those of people, institutions or organizations that the owner may or may not be associated with in professional or personal capacity, unless explicitly stated.

Feel free to challenge me, disagree with me, or tell me I’m completely nuts in the comments section of each blog entry, but I reserve the right to delete any comment for any reason whatsoever (abusive, profane, rude, or anonymous comments) - so keep it polite.

The content of this website is protected by copyright. No portion of this website may be copied or replicated in any form without the written consent of the website owner.

Recent Comments !
  • Anvesh Patel { Sure will do... } – May 27, 12:43 PM
  • Anvesh Patel { Great... } – May 27, 12:41 PM
  • Anvesh Patel { Great... } – May 27, 12:39 PM
  • Anvesh Patel { Great... } – May 27, 12:36 PM
  • Anvesh Patel { Great... } – May 27, 12:28 PM
  • Anvesh Patel { Great... } – May 27, 12:27 PM
  • Anvesh Patel { Great... } – May 27, 12:16 PM
  • Older »
Follow Me !
  • facebook
  • linkedin
  • twitter
  • youtube
  • google
  • flickr
© 2015 – 2019 All rights reserved. Database Research & Development (dbrnd.com)
Posting....