答复: [PERFORM] Postgresql update op is very very slow

From: "jay" <jackem(dot)mojx(at)alibaba-inc(dot)com>
To: "'Heikki Linnakangas'" <heikki(at)enterprisedb(dot)com>
Cc: <pgsql-performance(at)postgresql(dot)org>
Subject: 答复: [PERFORM] Postgresql update op is very very slow
Date: 2008-06-26 10:04:18
Message-ID: 005101c8d773$ff81b2c0$0644000a@hz.ali.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-performance

I know the problem, because there are about 35 million rows , which
cost about 12G disk space and checkpoint segments use 64, but update
operation is in one transaction which lead fast fill up the checkpoint
segments and lead do checkpoints frequently, but checkpoints will cost lots
resources, so update operation become slowly and slowly and bgwrite won't
write because it's not commit yet.
Create a new table maybe a quick solution, but it's not appropriated in some
cases.
If we can do commit very 1000 row per round, it may resolve the
problem.
But PG not support transaction within function yet?

-----邮件原件-----
发件人: pgsql-performance-owner(at)postgresql(dot)org
[mailto:pgsql-performance-owner(at)postgresql(dot)org] 代表 Heikki Linnakangas
发送时间: 2008年6月25日 18:11
收件人: jay
抄送: pgsql-performance(at)postgresql(dot)org
主题: Re: [PERFORM] Postgresql update op is very very slow

jay wrote:
> I've a table with about 34601755 rows ,when I execute 'update msg_table
set
> type=0;' is very very slow, cost several hours, but still not complete?
>
> Why postgresql is so slowly? Is the PG MVCC problem?

Possibly. Because of MVCC, a full-table update will actually create a
new version of each row.

I presume that's a one-off query, or a seldom-run batch operation, and
not something your application needs to do often. In that case, you
could drop all indexes, and recreate them after the update, which should
help a lot:

BEGIN;
DROP INDEX <index name>, <index name 2>, ...; -- for each index
UPDATE msg_table SET type = 0;
CREATE INDEX ... -- Recreate indexes
COMMIT;

Or even better, instead of using UPDATE, do a SELECT INTO a new table,
drop the old one, and rename the new one in its place. That has the
advantage that the new table doesn't contain the old row version, so you
don't need to vacuum right away to reclaim the space.

Actually, there's an even more clever trick to do roughly the same thing:

ALTER TABLE msg_table ALTER COLUMN type TYPE int4 USING 0;

(assuming type is int4, replace with the actual data type if necessary)

This will rewrite the table, similar to a DROP + CREATE, and rebuild all
indexes. But all in one command.

--
Heikki Linnakangas
EnterpriseDB http://www.enterprisedb.com

In response to

Responses

Browse pgsql-performance by date

  From Date Subject
Next Message Pavan Deolasee 2008-06-26 10:31:42 Re: [PERFORM] 答复: [PERFORM] Postgresql update op is very very slow
Previous Message Guillaume Smet 2008-06-26 07:12:56 Re: Typecast bug?