From c037471832e1ec3327f81eebbd8892e5c1042fe0 Mon Sep 17 00:00:00 2001 From: Andres Freund Date: Fri, 14 Oct 2022 11:11:34 -0700 Subject: [PATCH] pgstat: Track time of the last scan of a relation It can be useful to know when a relation has last been used, e.g., when evaluating whether an index is still required. It was already possible to infer the time of the last usage by tracking, e.g., pg_stat_all_indexes.idx_scan over time. But far from everybody does so. To make it easier to detect the last time a relation has been scanned, track that time in each relation's pgstat entry. To minimize overhead a) the timestamp is updated only when the backend pending stats entry is flushed to shared stats b) the last transaction's stop timestamp is used as the timestamp. Bumps catalog and stats format versions. Author: Dave Page Reviewed-by: Andres Freund Reviewed-by: Bruce Momjian Reviewed-by: Vik Fearing Discussion: https://postgr.es/m/CA+OCxozrVHNFVEPkweUHMZje+t1tfY816d9MZYc6eZwOOusOaQ@mail.gmail.com --- doc/src/sgml/monitoring.sgml | 30 +++ src/backend/catalog/system_views.sql | 3 + src/backend/utils/activity/pgstat_relation.c | 6 + src/backend/utils/adt/pgstatfuncs.c | 13 ++ src/include/catalog/catversion.h | 2 +- src/include/catalog/pg_proc.dat | 4 + src/include/pgstat.h | 3 +- src/test/regress/expected/rules.out | 9 + src/test/regress/expected/stats.out | 202 +++++++++++++++++++ src/test/regress/sql/stats.sql | 86 ++++++++ 10 files changed, 356 insertions(+), 2 deletions(-) diff --git a/doc/src/sgml/monitoring.sgml b/doc/src/sgml/monitoring.sgml index 342b20ebeb..60a2026b0b 100644 --- a/doc/src/sgml/monitoring.sgml +++ b/doc/src/sgml/monitoring.sgml @@ -4385,6 +4385,16 @@ SELECT pid, wait_event_type, wait_event FROM pg_stat_activity WHERE wait_event i + + + last_seq_scan timestamptz + + + The time of the last sequential scan on this table, based on the + most recent transaction stop time + + + seq_tup_read bigint @@ -4403,6 +4413,16 @@ SELECT pid, wait_event_type, wait_event FROM pg_stat_activity WHERE wait_event i + + + last_idx_scan timestamptz + + + The time of the last index scan on this table, based on the + most recent transaction stop time + + + idx_tup_fetch bigint @@ -4654,6 +4674,16 @@ SELECT pid, wait_event_type, wait_event FROM pg_stat_activity WHERE wait_event i + + + last_idx_scan timestamptz + + + The time of the last scan on this index, based on the + most recent transaction stop time + + + idx_tup_read bigint diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql index 55f7ec79e0..2d8104b090 100644 --- a/src/backend/catalog/system_views.sql +++ b/src/backend/catalog/system_views.sql @@ -656,8 +656,10 @@ CREATE VIEW pg_stat_all_tables AS N.nspname AS schemaname, C.relname AS relname, pg_stat_get_numscans(C.oid) AS seq_scan, + pg_stat_get_lastscan(C.oid) AS last_seq_scan, pg_stat_get_tuples_returned(C.oid) AS seq_tup_read, sum(pg_stat_get_numscans(I.indexrelid))::bigint AS idx_scan, + max(pg_stat_get_lastscan(I.indexrelid)) AS last_idx_scan, sum(pg_stat_get_tuples_fetched(I.indexrelid))::bigint + pg_stat_get_tuples_fetched(C.oid) AS idx_tup_fetch, pg_stat_get_tuples_inserted(C.oid) AS n_tup_ins, @@ -774,6 +776,7 @@ CREATE VIEW pg_stat_all_indexes AS C.relname AS relname, I.relname AS indexrelname, pg_stat_get_numscans(I.oid) AS idx_scan, + pg_stat_get_lastscan(I.oid) AS last_idx_scan, pg_stat_get_tuples_returned(I.oid) AS idx_tup_read, pg_stat_get_tuples_fetched(I.oid) AS idx_tup_fetch FROM pg_class C JOIN diff --git a/src/backend/utils/activity/pgstat_relation.c b/src/backend/utils/activity/pgstat_relation.c index a846d9ffb6..55a355f583 100644 --- a/src/backend/utils/activity/pgstat_relation.c +++ b/src/backend/utils/activity/pgstat_relation.c @@ -789,6 +789,12 @@ pgstat_relation_flush_cb(PgStat_EntryRef *entry_ref, bool nowait) tabentry = &shtabstats->stats; tabentry->numscans += lstats->t_counts.t_numscans; + if (lstats->t_counts.t_numscans) + { + TimestampTz t = GetCurrentTransactionStopTimestamp(); + if (t > tabentry->lastscan) + tabentry->lastscan = t; + } tabentry->tuples_returned += lstats->t_counts.t_tuples_returned; tabentry->tuples_fetched += lstats->t_counts.t_tuples_fetched; tabentry->tuples_inserted += lstats->t_counts.t_tuples_inserted; diff --git a/src/backend/utils/adt/pgstatfuncs.c b/src/backend/utils/adt/pgstatfuncs.c index eadd8464ff..85ac3e3f04 100644 --- a/src/backend/utils/adt/pgstatfuncs.c +++ b/src/backend/utils/adt/pgstatfuncs.c @@ -52,6 +52,19 @@ pg_stat_get_numscans(PG_FUNCTION_ARGS) } +Datum +pg_stat_get_lastscan(PG_FUNCTION_ARGS) +{ + Oid relid = PG_GETARG_OID(0); + PgStat_StatTabEntry *tabentry; + + if ((tabentry = pgstat_fetch_stat_tabentry(relid)) == NULL) + PG_RETURN_NULL(); + else + PG_RETURN_TIMESTAMPTZ(tabentry->lastscan); +} + + Datum pg_stat_get_tuples_returned(PG_FUNCTION_ARGS) { diff --git a/src/include/catalog/catversion.h b/src/include/catalog/catversion.h index c1af6eaf5f..4c930c189b 100644 --- a/src/include/catalog/catversion.h +++ b/src/include/catalog/catversion.h @@ -57,6 +57,6 @@ */ /* yyyymmddN */ -#define CATALOG_VERSION_NO 202209291 +#define CATALOG_VERSION_NO 202210141 #endif diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat index 68bb032d3e..62a5b8e655 100644 --- a/src/include/catalog/pg_proc.dat +++ b/src/include/catalog/pg_proc.dat @@ -5252,6 +5252,10 @@ proname => 'pg_stat_get_numscans', provolatile => 's', proparallel => 'r', prorettype => 'int8', proargtypes => 'oid', prosrc => 'pg_stat_get_numscans' }, +{ oid => '9976', descr => 'statistics: time of the last scan for table/index', + proname => 'pg_stat_get_lastscan', provolatile => 's', proparallel => 'r', + prorettype => 'timestamptz', proargtypes => 'oid', + prosrc => 'pg_stat_get_lastscan' }, { oid => '1929', descr => 'statistics: number of tuples read by seqscan', proname => 'pg_stat_get_tuples_returned', provolatile => 's', proparallel => 'r', prorettype => 'int8', proargtypes => 'oid', diff --git a/src/include/pgstat.h b/src/include/pgstat.h index cc1d1dcb7d..9e2ce6f011 100644 --- a/src/include/pgstat.h +++ b/src/include/pgstat.h @@ -242,7 +242,7 @@ typedef struct PgStat_TableXactStatus * ------------------------------------------------------------ */ -#define PGSTAT_FILE_FORMAT_ID 0x01A5BCA8 +#define PGSTAT_FILE_FORMAT_ID 0x01A5BCA9 typedef struct PgStat_ArchiverStats { @@ -354,6 +354,7 @@ typedef struct PgStat_StatSubEntry typedef struct PgStat_StatTabEntry { PgStat_Counter numscans; + TimestampTz lastscan; PgStat_Counter tuples_returned; PgStat_Counter tuples_fetched; diff --git a/src/test/regress/expected/rules.out b/src/test/regress/expected/rules.out index 9dd137415e..bfcd8ac9a0 100644 --- a/src/test/regress/expected/rules.out +++ b/src/test/regress/expected/rules.out @@ -1763,6 +1763,7 @@ pg_stat_all_indexes| SELECT c.oid AS relid, c.relname, i.relname AS indexrelname, pg_stat_get_numscans(i.oid) AS idx_scan, + pg_stat_get_lastscan(i.oid) AS last_idx_scan, pg_stat_get_tuples_returned(i.oid) AS idx_tup_read, pg_stat_get_tuples_fetched(i.oid) AS idx_tup_fetch FROM (((pg_class c @@ -1774,8 +1775,10 @@ pg_stat_all_tables| SELECT c.oid AS relid, n.nspname AS schemaname, c.relname, pg_stat_get_numscans(c.oid) AS seq_scan, + pg_stat_get_lastscan(c.oid) AS last_seq_scan, pg_stat_get_tuples_returned(c.oid) AS seq_tup_read, (sum(pg_stat_get_numscans(i.indexrelid)))::bigint AS idx_scan, + max(pg_stat_get_lastscan(i.indexrelid)) AS last_idx_scan, ((sum(pg_stat_get_tuples_fetched(i.indexrelid)))::bigint + pg_stat_get_tuples_fetched(c.oid)) AS idx_tup_fetch, pg_stat_get_tuples_inserted(c.oid) AS n_tup_ins, pg_stat_get_tuples_updated(c.oid) AS n_tup_upd, @@ -2107,6 +2110,7 @@ pg_stat_sys_indexes| SELECT pg_stat_all_indexes.relid, pg_stat_all_indexes.relname, pg_stat_all_indexes.indexrelname, pg_stat_all_indexes.idx_scan, + pg_stat_all_indexes.last_idx_scan, pg_stat_all_indexes.idx_tup_read, pg_stat_all_indexes.idx_tup_fetch FROM pg_stat_all_indexes @@ -2115,8 +2119,10 @@ pg_stat_sys_tables| SELECT pg_stat_all_tables.relid, pg_stat_all_tables.schemaname, pg_stat_all_tables.relname, pg_stat_all_tables.seq_scan, + pg_stat_all_tables.last_seq_scan, pg_stat_all_tables.seq_tup_read, pg_stat_all_tables.idx_scan, + pg_stat_all_tables.last_idx_scan, pg_stat_all_tables.idx_tup_fetch, pg_stat_all_tables.n_tup_ins, pg_stat_all_tables.n_tup_upd, @@ -2151,6 +2157,7 @@ pg_stat_user_indexes| SELECT pg_stat_all_indexes.relid, pg_stat_all_indexes.relname, pg_stat_all_indexes.indexrelname, pg_stat_all_indexes.idx_scan, + pg_stat_all_indexes.last_idx_scan, pg_stat_all_indexes.idx_tup_read, pg_stat_all_indexes.idx_tup_fetch FROM pg_stat_all_indexes @@ -2159,8 +2166,10 @@ pg_stat_user_tables| SELECT pg_stat_all_tables.relid, pg_stat_all_tables.schemaname, pg_stat_all_tables.relname, pg_stat_all_tables.seq_scan, + pg_stat_all_tables.last_seq_scan, pg_stat_all_tables.seq_tup_read, pg_stat_all_tables.idx_scan, + pg_stat_all_tables.last_idx_scan, pg_stat_all_tables.idx_tup_fetch, pg_stat_all_tables.n_tup_ins, pg_stat_all_tables.n_tup_upd, diff --git a/src/test/regress/expected/stats.out b/src/test/regress/expected/stats.out index f701da2069..257a6a9da9 100644 --- a/src/test/regress/expected/stats.out +++ b/src/test/regress/expected/stats.out @@ -556,6 +556,208 @@ SELECT pg_stat_get_live_tuples(:drop_stats_test_subxact_oid); DROP TABLE trunc_stats_test, trunc_stats_test1, trunc_stats_test2, trunc_stats_test3, trunc_stats_test4; DROP TABLE prevstats; +----- +-- Test that last_seq_scan, last_idx_scan are correctly maintained +-- +-- Perform test using a temporary table. That way autovacuum etc won't +-- interfere. To be able to check that timestamps increase, we sleep for 100ms +-- between tests, assuming that there aren't systems with a coarser timestamp +-- granularity. +----- +BEGIN; +CREATE TEMPORARY TABLE test_last_scan(idx_col int primary key, noidx_col int); +INSERT INTO test_last_scan(idx_col, noidx_col) VALUES(1, 1); +SELECT pg_stat_force_next_flush(); + pg_stat_force_next_flush +-------------------------- + +(1 row) + +COMMIT; +SELECT pg_stat_reset_single_table_counters('test_last_scan'::regclass); + pg_stat_reset_single_table_counters +------------------------------------- + +(1 row) + +SELECT seq_scan, idx_scan FROM pg_stat_all_tables WHERE relid = 'test_last_scan'::regclass; + seq_scan | idx_scan +----------+---------- + 0 | 0 +(1 row) + +-- ensure we start out with exactly one index and sequential scan +BEGIN; +SET LOCAL enable_seqscan TO on; +SET LOCAL enable_indexscan TO on; +SET LOCAL enable_bitmapscan TO off; +EXPLAIN (COSTS off) SELECT count(*) FROM test_last_scan WHERE noidx_col = 1; + QUERY PLAN +---------------------------------- + Aggregate + -> Seq Scan on test_last_scan + Filter: (noidx_col = 1) +(3 rows) + +SELECT count(*) FROM test_last_scan WHERE noidx_col = 1; + count +------- + 1 +(1 row) + +SET LOCAL enable_seqscan TO off; +EXPLAIN (COSTS off) SELECT count(*) FROM test_last_scan WHERE idx_col = 1; + QUERY PLAN +-------------------------------------------------------------- + Aggregate + -> Index Scan using test_last_scan_pkey on test_last_scan + Index Cond: (idx_col = 1) +(3 rows) + +SELECT count(*) FROM test_last_scan WHERE idx_col = 1; + count +------- + 1 +(1 row) + +SELECT pg_stat_force_next_flush(); + pg_stat_force_next_flush +-------------------------- + +(1 row) + +COMMIT; +-- fetch timestamps from before the next test +SELECT last_seq_scan AS test_last_seq, last_idx_scan AS test_last_idx +FROM pg_stat_all_tables WHERE relid = 'test_last_scan'::regclass \gset +SELECT pg_sleep(0.1); -- assume a minimum timestamp granularity of 100ms + pg_sleep +---------- + +(1 row) + +-- cause one sequential scan +BEGIN; +SET LOCAL enable_seqscan TO on; +SET LOCAL enable_indexscan TO off; +SET LOCAL enable_bitmapscan TO off; +EXPLAIN (COSTS off) SELECT count(*) FROM test_last_scan WHERE noidx_col = 1; + QUERY PLAN +---------------------------------- + Aggregate + -> Seq Scan on test_last_scan + Filter: (noidx_col = 1) +(3 rows) + +SELECT count(*) FROM test_last_scan WHERE noidx_col = 1; + count +------- + 1 +(1 row) + +SELECT pg_stat_force_next_flush(); + pg_stat_force_next_flush +-------------------------- + +(1 row) + +COMMIT; +-- check that just sequential scan stats were incremented +SELECT seq_scan, :'test_last_seq' < last_seq_scan AS seq_ok, idx_scan, :'test_last_idx' = last_idx_scan AS idx_ok +FROM pg_stat_all_tables WHERE relid = 'test_last_scan'::regclass; + seq_scan | seq_ok | idx_scan | idx_ok +----------+--------+----------+-------- + 2 | t | 1 | t +(1 row) + +-- fetch timestamps from before the next test +SELECT last_seq_scan AS test_last_seq, last_idx_scan AS test_last_idx +FROM pg_stat_all_tables WHERE relid = 'test_last_scan'::regclass \gset +SELECT pg_sleep(0.1); + pg_sleep +---------- + +(1 row) + +-- cause one index scan +BEGIN; +SET LOCAL enable_seqscan TO off; +SET LOCAL enable_indexscan TO on; +SET LOCAL enable_bitmapscan TO off; +EXPLAIN (COSTS off) SELECT count(*) FROM test_last_scan WHERE idx_col = 1; + QUERY PLAN +-------------------------------------------------------------- + Aggregate + -> Index Scan using test_last_scan_pkey on test_last_scan + Index Cond: (idx_col = 1) +(3 rows) + +SELECT count(*) FROM test_last_scan WHERE idx_col = 1; + count +------- + 1 +(1 row) + +SELECT pg_stat_force_next_flush(); + pg_stat_force_next_flush +-------------------------- + +(1 row) + +COMMIT; +-- check that just index scan stats were incremented +SELECT seq_scan, :'test_last_seq' = last_seq_scan AS seq_ok, idx_scan, :'test_last_idx' < last_idx_scan AS idx_ok +FROM pg_stat_all_tables WHERE relid = 'test_last_scan'::regclass; + seq_scan | seq_ok | idx_scan | idx_ok +----------+--------+----------+-------- + 2 | t | 2 | t +(1 row) + +-- fetch timestamps from before the next test +SELECT last_seq_scan AS test_last_seq, last_idx_scan AS test_last_idx +FROM pg_stat_all_tables WHERE relid = 'test_last_scan'::regclass \gset +SELECT pg_sleep(0.1); + pg_sleep +---------- + +(1 row) + +-- cause one bitmap index scan +BEGIN; +SET LOCAL enable_seqscan TO off; +SET LOCAL enable_indexscan TO off; +SET LOCAL enable_bitmapscan TO on; +EXPLAIN (COSTS off) SELECT count(*) FROM test_last_scan WHERE idx_col = 1; + QUERY PLAN +------------------------------------------------------ + Aggregate + -> Bitmap Heap Scan on test_last_scan + Recheck Cond: (idx_col = 1) + -> Bitmap Index Scan on test_last_scan_pkey + Index Cond: (idx_col = 1) +(5 rows) + +SELECT count(*) FROM test_last_scan WHERE idx_col = 1; + count +------- + 1 +(1 row) + +SELECT pg_stat_force_next_flush(); + pg_stat_force_next_flush +-------------------------- + +(1 row) + +COMMIT; +-- check that just index scan stats were incremented +SELECT seq_scan, :'test_last_seq' = last_seq_scan AS seq_ok, idx_scan, :'test_last_idx' < last_idx_scan AS idx_ok +FROM pg_stat_all_tables WHERE relid = 'test_last_scan'::regclass; + seq_scan | seq_ok | idx_scan | idx_ok +----------+--------+----------+-------- + 2 | t | 3 | t +(1 row) + ----- -- Test that various stats views are being properly populated ----- diff --git a/src/test/regress/sql/stats.sql b/src/test/regress/sql/stats.sql index eb081f65a4..f6270f7bad 100644 --- a/src/test/regress/sql/stats.sql +++ b/src/test/regress/sql/stats.sql @@ -290,6 +290,92 @@ DROP TABLE trunc_stats_test, trunc_stats_test1, trunc_stats_test2, trunc_stats_t DROP TABLE prevstats; +----- +-- Test that last_seq_scan, last_idx_scan are correctly maintained +-- +-- Perform test using a temporary table. That way autovacuum etc won't +-- interfere. To be able to check that timestamps increase, we sleep for 100ms +-- between tests, assuming that there aren't systems with a coarser timestamp +-- granularity. +----- + +BEGIN; +CREATE TEMPORARY TABLE test_last_scan(idx_col int primary key, noidx_col int); +INSERT INTO test_last_scan(idx_col, noidx_col) VALUES(1, 1); +SELECT pg_stat_force_next_flush(); +COMMIT; + +SELECT pg_stat_reset_single_table_counters('test_last_scan'::regclass); +SELECT seq_scan, idx_scan FROM pg_stat_all_tables WHERE relid = 'test_last_scan'::regclass; + +-- ensure we start out with exactly one index and sequential scan +BEGIN; +SET LOCAL enable_seqscan TO on; +SET LOCAL enable_indexscan TO on; +SET LOCAL enable_bitmapscan TO off; +EXPLAIN (COSTS off) SELECT count(*) FROM test_last_scan WHERE noidx_col = 1; +SELECT count(*) FROM test_last_scan WHERE noidx_col = 1; +SET LOCAL enable_seqscan TO off; +EXPLAIN (COSTS off) SELECT count(*) FROM test_last_scan WHERE idx_col = 1; +SELECT count(*) FROM test_last_scan WHERE idx_col = 1; +SELECT pg_stat_force_next_flush(); +COMMIT; + +-- fetch timestamps from before the next test +SELECT last_seq_scan AS test_last_seq, last_idx_scan AS test_last_idx +FROM pg_stat_all_tables WHERE relid = 'test_last_scan'::regclass \gset +SELECT pg_sleep(0.1); -- assume a minimum timestamp granularity of 100ms + +-- cause one sequential scan +BEGIN; +SET LOCAL enable_seqscan TO on; +SET LOCAL enable_indexscan TO off; +SET LOCAL enable_bitmapscan TO off; +EXPLAIN (COSTS off) SELECT count(*) FROM test_last_scan WHERE noidx_col = 1; +SELECT count(*) FROM test_last_scan WHERE noidx_col = 1; +SELECT pg_stat_force_next_flush(); +COMMIT; +-- check that just sequential scan stats were incremented +SELECT seq_scan, :'test_last_seq' < last_seq_scan AS seq_ok, idx_scan, :'test_last_idx' = last_idx_scan AS idx_ok +FROM pg_stat_all_tables WHERE relid = 'test_last_scan'::regclass; + +-- fetch timestamps from before the next test +SELECT last_seq_scan AS test_last_seq, last_idx_scan AS test_last_idx +FROM pg_stat_all_tables WHERE relid = 'test_last_scan'::regclass \gset +SELECT pg_sleep(0.1); + +-- cause one index scan +BEGIN; +SET LOCAL enable_seqscan TO off; +SET LOCAL enable_indexscan TO on; +SET LOCAL enable_bitmapscan TO off; +EXPLAIN (COSTS off) SELECT count(*) FROM test_last_scan WHERE idx_col = 1; +SELECT count(*) FROM test_last_scan WHERE idx_col = 1; +SELECT pg_stat_force_next_flush(); +COMMIT; +-- check that just index scan stats were incremented +SELECT seq_scan, :'test_last_seq' = last_seq_scan AS seq_ok, idx_scan, :'test_last_idx' < last_idx_scan AS idx_ok +FROM pg_stat_all_tables WHERE relid = 'test_last_scan'::regclass; + +-- fetch timestamps from before the next test +SELECT last_seq_scan AS test_last_seq, last_idx_scan AS test_last_idx +FROM pg_stat_all_tables WHERE relid = 'test_last_scan'::regclass \gset +SELECT pg_sleep(0.1); + +-- cause one bitmap index scan +BEGIN; +SET LOCAL enable_seqscan TO off; +SET LOCAL enable_indexscan TO off; +SET LOCAL enable_bitmapscan TO on; +EXPLAIN (COSTS off) SELECT count(*) FROM test_last_scan WHERE idx_col = 1; +SELECT count(*) FROM test_last_scan WHERE idx_col = 1; +SELECT pg_stat_force_next_flush(); +COMMIT; +-- check that just index scan stats were incremented +SELECT seq_scan, :'test_last_seq' = last_seq_scan AS seq_ok, idx_scan, :'test_last_idx' < last_idx_scan AS idx_ok +FROM pg_stat_all_tables WHERE relid = 'test_last_scan'::regclass; + + ----- -- Test that various stats views are being properly populated -----