Googling 'upsert' (an Oraclism, I believe) will get you hits on Oracle and DB2's implementation of MERGE, which does what AMOUNTS to what is
described below (one mass UPDATE...FROM, one mass INSERT...WHERE NOT EXISTS).


No, you shouldn't iterate row-by-row through the temp table.
Whenever possible, try to do updates in one single (mass) operation.
Doing it that way gives the optimizer the best chance at amortizing
fixed costs, and batching operations.

---------
In any database other than Postgres, I would recommend doing the
INSERT /followed by/ the UPDATE. That order looks wonky --- your update
ends up pointlessly operating on the rows just INSERTED. The trick is, UPDATE acquires and holds write locks (the rows were previously visible to other processes), while INSERT's write locks refer to rows that no other process could try to lock.


Stephen Frost wrote:
* Markus Schaber ([EMAIL PROTECTED]) wrote:

Generally, what is the fastest way for doing bulk processing of update-if-primary-key-matches-and-insert-otherwise operations?


This is a very good question, and I havn't seen much of an answer to it
yet.  I'm curious about the answer myself, actually.  In the more recent
SQL specs, from what I understand, this is essentially what the 'MERGE'
command is for.  This was recently added and unfortunately is not yet
supported in Postgres.  Hopefully it will be added soon.

Otherwise, what I've done is basically an update followed by an insert
using outer joins.  If there's something better, I'd love to hear about
it.  The statements looks something like:

update X
  set colA = a.colA,
      colB = a.colB
  from Y a
  where keyA = a.keyA and
        keyB = a.keyB;

insert into X
  select a.keyA,
         a.keyB,
         a.colA,
         a.colB
  from Y a left join X b
       using (keyA, keyB)
  where b.keyA is NULL and
        b.keyB is NULL;

With the appropriate indexes, this is pretty fast but I think a merge
would be much faster.

                Thanks,

Stephen

---------------------------(end of broadcast)--------------------------- TIP 1: subscribe and unsubscribe commands go to [EMAIL PROTECTED]

Reply via email to