Skip to content
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
59 changes: 51 additions & 8 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -647,17 +647,60 @@ This command displays an estimation of table "bloat" – space allocated to a re

RubyPgExtras.vacuum_stats

schema | table | last_vacuum | last_autovacuum | rowcount | dead_rowcount | autovacuum_threshold | expect_autovacuum
--------+-----------------------+-------------+------------------+----------------+----------------+----------------------+-------------------
public | log_table | | 2013-04-26 17:37 | 18,030 | 0 | 3,656 |
public | data_table | | 2013-04-26 13:09 | 79 | 28 | 66 |
public | other_table | | 2013-04-26 11:41 | 41 | 47 | 58 |
public | queue_table | | 2013-04-26 17:39 | 12 | 8,228 | 52 | yes
public | picnic_table | | | 13 | 0 | 53 |
schema | table | last_manual_vacuum | manual_vacuum_count | last_autovacuum | autovacuum_count | rowcount | dead_rowcount | dead_tup_autovacuum_threshold | n_ins_since_vacuum | insert_autovacuum_threshold | expect_autovacuum
--------+-----------------------+--------------------+---------------------+------------------+------------------+----------------+----------------+-------------------------------+--------------------+-----------------------------+-------------------
public | log_table | | 0 | 2013-04-26 17:37 | 5 | 18,030 | 0 | 3,656 | 0 | 3,606 |
public | data_table | | 0 | 2013-04-26 13:09 | 3 | 79 | 28 | 66 | 10 | 16 | yes (dead_tuples)
public | other_table | | 0 | 2013-04-26 11:41 | 4 | 41 | 47 | 58 | 2,000 | 1,008 | yes (dead_tuples & inserts)
(truncated results for brevity)
```

This command displays statistics related to vacuum operations for each table, including an estimation of dead rows, last autovacuum and the current autovacuum threshold. This command can be useful when determining if current vacuum thresholds require adjustments, and to determine when the table was last vacuumed.
This command displays statistics related to vacuum operations for each table, including last manual vacuum and autovacuum timestamps and counters, an estimation of dead rows, dead-tuple-based autovacuum threshold, number of rows inserted since the last VACUUM (`n_ins_since_vacuum`) and the insert-based autovacuum threshold introduced in PostgreSQL 13 ([PostgreSQL autovacuum configuration](https://www.postgresql.org/docs/current/runtime-config-vacuum.html#RUNTIME-CONFIG-AUTOVACUUM)). It helps determine if current autovacuum thresholds (both dead-tuple and insert-based) are appropriate, and whether an automatic vacuum is expected to be triggered soon.

### `vacuum_progress`

```ruby

RubyPgExtras.vacuum_progress

database | schema | table | pid | phase | heap_blks_total | heap_blks_scanned | heap_blks_vacuumed | index_vacuum_count
----------+--------+----------+-------+---------------------+-----------------+-------------------+--------------------+--------------------
app_db | public | users | 12345 | scanning heap | 125000 | 32000 | 0 | 0
app_db | public | orders | 12346 | vacuuming indexes | 80000 | 80000 | 75000 | 3
(truncated results for brevity)
```

This command shows the current progress of `VACUUM` / autovacuum operations by reading `pg_stat_progress_vacuum` ([VACUUM progress reporting docs](https://www.postgresql.org/docs/current/progress-reporting.html#VACUUM-PROGRESS-REPORTING)). It can be used to see which tables are being vacuumed right now, how far each operation has progressed, and how many index vacuum cycles have been performed.

### `analyze_progress`

```ruby

RubyPgExtras.analyze_progress

database | schema | table | pid | phase | sample_blks_total | sample_blks_scanned | ext_stats_total | ext_stats_computed
----------+--------+----------+-------+----------------------+-------------------+---------------------+-----------------+--------------------
app_db | public | users | 22345 | acquiring sample rows| 5000 | 1200 | 2 | 0
app_db | public | orders | 22346 | computing statistics | 8000 | 8000 | 1 | 1
(truncated results for brevity)
```

This command displays the current progress of `ANALYZE` and auto-analyze operations using `pg_stat_progress_analyze` ([ANALYZE progress reporting docs](https://www.postgresql.org/docs/current/progress-reporting.html#ANALYZE-PROGRESS-REPORTING)). It helps understand how far statistics collection has progressed for each active analyze and whether extended statistics are being computed.

### `vacuum_io_stats`

```ruby

RubyPgExtras.vacuum_io_stats

backend_type | object | context | reads | writes | writebacks | extends | evictions | reuses | fsyncs | stats_reset
--------------------+----------+----------+---------+---------+-----------+---------+-----------+---------+--------+-------------------------------
autovacuum worker | relation | vacuum | 5824251 | 3028684 | 0 | 0 | 2588 | 5821460 | 0 | 2025-01-10 11:50:27.583875+00
autovacuum launcher| relation | autovacuum| 16306 | 2494 | 0 | 2915 | 17785 | 0 | 0 | 2025-01-10 11:50:27.583875+00
(truncated results for brevity)
```

This command surfaces cumulative I/O statistics for autovacuum-related VACUUM activity, based on the `pg_stat_io` view introduced in PostgreSQL 16 ([pg_stat_io documentation](https://www.postgresql.org/docs/current/monitoring-stats.html#MONITORING-PG-STAT-IO-VIEW)). It shows how many blocks autovacuum workers have read and written, how many buffer evictions and ring-buffer reuses occurred, and when the statistics were last reset; this is useful for determining whether autovacuum is responsible for I/O spikes, as described in the pganalyze article on `pg_stat_io` ([Tracking cumulative I/O activity by autovacuum and manual VACUUMs](https://pganalyze.com/blog/pg-stat-io#tracking-cumulative-io-activity-by-autovacuum-and-manual-vacuums)). On PostgreSQL versions below 16 this method returns a single informational row indicating that the feature is unavailable.

### `kill_all`

Expand Down
28 changes: 27 additions & 1 deletion lib/ruby-pg-extras.rb
Original file line number Diff line number Diff line change
Expand Up @@ -26,7 +26,9 @@ module RubyPgExtras
long_running_queries mandelbrot outliers
records_rank seq_scans table_index_scans table_indexes_size
table_size total_index_size total_table_size
unused_indexes duplicate_indexes vacuum_stats kill_all kill_pid
unused_indexes duplicate_indexes vacuum_stats vacuum_progress vacuum_io_stats
analyze_progress
kill_all kill_pid
pg_stat_statements_reset buffercache_stats
buffercache_usage ssl_used connections
table_schema table_schemas
Expand All @@ -50,6 +52,11 @@ module RubyPgExtras
outliers: { limit: 10 },
outliers_legacy: { limit: 10 },
outliers_17: { limit: 10 },
vacuum_progress: {},
vacuum_progress_17: {},
vacuum_io_stats: {},
vacuum_io_stats_legacy: {},
analyze_progress: {},
buffercache_stats: { limit: 10 },
buffercache_usage: { limit: 20 },
unused_indexes: { max_scans: 50, schema: DEFAULT_SCHEMA },
Expand Down Expand Up @@ -92,6 +99,25 @@ def self.run_query_base(query_name:, conn:, exec_method:, in_format:, args: {})
end
end

# vacuum_progress uses pg_stat_progress_vacuum only and does not depend on pg_stat_statements,
# so we switch it based on the server_version_num instead of the pg_stat_statements version.
if query_name == :vacuum_progress
server_version_num = conn.send(exec_method, "SHOW server_version_num").to_a[0].values[0].to_i
if server_version_num >= 170000
query_name = :vacuum_progress_17
end
end

# vacuum_io_stats relies on pg_stat_io which is available starting from PostgreSQL 16.
# For older versions we fall back to vacuum_io_stats_legacy which just indicates
# that this feature is not available on the current server.
if query_name == :vacuum_io_stats
server_version_num = conn.send(exec_method, "SHOW server_version_num").to_a[0].values[0].to_i
if server_version_num < 160000
query_name = :vacuum_io_stats_legacy
end
end

REQUIRED_ARGS.fetch(query_name) { [] }.each do |arg_name|
if args[arg_name].nil?
raise ArgumentError, "'#{arg_name}' is required"
Expand Down
27 changes: 27 additions & 0 deletions lib/ruby_pg_extras/queries/analyze_progress.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,27 @@
/* Current ANALYZE progress as reported by pg_stat_progress_analyze */

SELECT
a.datname AS database,
n.nspname AS schema,
c.relname AS table,
p.pid,
p.phase,
p.sample_blks_total,
p.sample_blks_scanned,
p.ext_stats_total,
p.ext_stats_computed,
p.child_tables_total,
p.child_tables_done,
p.current_child_table_relid
FROM
pg_stat_progress_analyze p
LEFT JOIN pg_class c ON p.relid = c.oid
LEFT JOIN pg_namespace n ON c.relnamespace = n.oid
LEFT JOIN pg_stat_activity a ON p.pid = a.pid
ORDER BY
a.datname,
n.nspname,
c.relname,
p.pid;


31 changes: 31 additions & 0 deletions lib/ruby_pg_extras/queries/vacuum_io_stats.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,31 @@
/* I/O statistics for autovacuum backends from pg_stat_io (PostgreSQL 16+) */

SELECT
backend_type,
object,
context,
reads,
read_time,
writes,
write_time,
writebacks,
writeback_time,
extends,
extend_time,
fsyncs,
fsync_time,
reuses,
evictions,
stats_reset
FROM
pg_stat_io
WHERE
backend_type IN ('autovacuum worker', 'autovacuum launcher')
AND object = 'relation'
AND context IN ('vacuum', 'autovacuum')
ORDER BY
backend_type,
context,
object;


5 changes: 5 additions & 0 deletions lib/ruby_pg_extras/queries/vacuum_io_stats_legacy.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
/* I/O statistics for autovacuum backends are only available via pg_stat_io (PostgreSQL 16+). */

SELECT 'Upgrade to PostgreSQL 16 or newer to use this feature' AS "feature not available";


26 changes: 26 additions & 0 deletions lib/ruby_pg_extras/queries/vacuum_progress.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,26 @@
/* Current VACUUM progress as reported by pg_stat_progress_vacuum */

SELECT
a.datname AS database,
n.nspname AS schema,
c.relname AS table,
p.pid,
p.phase,
p.heap_blks_total,
p.heap_blks_scanned,
p.heap_blks_vacuumed,
p.index_vacuum_count,
p.max_dead_tuples,
p.num_dead_tuples
FROM
pg_stat_progress_vacuum p
LEFT JOIN pg_class c ON p.relid = c.oid
LEFT JOIN pg_namespace n ON c.relnamespace = n.oid
LEFT JOIN pg_stat_activity a ON p.pid = a.pid
ORDER BY
a.datname,
n.nspname,
c.relname,
p.pid;


29 changes: 29 additions & 0 deletions lib/ruby_pg_extras/queries/vacuum_progress_17.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,29 @@
/* Current VACUUM progress as reported by pg_stat_progress_vacuum */

SELECT
a.datname AS database,
n.nspname AS schema,
c.relname AS table,
p.pid,
p.phase,
p.heap_blks_total,
p.heap_blks_scanned,
p.heap_blks_vacuumed,
p.index_vacuum_count,
p.indexes_total,
p.indexes_processed,
p.num_dead_item_ids,
p.dead_tuple_bytes,
p.max_dead_tuple_bytes
FROM
pg_stat_progress_vacuum p
LEFT JOIN pg_class c ON p.relid = c.oid
LEFT JOIN pg_namespace n ON c.relnamespace = n.oid
LEFT JOIN pg_stat_activity a ON p.pid = a.pid
ORDER BY
a.datname,
n.nspname,
c.relname,
p.pid;


6 changes: 4 additions & 2 deletions lib/ruby_pg_extras/queries/vacuum_stats.sql
Original file line number Diff line number Diff line change
@@ -1,4 +1,4 @@
/* Dead rows and whether an automatic vacuum is expected to be triggered */
/* Dead rows, new inserts since last VACUUM and whether an automatic vacuum is expected to be triggered */

WITH table_opts AS (
SELECT
Expand Down Expand Up @@ -34,8 +34,10 @@ WITH table_opts AS (
SELECT
vacuum_settings.nspname AS schema,
vacuum_settings.relname AS table,
to_char(psut.last_vacuum, 'YYYY-MM-DD HH24:MI') AS last_vacuum,
to_char(psut.last_vacuum, 'YYYY-MM-DD HH24:MI') AS last_manual_vacuum,
to_char(psut.vacuum_count, '9G999G999G999') AS manual_vacuum_count,
to_char(psut.last_autovacuum, 'YYYY-MM-DD HH24:MI') AS last_autovacuum,
to_char(psut.autovacuum_count, '9G999G999G999') AS autovacuum_count,
to_char(pg_class.reltuples, '9G999G999G999') AS rowcount,
to_char(psut.n_dead_tup, '9G999G999G999') AS dead_rowcount,
to_char(
Expand Down