Introduction

PostgreSQL 18 will normally (as there is always a risk of seeing something reverted until its GA release) include this commit: Add backend-level statistics to pgstats.

commit 9aea73fc61d4e77e000724ce0b2f896590a10e03
Author: Michael Paquier <michael@paquier.xyz>
Date:   Thu Dec 19 13:19:22 2024 +0900

Add backend-level statistics to pgstats

This adds a new variable-numbered statistics kind in pgstats, where the
object ID key of the stats entries is based on the proc number of the
backends.  This acts as an upper-bound for the number of stats entries
that can exist at once.  The entries are created when a backend starts
after authentication succeeds, and are removed when the backend exits,
making the stats entry exist for as long as their backend is up and
running.  These are not written to the pgstats file at shutdown (note
that write_to_file is disabled, as a safety measure).

Currently, these stats include only information about the I/O generated
by a backend, using the same layer as pg_stat_io, except that it is now
possible to know how much activity is happening in each backend rather
than an overall aggregate of all the activity.  A function called
pg_stat_get_backend_io() is added to access this data depending on the
PID of a backend.  The existing structure could be expanded in the
future to add more information about other statistics related to
backends, depending on requirements or ideas.

Auxiliary processes are not included in this set of statistics.  These
are less interesting to have than normal backends as they have dedicated
entries in pg_stat_io, and stats kinds of their own.

This commit includes also pg_stat_reset_backend_stats(), function able
to reset all the stats associated to a single backend.

It means that, thanks to the new pg_stat_get_backend_io() function, we can see the I/O activity in each backend (in addition to the overall aggregate still available through the pg_stat_io view).

Let’s look at some examples

Thanks to this new pg_stat_get_backend_io() function, we can:

Retrieve the I/O statistics for my backend

db1=# SELECT * FROM pg_stat_get_backend_io(pg_backend_pid());
  backend_type  |    object     |  context  | reads | read_time | writes | write_time | writebacks | writeback_time | extends | extend_time | op_bytes |  hits   | evictions | reuses | fsyncs | fsync_time | stats_reset
----------------+---------------+-----------+-------+-----------+--------+------------+------------+----------------+---------+-------------+----------+---------+-----------+--------+--------+------------+-------------
 client backend | relation      | bulkread  |     0 |         0 |      0 |          0 |          0 |              0 |         |             |     8192 |       0 |         0 |      0 |        |            |
 client backend | relation      | bulkwrite |     0 |         0 |      0 |          0 |          0 |              0 |       0 |           0 |     8192 |       0 |         0 |      0 |        |            |
 client backend | relation      | normal    |     8 |         0 |    832 |          0 |          0 |              0 |    7967 |           0 |     8192 | 1816551 |      2433 |        |      0 |          0 |
 client backend | relation      | vacuum    |     0 |         0 |      0 |          0 |          0 |              0 |       0 |           0 |     8192 |       0 |         0 |      0 |        |            |
 client backend | temp relation | normal    |     0 |         0 |      0 |          0 |            |                |       0 |           0 |     8192 |       0 |         0 |        |        |            |
(5 rows)

Using pg_backend_pid() as input of pg_stat_get_backend_io(), I can see the I/O statistics for my backend.

Find out which backend is generating the most hits

db1=# SELECT datname, application_name, pid, sum(hits)
db1-# FROM pg_stat_activity, pg_stat_get_backend_io(pid)
db1-# WHERE hits != 0
db1-# GROUP BY datname, application_name, pid
db1-# ORDER BY 4 desc
db1-# LIMIT 1;

 datname | application_name |  pid   |   sum
---------+------------------+--------+---------
 db1     | app2             | 502479 | 1816958
(1 row)

Using pg_stat_get_backend_io() in conjonction with pg_stat_activity, I can figure out which backend is generating the most hits.

Get the writes generated by application (and the ratio cluster wide)

db1=# SELECT application_name, writes, round(100 * writes/sum(writes) over(),2) AS "%"
FROM  (SELECT application_name, sum(writes) AS writes
       FROM pg_stat_activity, pg_stat_get_backend_io(pid)
       WHERE writes != 0 GROUP BY application_name);
 application_name | writes |   %
------------------+--------+-------
 app1             |   2374 | 34.11
 app2             |   4586 | 65.89
(2 rows)

Using pg_stat_get_backend_io() in conjonction with pg_stat_activity and windows function, I can get the writes generated by application (and the ratio cluster wide).

There is much more we can do with the new function, the examples above are far from exhaustive.

Remarks

The output of the new pg_stat_get_backend_io() function has the same meaning as the one from the pg_stat_io view (please refer to the documentation and/or to Melanie’s presentation for example).

The per backend I/O stats do not persist after a server restart (it would not make sense to report statistics for backends that are gone). The pg_stat_io data persists though.

Once a backend disconnect its I/O related stats are not available anymore.

A new pg_stat_reset_backend_stats() function has also been added to reset all the stats associated to a single backend.

Conclusion

It’s now possible to see the I/O activity in each backend and build insightful queries on top of this new pg_stat_get_backend_io() function.