Re: Insertion to temp table deteriorating over time

From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: "Steven Flatt" <steven(dot)flatt(at)gmail(dot)com>
Cc: pgsql-performance(at)postgresql(dot)org
Subject: Re: Insertion to temp table deteriorating over time
Date: 2006-12-13 23:44:47
Message-ID: 13154.1166053487@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-performance

"Steven Flatt" <steven(dot)flatt(at)gmail(dot)com> writes:
> Having said that, what kinds of things should I be looking for that could
> deteriorate/bloat over time? Ordinarily the culprit might be infrequent
> vacuuming or analyzing, but that wouldn't be corrected by a restart of
> Postgres. In our case, restarting Postgres gives us a huge performance
> improvement (for a short while, anyways).

> By the way, we are using PG 7.4.6 on FreeBSD 5.30.0170. The temp table has
> 15 columns: a timestamp, a double, and the rest integers. It has no
> indexes.

Hm, *are* you vacuuming only infrequently? In particular, what is your
maintenance policy for pg_class?

Some experimentation with TRUNCATE and VACUUM VERBOSE shows that in 7.4,
a TRUNCATE of a temp table with no indexes and no toast table generates
three dead row versions in pg_class. (I'm surprised that it's as many
as three, but in any case the TRUNCATE would certainly have to do one
update of the table's pg_class entry and thereby generate one dead row
version.)

If you're being sloppy about vacuuming pg_class, then over time the
repeated-truncate pattern would build up a huge number of dead rows
in pg_class, *all with the same OID*. It's unsurprising that this
would create some slowness in looking up the temp table's pg_class
entry.

If this theory is correct, the reason that starting a fresh backend
makes it fast again is that the new backend creates a whole new temp
table with a new OID assigned, and so the adjacent litter in pg_class
doesn't matter anymore (or not so much anyway).

Solution would be to institute regular vacuuming of the system
catalogs...

regards, tom lane

In response to

Browse pgsql-performance by date

  From Date Subject
Next Message Bruce Momjian 2006-12-14 01:04:13 Re: New to PostgreSQL, performance considerations
Previous Message Tom Lane 2006-12-13 23:27:27 Re: Insertion to temp table deteriorating over time