From: | David Rowley <david(dot)rowley(at)2ndquadrant(dot)com> |
---|---|
To: | anand086 <anand086(at)gmail(dot)com> |
Cc: | postgres performance list <pgsql-performance(at)postgresql(dot)org> |
Subject: | Re: SQL Perfomance during autovacuum |
Date: | 2018-12-19 06:33:41 |
Message-ID: | CAKJS1f-2mB7NhgH7sjbUCz4O2M6sAd1z=KC86Y74iGEkTs5bWw@mail.gmail.com |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-performance |
On Wed, 19 Dec 2018 at 19:04, anand086 <anand086(at)gmail(dot)com> wrote:
> We have noticed this increase in execution times for the sqls only when
> autovacuum runs and it runs with prevent wraparound mode. I think during the
> autovacuum process the Buffers: shared hit are increasing causing increase
> in execution time.
>
> I need help with the approach to debug this issue. Is this expected
> behaviour wherein sql execution timing incease during the autovacuum? If so
> , what is the reason for the same?
This is unsurprising. There are various GUC settings designed to
throttle vacuum to help minimise this problem. The auto-vacuum process
is competing for the same resources as your query is, and is likely
loading many new buffers, therefore flushing buffers out of cache that
might be useful for your query.
Showing the output of:
select name,setting from pg_Settings where name like '%vacuum%';
may be of use here.
You'll particularly want to pay attention to the settings of
autovacuum_vacuum_cost_delay, autovacuum_vacuum_cost_limit and
vacuum_cost_limit. The settings of vacuum_cost_page_dirty,
vacuum_cost_page_hit, vacuum_cost_page_miss matter too, but these are
less often changed by users.
You may be able to learn exactly what's going on with the query by doing:
set track_io_timing = on;
explain (analyze, buffers, timing) <your query here>
both during the auto-vacuum run, and at a time when it's not running.
If the query plans of each match, then pay attention to the number of
buffers read and how long they took to read. If you find that these
don't explain the variation then something else is at fault, perhaps
CPU contention, or perhaps swapping due to high memory usage.
It also seems pretty strange that you should need to use DISTINCT on a
column that's named "id".
--
David Rowley http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Training & Services
From | Date | Subject | |
---|---|---|---|
Next Message | Justin Pryzby | 2018-12-19 06:51:49 | Re: Increasing parallelism of queries while using file fdw and partitions |
Previous Message | anand086 | 2018-12-19 06:04:40 | SQL Perfomance during autovacuum |