Thread: Auto-Vacuum in 8.1 was ineffective for me. 8.2 may work better?

Auto-Vacuum in 8.1 was ineffective for me. 8.2 may work better?

From
Mark Stosberg
Date:
When I upgraded a busy database system to PostgreSQL 8.1, I was excited
about AutoVacuum, and promptly enabled it, and turned off the daily
vacuum process.

(
I set the following, as well as the option to enable auto vacuuming
stats_start_collector = true
stats_row_level = true
)

I could see in the logs that related activity was happening, but within
a few days, the performance became horrible, and enabling the regular
vacuum fixed it.

Eventually autovacuum was completely disabled.

What could have happened? Is 8.2 more likely to "just work" in the
regard? Is the the table-specific tuning that I would have needed to do?

I realize getting autovacuuming to work could be one way to exclude the
large table I wrote about in a recent post.

   Mark

Re: Auto-Vacuum in 8.1 was ineffective for me. 8.2 may work better?

From
Alvaro Herrera
Date:
Mark Stosberg wrote:
>
> When I upgraded a busy database system to PostgreSQL 8.1, I was excited
> about AutoVacuum, and promptly enabled it, and turned off the daily
> vacuum process.
>
> (
> I set the following, as well as the option to enable auto vacuuming
> stats_start_collector = true
> stats_row_level = true
> )
>
> I could see in the logs that related activity was happening, but within
> a few days, the performance became horrible, and enabling the regular
> vacuum fixed it.
>
> Eventually autovacuum was completely disabled.

This has been tracked down to a bug in 8.1's Windows port.  See
http://people.planetpostgresql.org/mha/index.php?/archives/134-8.1-on-win32-pgstat-and-autovacuum.html

--
Alvaro Herrera                                http://www.CommandPrompt.com/
PostgreSQL Replication, Consulting, Custom Development, 24x7 support

Re: Auto-Vacuum in 8.1 was ineffective for me. 8.2 may work better?

From
Mark Stosberg
Date:
Alvaro Herrera wrote:
> Mark Stosberg wrote:
>> When I upgraded a busy database system to PostgreSQL 8.1, I was excited
>> about AutoVacuum, and promptly enabled it, and turned off the daily
>> vacuum process.
>>
>> (
>> I set the following, as well as the option to enable auto vacuuming
>> stats_start_collector = true
>> stats_row_level = true
>> )
>>
>> I could see in the logs that related activity was happening, but within
>> a few days, the performance became horrible, and enabling the regular
>> vacuum fixed it.
>>
>> Eventually autovacuum was completely disabled.
>
> This has been tracked down to a bug in 8.1's Windows port.  See
> http://people.planetpostgresql.org/mha/index.php?/archives/134-8.1-on-win32-pgstat-and-autovacuum.html

Thanks for the response Alvaro. This would have been on FreeBSD.

Let me ask the question a different way: Is simply setting the two
values plus enabling autovacuuming generally enough, or is further
tweaking common place?

Perhaps I'll give it another tree when we upgrade to 8.2.

  Mark

Re: Auto-Vacuum in 8.1 was ineffective for me. 8.2 may work better?

From
"Matthew T. O'Connor"
Date:
Mark Stosberg wrote:
> Let me ask the question a different way: Is simply setting the two
> values plus enabling autovacuuming generally enough, or is further
> tweaking common place?

No, most people in addition to setting those two GUC settings also lower
the threshold values (there is a fair amount of discussion on this in
the lists) the defaults are not aggressive enough, so you tables
probably aren't getting vacuumed often enough to keep up with the load.

Some work loads also require that you do cron based vacuuming of
specific highly active tables.

> Perhaps I'll give it another tree when we upgrade to 8.2.

Autovacuum is still somewhat new, and there were some significant
improvements in 8.2 so yes you should give it another try.

Re: Auto-Vacuum in 8.1 was ineffective for me. 8.2 may work better?

From
Alvaro Herrera
Date:
Mark Stosberg wrote:
> Alvaro Herrera wrote:
> > Mark Stosberg wrote:
> >> When I upgraded a busy database system to PostgreSQL 8.1, I was excited
> >> about AutoVacuum, and promptly enabled it, and turned off the daily
> >> vacuum process.
> >>
> >> (
> >> I set the following, as well as the option to enable auto vacuuming
> >> stats_start_collector = true
> >> stats_row_level = true
> >> )
> >>
> >> I could see in the logs that related activity was happening, but within
> >> a few days, the performance became horrible, and enabling the regular
> >> vacuum fixed it.
> >>
> >> Eventually autovacuum was completely disabled.

> > This has been tracked down to a bug in 8.1's Windows port.  See
> > http://people.planetpostgresql.org/mha/index.php?/archives/134-8.1-on-win32-pgstat-and-autovacuum.html
>
> Thanks for the response Alvaro. This would have been on FreeBSD.

Oh, maybe I misread your OP :-)  With "completely disabled" I thought
you meant it was "frozen", i.e., it ran, but did nothing.

> Let me ask the question a different way: Is simply setting the two
> values plus enabling autovacuuming generally enough, or is further
> tweaking common place?

I assume your FSM configuration is already good enough?

What you should do is find out what tables are not getting vacuumed
enough (e.g. by using contrib/pgstattuple repeteadly and seeing where is
dead space increasing) and tweak the autovacuum settings to have them
vacuumed more often.  This is done by inserting appropriate tuples in
pg_autovacuum.

--
Alvaro Herrera                                http://www.CommandPrompt.com/
The PostgreSQL Company - Command Prompt, Inc.

Using the 8.2 autovacuum values with 8.1

From
Mark Stosberg
Date:
Thanks to everyone for the feedback about vacuuming. It's been very
useful. The pointers to the pgstattuple and Pgfouine tools were also
helpful.

I'm now considering the following plan for trying Autovacuuming again
with 8.1. I'd like any peer review you have to offer of the following:

1. First, I'll move the settings to match the defaults in 8.2. The ones
I noticed in particular were:

autovacuum_vacuum_threshold changes: 1000 -> 500
autovacuum_anayze_threshold changes: 500 -> 250
autovacuum_scale_factor  changes:  .4 -> .2
autovacuum_analyze_scale_factor changes .2 -> .1

2. Try the vacuum cost delay feature, starting with a 20ms value:

autovacuum_vacuum_cost_delay = 20

3. Immediately add a row to pg_autovacuum for a huge logging table that
would be too slow to vacuum usually. We'll still vacuum it once a week
for good measure by cron.

4. For good measure, I think I still keep the nightly cron entry that
does a complete vacuum analyze (except for that large table...).

Seem like a reasonable plan?

   Mark

Re: Using the 8.2 autovacuum values with 8.1

From
Csaba Nagy
Date:
On Thu, 2007-02-22 at 22:53, Mark Stosberg wrote:
> Thanks to everyone for the feedback about vacuuming. It's been very
> useful. The pointers to the pgstattuple and Pgfouine tools were also
> helpful.
>
> I'm now considering the following plan for trying Autovacuuming again
> with 8.1. I'd like any peer review you have to offer of the following:
>
> 1. First, I'll move the settings to match the defaults in 8.2. The ones
> I noticed in particular were:
>
> autovacuum_vacuum_threshold changes: 1000 -> 500
> autovacuum_anayze_threshold changes: 500 -> 250
> autovacuum_scale_factor  changes:  .4 -> .2
> autovacuum_analyze_scale_factor changes .2 -> .1
>
> 2. Try the vacuum cost delay feature, starting with a 20ms value:
>
> autovacuum_vacuum_cost_delay = 20
>
> 3. Immediately add a row to pg_autovacuum for a huge logging table that
> would be too slow to vacuum usually. We'll still vacuum it once a week
> for good measure by cron.
>
> 4. For good measure, I think I still keep the nightly cron entry that
> does a complete vacuum analyze (except for that large table...).
>
> Seem like a reasonable plan?

You likely don't need the nightly full vacuum run... we also do here a
nightly vacuum beside autovacuum, but not a full one, only for tables
which are big enough that we don't want autovacuum to touch them in high
business time but they have enough change that we want a vacuum on them
frequent enough. I discover them by checking the stats, for example:

SELECT
    c.relname,
    c.reltuples::bigint as rowcnt,
    pg_stat_get_tuples_inserted(c.oid) AS inserted,
    pg_stat_get_tuples_updated(c.oid) AS updated,
    pg_stat_get_tuples_deleted(c.oid) AS deleted
FROM pg_class c
WHERE c.relkind = 'r'::"char"
GROUP BY c.oid, c.relname, c.reltuples
HAVING pg_stat_get_tuples_updated(c.oid) +
pg_stat_get_tuples_deleted(c.oid) > 1000
ORDER BY pg_stat_get_tuples_updated(c.oid) +
pg_stat_get_tuples_deleted(c.oid) DESC;


The top tables in this list for which the (deleted + updated) / rowcnt
is relatively small but still significant need your attention for
nightly vacuum... the rest is handled just fine by autovacuum.

On the other end of the scale, if you have tables for which the
deletion/update rate is way higher then the row count, that's likely a
hot-spot table which you probably need extra vacuuming during the day.

Cheers,
Csaba.



Re: Using the 8.2 autovacuum values with 8.1

From
"Jim C. Nasby"
Date:
On Fri, Feb 23, 2007 at 10:13:31AM +0100, Csaba Nagy wrote:
> You likely don't need the nightly full vacuum run... we also do here a
> nightly vacuum beside autovacuum, but not a full one, only for tables
> which are big enough that we don't want autovacuum to touch them in high
> business time but they have enough change that we want a vacuum on them
> frequent enough. I discover them by checking the stats, for example:

Something else I like doing is a periodic vacuumdb -av and capture the
output. It's a good way to keep an eye on FSM utilization. Once you've
got vacuuming under control you can probably just do that once a month
or so.
--
Jim Nasby                                            jim@nasby.net
EnterpriseDB      http://enterprisedb.com      512.569.9461 (cell)