Re: Identify transactions causing highest wal generation

Поиск
Список
Период
Сортировка
От Bharath Rupireddy
Тема Re: Identify transactions causing highest wal generation
Дата
Msg-id CALj2ACWfxRdL2Gaa8SdYcEuoAae8PjYNaXicVokE3M5KFyjfmg@mail.gmail.com
обсуждение исходный текст
Ответ на Re: Identify transactions causing highest wal generation  (Tomas Vondra <tomas.vondra@enterprisedb.com>)
Список pgsql-hackers
On Fri, Mar 8, 2024 at 9:10 PM Tomas Vondra
<tomas.vondra@enterprisedb.com> wrote:
>
> On 3/8/24 15:50, Gayatri Singh wrote:
> > Hello Team,
> >
> > Can you help me with steps to identify transactions which caused wal
> > generation to surge ?
> >
>
> You should probably take a look at pg_waldump, which prints information
> about WAL contents, including which XID generated each record.

Right. pg_walinspect too can help get the same info for the available
WAL if you are on a production database with PG15 without any access
to the host instance.

> I don't know what exactly is your goal,

Yeah, it's good to know the use-case if possible.

> but sometimes it's not entirely
> direct relationship.For example, a transaction may delete a record,
> which generates just a little bit of WAL. But then after a checkpoint a
> VACUUM comes around, vacuums the page to reclaim the space of the entry,
> and ends up writing FPI (which is much larger). You could argue this WAL
> is also attributable to the original transaction, but that's not what
> pg_waldump will allow you to do. FPIs in general may inflate the numbers
> unpredictably, and it's not something the original transaction can
> affect very much.

Nice. If one knows the fact that there can be WAL generated without
associated transaction (no XID), there won't be surprises when the
amount of WAL generated by all transactions is compared against the
total WAL on the database.

Alternatively, one can get the correct amount of WAL generated
including the WAL without XID before and after doing some operations
as shown below:

postgres=# SELECT pg_current_wal_lsn();
 pg_current_wal_lsn
--------------------
 0/52EB488
(1 row)

postgres=# create table foo as select i from generate_series(1, 1000000) i;
SELECT 1000000
postgres=# update foo set i = i +1 where i%2 = 0;
UPDATE 500000
postgres=# SELECT pg_current_wal_lsn();
 pg_current_wal_lsn
--------------------
 0/D2B8000
(1 row)

postgres=# SELECT pg_wal_lsn_diff('0/D2B8000', '0/52EB488');
 pg_wal_lsn_diff
-----------------
       134007672
(1 row)

postgres=# SELECT pg_size_pretty(pg_wal_lsn_diff('0/D2B8000', '0/52EB488'));
 pg_size_pretty
----------------
 128 MB
(1 row)

--
Bharath Rupireddy
PostgreSQL Contributors Team
RDS Open Source Databases
Amazon Web Services: https://aws.amazon.com



В списке pgsql-hackers по дате отправления:

Предыдущее
От: "Euler Taveira"
Дата:
Сообщение: Re: Identify transactions causing highest wal generation
Следующее
От: Melanie Plageman
Дата:
Сообщение: Re: Confine vacuum skip logic to lazy_scan_skip