UPSERT/MERGE using Writable CTE in PostgreSQL 9.1

There is always discussion of having UPSERT/MERGE in postgresql. Since, oracle and other RDBMS has this feature, therefore people ask about this feature in PostgeSQL.

In previous version of PostgreSQL, we used to implement it using functions. Now in PostgreSQL 9.1, user can implement this feature using Writable CTE.

PostgreSQL 9.1, now has Writable CTE using WTH.

WITH provides a way to write auxiliary statements for use in a larger query. These statements, which are often referred to as Common Table Expressions or CTEs, can be thought of as defining temporary tables that exist just for one query. Each auxiliary statement in a WITH clause can be a SELECT, INSERT, UPDATE, or DELETE; and the WITH clause itself is attached to a primary statement that can also be a SELECT, INSERT, UPDATE, or DELETE. Lets see how we can use Writable CTE for UPSERT. Following are SQL Code which can be use in Oracle and PostgreSQL for creating sample data: For oracle:
create table myTable
  (pid number, sales number, status varchar2(6));

create table myTable2
  (pid number, sales number, status varchar2(6));

insert into myTable2 values(1,12,'CURR');
insert into myTable2 values(2,13,'NEW' );
insert into myTable2 values(3,15,'CURR');
insert into myTable  values(2,24,'CURR');
insert into myTable  values(3, 0,'OBS' );
insert into myTable  values(4,42,'CURR');
select * from myTable2;
For PostgreSQL 9.1:
create table myTable
  (pid numeric, sales numeric, status varchar(6));

create table myTable2
  (pid numeric, sales numeric, status varchar(6));

insert into myTable2 values(1,12,'CURR');
insert into myTable2 values(2,13,'NEW' );
insert into myTable2 values(3,15,'CURR');
insert into myTable  values(2,24,'CURR');
insert into myTable  values(3, 0,'OBS' );
insert into myTable  values(4,42,'CURR');
select * from myTable2;
In Oracle, people use Merge Something like given below:
merge into myTable2 m
         using myTable d
          on (m.pid = d.pid)
   when  matched
   then  update set   m.sales  = m.sales+d.sales
                ,     m.status = d.status
   when  not matched
   then  insert values (d.pid,d.sales,'NEW');

SQL> select * from myTable2;
       PID SALES STATUS
---------- ---------- ------
  1    12 CURR
  2    37 CURR
  3    15 OBS
  4    42 NEW
In PostgreSQL 9.1, with writable CTE:
WITH upsert as
(update mytable2 m set sales=m.sales+d.sales, status=d.status from mytable d where m.pid=d.pid
  RETURNING m.*
)
insert into mytable2 select a.pid, a.sales,'NEW' from mytable a where a.pid not in (select b.pid from mytable2 b);


postgres=# select * from mytable2 order by 1;
 pid | sales | status 
-----+-------+--------
   1 |    12 | CURR
   2 |    37 | CURR
   3 |    15 | OBS
   4 |    42 | NEW
Now, we have Writable CTE which can help us make UPSERT in PostgreSQL. Enjoy :)

Comments

  1. thanks a lot. You have saved my job!!!!!!!!!!!!!!!!!!!!!!!!!

    ReplyDelete

Post a Comment

Popular posts from this blog

Does UPDATE Change ROWID in Oracle?

PostgreSQL Database Link to Oracle Database on Linux

Fix of "ORA-29275: partial multibyte character"