Re: Bulk loading/merging

From: "Jim C(dot) Nasby" <jnasby(at)pervasive(dot)com>
To: Michael Artz <mlartz(at)gmail(dot)com>
Cc: pgsql-performance(at)postgresql(dot)org
Subject: Re: Bulk loading/merging
Date: 2006-06-05 15:04:25
Message-ID: 20060605150425.GS53487@pervasive.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-performance

On Thu, Jun 01, 2006 at 02:04:46PM -0400, Michael Artz wrote:
> On 5/30/06, Jim C. Nasby <jnasby(at)pervasive(dot)com> wrote:
>
> >Your best bet is to do this as a single, bulk operation if possible.
> >That way you can simply do an UPDATE ... WHERE EXISTS followed by an
> >INSERT ... SELECT ... WHERE NOT EXISTS.
>
>
>
> hmm, I don't quite understand what you are saying and I think my
> basic misunderstanding is how to use the UPDATE ... WHERE EXISTS to merge
> data in bulk. Assuming that I bulk COPYed the data into a temporary
> table, I'd need to issue an UPDATE for each row in the newly created table,
> right?
>
> For example, for a slightly different key,count schema:
>
> CREATE TABLE kc (key integer, count integer);
>
> and wanting to merge the following data by just updating the count for a
> given key to the equivalent of OLD.count + NEW.count:
>
> 1,10
> 2,15
> 3,45
> 1,30
>
> How would I go about using UPDATE ... WHERE EXISTS to update the "master" kc
> table from a (temporary) table loaded with the above data?

CREATE TEMP TABLE moo () LIKE kc;
COPY ... moo;
BEGIN;
UPDATE kc
SET count=kc.count + moo.count
FROM moo
WHERE moo.key = kc.key
;
INSERT INTO kc(key, count)
SELECT key, count
FROM moo
WHERE NOT EXISTS (
SELECT 1
FROM kc
WHERE kc.key = moo.key
)
;
COMMIT;
--
Jim C. Nasby, Sr. Engineering Consultant jnasby(at)pervasive(dot)com
Pervasive Software http://pervasive.com work: 512-231-6117
vcard: http://jim.nasby.net/pervasive.vcf cell: 512-569-9461

In response to

Browse pgsql-performance by date

  From Date Subject
Next Message Jim C. Nasby 2006-06-05 15:22:59 Re: [PERFORM] psql -A (unaligned format) eats too much memory
Previous Message Jim C. Nasby 2006-06-05 14:48:41 Re: [PERFORM] help me problems with pg_clog file