Re: Which update action quicker?

From: Heikki Linnakangas <hlinnakangas(at)vmware(dot)com>
To: <emilu(at)encs(dot)concordia(dot)ca>, "pgsql-performance(at)postgresql(dot)org" <pgsql-performance(at)postgresql(dot)org>
Subject: Re: Which update action quicker?
Date: 2014-09-24 13:48:36
Message-ID: 5422CBB4.3000301@vmware.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-performance

On 09/23/2014 11:37 PM, Emi Lu wrote:
> Hello list,
>
> For a big table with more than 1,000,000 records, may I know which update is
> quicker please?
>
> (1) update t1
> set c1 = a.c1
> from a
> where pk and
> t1.c1 <> a.c1;
> ......
> update t1
> set c_N = a.c_N
> from a
> where pk and
> t1.c_N <> a.c_N;
>
>
> (2) update t1
> set c1 = a.c1 ,
> c2 = a.c2,
> ...
> c_N = a.c_N
> from a
> where pk AND
> ( t1.c1 <> a.c1 OR t1.c2 <> a.c2..... t1.c_N <> a.c_N)

Probably (2). <> is not indexable, so each update will have to perform a
sequential scan of the table. With (2), you only need to scan it once,
with (1) you have to scan it N times. Also, method (1) will update the
same row multiple times, if it needs to have more than one column updated.

> Or other quicker way for update action?

If a large percentage of the table needs to be updated, it can be faster
to create a new table, insert all the rows with the right values, drop
the old table and rename the new one in its place. All in one transaction.

- Heikki

In response to

Responses

Browse pgsql-performance by date

  From Date Subject
Next Message Emi Lu 2014-09-24 14:13:05 Re: Which update action quicker?
Previous Message Mkrtchyan, Tigran 2014-09-24 13:03:23 Re: postgres 9.3 vs. 9.4