[PATCH] Add last_executed timestamp to pg_stat_statements
Hello,
I would like to propose adding a last_executed timestamptz column to
pg_stat_statements. This column records when each tracked statement
was most recently executed.
The motivation comes from real world experience with monitoring tools
like pgwatch that poll pg_stat_statements regularly. Currently, these
tools must fetch and store statistics for all statements, even those
that haven't executed recently. This creates significant storage
overhead. For a database with around 3400 statements polled every 3
minutes, storing full query text requires roughly 2.5 MB per snapshot.
Over two weeks, this accumulates to about 17 GB. Even without query
text, storage reaches 10 GB.
With a last_executed timestamptz, monitoring tools can simply filter
statements by "last_executed > NOW() - polling_interval" to fetch only
statements that have been executed since the last poll. This
eliminates the need for complex workarounds that some tools currently
use to identify changed statements
(https://github.com/cybertec-postgresql/pgwatch/blob/759df3a149cbbe973165547186068aa7b5332f9d/internal/metrics/metrics.yaml#L2605-L2766).
Beyond monitoring efficiency, the timestamp enables other useful
queries. You can find statements that haven't executed in 30 days to
identify deprecated code paths. You can correlate statement execution
with specific time windows during incident investigation. You can also
make informed decisions about which statistics to reset.
The implementation is straightforward. The timestamp is stored in the
Counters structure and updated on every statement execution, protected
by the existing spinlock. The overhead is minimal, just a single
timestamp assignment per execution. The timestamp persists with other
statistics across server restarts. I've bumped the stats file format
version to handle the structure change cleanly.
The patch includes a new pg_stat_statements_1_14 function, the upgrade
script from 1.13 to 1.14, and regression tests. All existing tests
continue to pass.
I believe this is a simple addition that addresses a real pain point
for database monitoring and provides useful functionality for
understanding query patterns over time.
Thanks in advance!
Attached patch applies cleanly to the current master.
Attachments:
0001-pg_stat_statements_last_executed.patchapplication/octet-stream; name=0001-pg_stat_statements_last_executed.patchDownload
From 97aed1483d21359d0c0dfd1c332c0e569f66ac09 Mon Sep 17 00:00:00 2001
From: Pavlo Golub <pavlo.golub@cybertec.at>
Date: Wed, 10 Dec 2025 15:14:22 +0000
Subject: [PATCH] Add last_executed timestamp to pg_stat_statements
This patch adds a last_executed timestamp column to pg_stat_statements,
recording when each statement was most recently executed. This enables
efficient filtering of active statements, which is particularly useful
for monitoring systems that poll pg_stat_statements periodically.
The new column helps reduce storage overhead in monitoring systems. For
example, a system polling every 3 minutes can now filter statements
executed since the last poll, avoiding storage of unchanged statistics.
The implementation updates the timestamp on every statement execution
with minimal overhead, protected by the existing spinlock. The timestamp
is persisted with other statistics and survives server restarts.
Changes include:
- New last_executed column of type timestamptz in pg_stat_statements view
- pg_stat_statements_1_14 function for version 1.14
- Upgrade script from version 1.13 to 1.14
- Regression test covering timestamp behavior
- Updated file header magic number for stats file format change
- Documentation updates
---
contrib/pg_stat_statements/Makefile | 3 +-
.../expected/last_executed.out | 113 ++++++++++++++++++
contrib/pg_stat_statements/meson.build | 2 +
.../pg_stat_statements--1.13--1.14.sql | 79 ++++++++++++
.../pg_stat_statements/pg_stat_statements.c | 30 ++++-
.../pg_stat_statements.control | 2 +-
.../pg_stat_statements/sql/last_executed.sql | 52 ++++++++
doc/src/sgml/pgstatstatements.sgml | 9 ++
8 files changed, 286 insertions(+), 4 deletions(-)
create mode 100644 contrib/pg_stat_statements/expected/last_executed.out
create mode 100644 contrib/pg_stat_statements/pg_stat_statements--1.13--1.14.sql
create mode 100644 contrib/pg_stat_statements/sql/last_executed.sql
diff --git a/contrib/pg_stat_statements/Makefile b/contrib/pg_stat_statements/Makefile
index fe0478ac552..518030d2188 100644
--- a/contrib/pg_stat_statements/Makefile
+++ b/contrib/pg_stat_statements/Makefile
@@ -7,6 +7,7 @@ OBJS = \
EXTENSION = pg_stat_statements
DATA = pg_stat_statements--1.4.sql \
+ pg_stat_statements--1.13--1.14.sql \
pg_stat_statements--1.12--1.13.sql \
pg_stat_statements--1.11--1.12.sql pg_stat_statements--1.10--1.11.sql \
pg_stat_statements--1.9--1.10.sql pg_stat_statements--1.8--1.9.sql \
@@ -21,7 +22,7 @@ LDFLAGS_SL += $(filter -lm, $(LIBS))
REGRESS_OPTS = --temp-config $(top_srcdir)/contrib/pg_stat_statements/pg_stat_statements.conf
REGRESS = select dml cursors utility level_tracking planning \
user_activity wal entry_timestamp privileges extended \
- parallel plancache cleanup oldextversions squashing
+ parallel plancache cleanup oldextversions squashing last_executed
# Disabled because these tests require "shared_preload_libraries=pg_stat_statements",
# which typical installcheck users do not have (e.g. buildfarm clients).
NO_INSTALLCHECK = 1
diff --git a/contrib/pg_stat_statements/expected/last_executed.out b/contrib/pg_stat_statements/expected/last_executed.out
new file mode 100644
index 00000000000..9d6502566b1
--- /dev/null
+++ b/contrib/pg_stat_statements/expected/last_executed.out
@@ -0,0 +1,113 @@
+--
+-- last_executed timestamp
+--
+SELECT pg_stat_statements_reset() IS NOT NULL AS t;
+ t
+---
+ t
+(1 row)
+
+SELECT 1 AS "LAST1";
+ LAST1
+-------
+ 1
+(1 row)
+
+SELECT now() AS ref_ts1 \gset
+SELECT pg_sleep(0.1);
+ pg_sleep
+----------
+
+(1 row)
+
+SELECT 2 AS "LAST2";
+ LAST2
+-------
+ 2
+(1 row)
+
+SELECT now() AS ref_ts2 \gset
+-- verify last_executed is set and updated
+SELECT
+ query,
+ last_executed IS NOT NULL as has_ts,
+ last_executed >= :'ref_ts1' as after_ref1,
+ stats_since <= last_executed as after_stats_since
+FROM pg_stat_statements
+WHERE query LIKE '%LAST%'
+ORDER BY query COLLATE "C";
+ query | has_ts | after_ref1 | after_stats_since
+----------------------+--------+------------+-------------------
+ SELECT $1 AS "LAST1" | t | t | t
+(1 row)
+
+-- execute again and verify update
+SELECT pg_sleep(0.1);
+ pg_sleep
+----------
+
+(1 row)
+
+SELECT 1 AS "LAST1";
+ LAST1
+-------
+ 1
+(1 row)
+
+SELECT now() AS ref_ts3 \gset
+SELECT
+ query,
+ last_executed >= :'ref_ts3' as updated
+FROM pg_stat_statements
+WHERE query LIKE '%LAST1%';
+ query | updated
+----------------------+---------
+ SELECT $1 AS "LAST1" | f
+(1 row)
+
+-- test filtering (monitoring use case)
+SELECT query, count(*) as count
+FROM pg_stat_statements
+WHERE last_executed >= :'ref_ts2'
+GROUP BY query
+ORDER BY query COLLATE "C";
+ query | count
+-------------------------------------------------------+-------
+ SELECT +| 1
+ query, +|
+ last_executed >= $1 as updated +|
+ FROM pg_stat_statements +|
+ WHERE query LIKE $2 |
+ SELECT +| 1
+ query, +|
+ last_executed IS NOT NULL as has_ts, +|
+ last_executed >= $1 as after_ref1, +|
+ stats_since <= last_executed as after_stats_since+|
+ FROM pg_stat_statements +|
+ WHERE query LIKE $2 +|
+ ORDER BY query COLLATE "C" |
+ SELECT $1 AS "LAST1" | 1
+ SELECT now() AS ref_ts1 | 1
+ SELECT pg_sleep($1) | 1
+(5 rows)
+
+-- minmax reset should not affect last_executed
+SELECT pg_stat_statements_reset(0, 0, queryid, true)
+FROM pg_stat_statements
+WHERE query LIKE '%LAST1%' \gset
+SELECT
+ query,
+ last_executed >= :'ref_ts3' as ts_preserved
+FROM pg_stat_statements
+WHERE query LIKE '%LAST1%';
+ query | ts_preserved
+----------------------+--------------
+ SELECT $1 AS "LAST1" | f
+(1 row)
+
+SELECT pg_stat_statements_reset() IS NOT NULL AS t;
+ t
+---
+ t
+(1 row)
+
diff --git a/contrib/pg_stat_statements/meson.build b/contrib/pg_stat_statements/meson.build
index 7b8bfbb1de7..12760f9c3a1 100644
--- a/contrib/pg_stat_statements/meson.build
+++ b/contrib/pg_stat_statements/meson.build
@@ -21,6 +21,7 @@ contrib_targets += pg_stat_statements
install_data(
'pg_stat_statements.control',
'pg_stat_statements--1.4.sql',
+ 'pg_stat_statements--1.13--1.14.sql',
'pg_stat_statements--1.12--1.13.sql',
'pg_stat_statements--1.11--1.12.sql',
'pg_stat_statements--1.10--1.11.sql',
@@ -59,6 +60,7 @@ tests += {
'cleanup',
'oldextversions',
'squashing',
+ 'last_executed',
],
'regress_args': ['--temp-config', files('pg_stat_statements.conf')],
# Disabled because these tests require
diff --git a/contrib/pg_stat_statements/pg_stat_statements--1.13--1.14.sql b/contrib/pg_stat_statements/pg_stat_statements--1.13--1.14.sql
new file mode 100644
index 00000000000..5b9ca8b2f77
--- /dev/null
+++ b/contrib/pg_stat_statements/pg_stat_statements--1.13--1.14.sql
@@ -0,0 +1,79 @@
+/* contrib/pg_stat_statements/pg_stat_statements--1.13--1.14.sql */
+
+-- complain if script is sourced in psql, rather than via ALTER EXTENSION
+\echo Use "ALTER EXTENSION pg_stat_statements UPDATE TO '1.14'" to load this file. \quit
+
+/* First we have to remove them from the extension */
+ALTER EXTENSION pg_stat_statements DROP VIEW pg_stat_statements;
+ALTER EXTENSION pg_stat_statements DROP FUNCTION pg_stat_statements(boolean);
+
+/* Then we can drop them */
+DROP VIEW pg_stat_statements;
+DROP FUNCTION pg_stat_statements(boolean);
+
+/* Now redefine */
+CREATE FUNCTION pg_stat_statements(IN showtext boolean,
+ OUT userid oid,
+ OUT dbid oid,
+ OUT toplevel bool,
+ OUT queryid bigint,
+ OUT query text,
+ OUT plans int8,
+ OUT total_plan_time float8,
+ OUT min_plan_time float8,
+ OUT max_plan_time float8,
+ OUT mean_plan_time float8,
+ OUT stddev_plan_time float8,
+ OUT calls int8,
+ OUT total_exec_time float8,
+ OUT min_exec_time float8,
+ OUT max_exec_time float8,
+ OUT mean_exec_time float8,
+ OUT stddev_exec_time float8,
+ OUT rows int8,
+ OUT shared_blks_hit int8,
+ OUT shared_blks_read int8,
+ OUT shared_blks_dirtied int8,
+ OUT shared_blks_written int8,
+ OUT local_blks_hit int8,
+ OUT local_blks_read int8,
+ OUT local_blks_dirtied int8,
+ OUT local_blks_written int8,
+ OUT temp_blks_read int8,
+ OUT temp_blks_written int8,
+ OUT shared_blk_read_time float8,
+ OUT shared_blk_write_time float8,
+ OUT local_blk_read_time float8,
+ OUT local_blk_write_time float8,
+ OUT temp_blk_read_time float8,
+ OUT temp_blk_write_time float8,
+ OUT wal_records int8,
+ OUT wal_fpi int8,
+ OUT wal_bytes numeric,
+ OUT wal_buffers_full int8,
+ OUT jit_functions int8,
+ OUT jit_generation_time float8,
+ OUT jit_inlining_count int8,
+ OUT jit_inlining_time float8,
+ OUT jit_optimization_count int8,
+ OUT jit_optimization_time float8,
+ OUT jit_emission_count int8,
+ OUT jit_emission_time float8,
+ OUT jit_deform_count int8,
+ OUT jit_deform_time float8,
+ OUT parallel_workers_to_launch int8,
+ OUT parallel_workers_launched int8,
+ OUT generic_plan_calls int8,
+ OUT custom_plan_calls int8,
+ OUT stats_since timestamp with time zone,
+ OUT minmax_stats_since timestamp with time zone,
+ OUT last_executed timestamp with time zone
+)
+RETURNS SETOF record
+AS 'MODULE_PATHNAME', 'pg_stat_statements_1_14'
+LANGUAGE C STRICT VOLATILE PARALLEL SAFE;
+
+CREATE VIEW pg_stat_statements AS
+ SELECT * FROM pg_stat_statements(true);
+
+GRANT SELECT ON pg_stat_statements TO PUBLIC;
diff --git a/contrib/pg_stat_statements/pg_stat_statements.c b/contrib/pg_stat_statements/pg_stat_statements.c
index 39208f80b5b..df5890e3fec 100644
--- a/contrib/pg_stat_statements/pg_stat_statements.c
+++ b/contrib/pg_stat_statements/pg_stat_statements.c
@@ -86,7 +86,7 @@ PG_MODULE_MAGIC_EXT(
#define PGSS_TEXT_FILE PG_STAT_TMP_DIR "/pgss_query_texts.stat"
/* Magic number identifying the stats file format */
-static const uint32 PGSS_FILE_HEADER = 0x20250731;
+static const uint32 PGSS_FILE_HEADER = 0x20251210;
/* PostgreSQL major version number, changes in which invalidate all entries */
static const uint32 PGSS_PG_MAJOR_VERSION = PG_VERSION_NUM / 100;
@@ -116,6 +116,7 @@ typedef enum pgssVersion
PGSS_V1_11,
PGSS_V1_12,
PGSS_V1_13,
+ PGSS_V1_14,
} pgssVersion;
typedef enum pgssStoreKind
@@ -213,6 +214,7 @@ typedef struct Counters
* launched */
int64 generic_plan_calls; /* number of calls using a generic plan */
int64 custom_plan_calls; /* number of calls using a custom plan */
+ TimestampTz last_executed; /* timestamp of last statement execution */
} Counters;
/*
@@ -327,6 +329,7 @@ PG_FUNCTION_INFO_V1(pg_stat_statements_1_10);
PG_FUNCTION_INFO_V1(pg_stat_statements_1_11);
PG_FUNCTION_INFO_V1(pg_stat_statements_1_12);
PG_FUNCTION_INFO_V1(pg_stat_statements_1_13);
+PG_FUNCTION_INFO_V1(pg_stat_statements_1_14);
PG_FUNCTION_INFO_V1(pg_stat_statements);
PG_FUNCTION_INFO_V1(pg_stat_statements_info);
@@ -1513,6 +1516,9 @@ pgss_store(const char *query, int64 queryId,
else if (planOrigin == PLAN_STMT_CACHE_CUSTOM)
entry->counters.custom_plan_calls++;
+ /* Update last_executed timestamp */
+ entry->counters.last_executed = GetCurrentTimestamp();
+
SpinLockRelease(&entry->mutex);
}
@@ -1581,7 +1587,8 @@ pg_stat_statements_reset(PG_FUNCTION_ARGS)
#define PG_STAT_STATEMENTS_COLS_V1_11 49
#define PG_STAT_STATEMENTS_COLS_V1_12 52
#define PG_STAT_STATEMENTS_COLS_V1_13 54
-#define PG_STAT_STATEMENTS_COLS 54 /* maximum of above */
+#define PG_STAT_STATEMENTS_COLS_V1_14 55
+#define PG_STAT_STATEMENTS_COLS 55 /* maximum of above */
/*
* Retrieve statement statistics.
@@ -1593,6 +1600,16 @@ pg_stat_statements_reset(PG_FUNCTION_ARGS)
* expected API version is identified by embedding it in the C name of the
* function. Unfortunately we weren't bright enough to do that for 1.1.
*/
+Datum
+pg_stat_statements_1_14(PG_FUNCTION_ARGS)
+{
+ bool showtext = PG_GETARG_BOOL(0);
+
+ pg_stat_statements_internal(fcinfo, PGSS_V1_14, showtext);
+
+ return (Datum) 0;
+}
+
Datum
pg_stat_statements_1_13(PG_FUNCTION_ARGS)
{
@@ -1765,6 +1782,10 @@ pg_stat_statements_internal(FunctionCallInfo fcinfo,
if (api_version != PGSS_V1_13)
elog(ERROR, "incorrect number of output arguments");
break;
+ case PG_STAT_STATEMENTS_COLS_V1_14:
+ if (api_version != PGSS_V1_14)
+ elog(ERROR, "incorrect number of output arguments");
+ break;
default:
elog(ERROR, "incorrect number of output arguments");
}
@@ -2027,6 +2048,10 @@ pg_stat_statements_internal(FunctionCallInfo fcinfo,
values[i++] = TimestampTzGetDatum(stats_since);
values[i++] = TimestampTzGetDatum(minmax_stats_since);
}
+ if (api_version >= PGSS_V1_14)
+ {
+ values[i++] = TimestampTzGetDatum(tmp.last_executed);
+ }
Assert(i == (api_version == PGSS_V1_0 ? PG_STAT_STATEMENTS_COLS_V1_0 :
api_version == PGSS_V1_1 ? PG_STAT_STATEMENTS_COLS_V1_1 :
@@ -2038,6 +2063,7 @@ pg_stat_statements_internal(FunctionCallInfo fcinfo,
api_version == PGSS_V1_11 ? PG_STAT_STATEMENTS_COLS_V1_11 :
api_version == PGSS_V1_12 ? PG_STAT_STATEMENTS_COLS_V1_12 :
api_version == PGSS_V1_13 ? PG_STAT_STATEMENTS_COLS_V1_13 :
+ api_version == PGSS_V1_14 ? PG_STAT_STATEMENTS_COLS_V1_14 :
-1 /* fail if you forget to update this assert */ ));
tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, values, nulls);
diff --git a/contrib/pg_stat_statements/pg_stat_statements.control b/contrib/pg_stat_statements/pg_stat_statements.control
index 2eee0ceffa8..61ae41efc14 100644
--- a/contrib/pg_stat_statements/pg_stat_statements.control
+++ b/contrib/pg_stat_statements/pg_stat_statements.control
@@ -1,5 +1,5 @@
# pg_stat_statements extension
comment = 'track planning and execution statistics of all SQL statements executed'
-default_version = '1.13'
+default_version = '1.14'
module_pathname = '$libdir/pg_stat_statements'
relocatable = true
diff --git a/contrib/pg_stat_statements/sql/last_executed.sql b/contrib/pg_stat_statements/sql/last_executed.sql
new file mode 100644
index 00000000000..b68ec2165be
--- /dev/null
+++ b/contrib/pg_stat_statements/sql/last_executed.sql
@@ -0,0 +1,52 @@
+--
+-- last_executed timestamp
+--
+
+SELECT pg_stat_statements_reset() IS NOT NULL AS t;
+
+SELECT 1 AS "LAST1";
+SELECT now() AS ref_ts1 \gset
+SELECT pg_sleep(0.1);
+SELECT 2 AS "LAST2";
+SELECT now() AS ref_ts2 \gset
+
+-- verify last_executed is set and updated
+SELECT
+ query,
+ last_executed IS NOT NULL as has_ts,
+ last_executed >= :'ref_ts1' as after_ref1,
+ stats_since <= last_executed as after_stats_since
+FROM pg_stat_statements
+WHERE query LIKE '%LAST%'
+ORDER BY query COLLATE "C";
+
+-- execute again and verify update
+SELECT pg_sleep(0.1);
+SELECT 1 AS "LAST1";
+SELECT now() AS ref_ts3 \gset
+
+SELECT
+ query,
+ last_executed >= :'ref_ts3' as updated
+FROM pg_stat_statements
+WHERE query LIKE '%LAST1%';
+
+-- test filtering (monitoring use case)
+SELECT query, count(*) as count
+FROM pg_stat_statements
+WHERE last_executed >= :'ref_ts2'
+GROUP BY query
+ORDER BY query COLLATE "C";
+
+-- minmax reset should not affect last_executed
+SELECT pg_stat_statements_reset(0, 0, queryid, true)
+FROM pg_stat_statements
+WHERE query LIKE '%LAST1%' \gset
+
+SELECT
+ query,
+ last_executed >= :'ref_ts3' as ts_preserved
+FROM pg_stat_statements
+WHERE query LIKE '%LAST1%';
+
+SELECT pg_stat_statements_reset() IS NOT NULL AS t;
diff --git a/doc/src/sgml/pgstatstatements.sgml b/doc/src/sgml/pgstatstatements.sgml
index d753de5836e..e5d75c6a2f5 100644
--- a/doc/src/sgml/pgstatstatements.sgml
+++ b/doc/src/sgml/pgstatstatements.sgml
@@ -593,6 +593,15 @@
<structfield>max_exec_time</structfield>)
</para></entry>
</row>
+
+ <row>
+ <entry role="catalog_table_entry"><para role="column_definition">
+ <structfield>last_executed</structfield> <type>timestamp with time zone</type>
+ </para>
+ <para>
+ Time at which the statement was last executed
+ </para></entry>
+ </row>
</tbody>
</tgroup>
</table>
--
2.52.0
Hi,
Thanks for raising this. I did not look at the patch, but I have some high
level comments.
I would like to propose adding a last_executed timestamptz column to
pg_stat_statements. This column records when each tracked statement
was most recently executed.
I do think there is value in adding a last_executed timestamp. I actually think
last_executed should be the time the query started timestamp, so we should
actually create an entry at ExecutorStart, along with calls_started and
calls_completed. This is great for tracking cancelled queries.
The issue is the extra overhead of tracking the query on
EcecutorStart, but that
should be less of an issue once we move pg_stat_statements to the cumulative
statistics system, which will be possible once we get some prerequisite
work to make this happen [0]/messages/by-id/CAA5RZ0s9SDOu+Z6veoJCHWk+kDeTktAtC-KY9fQ9Z6BJdDUirQ@mail.gmail.com.
Another concern is the width of the current view. I think before we add
any new attribute, pg_stat_statements fields should be split.
This was discussed in [1]/messages/by-id/03f82e6f-66a3-4c4d-935c-ea4d93871dc1@gmail.com.
The motivation comes from real world experience with monitoring tools
like pgwatch that poll pg_stat_statements regularly. Currently, these
tools must fetch and store statistics for all statements, even those
that haven't executed recently. This creates significant storage
overhead. For a database with around 3400 statements polled every 3
minutes, storing full query text requires roughly 2.5 MB per snapshot.
Over two weeks, this accumulates to about 17 GB. Even without query
text, storage reaches 10 GB.With a last_executed timestamptz, monitoring tools can simply filter
statements by "last_executed > NOW() - polling_interval" to fetch only
statements that have been executed since the last poll. This
eliminates the need for complex workarounds that some tools currently
use to identify changed statements
(https://github.com/cybertec-postgresql/pgwatch/blob/759df3a149cbbe973165547186068aa7b5332f9d/internal/metrics/metrics.yaml#L2605-L2766).
Can pg_stat_statements.stats_since help here?
for example "where stats_since > last_poll_timestamp" ?
The client does have to track the last_poll_timestamp in that
case.
[0]: /messages/by-id/CAA5RZ0s9SDOu+Z6veoJCHWk+kDeTktAtC-KY9fQ9Z6BJdDUirQ@mail.gmail.com
[1]: /messages/by-id/03f82e6f-66a3-4c4d-935c-ea4d93871dc1@gmail.com
--
Sami Imseih
Amazon Web Services (AWS)
Hi
Hi,
Thanks for raising this. I did not look at the patch, but I have some high
level comments.I would like to propose adding a last_executed timestamptz column to
pg_stat_statements. This column records when each tracked statement
was most recently executed.I do think there is value in adding a last_executed timestamp.
Thanks for your support!
Can pg_stat_statements.stats_since help here?
for example "where stats_since > last_poll_timestamp" ?
Actually no, monitoring tools fetch snapshots to find the difference
between snapshots.
Data for every statement is changes after each execution.
But stats_since is inserted only once when the new statement execution
appears and is never updated during next executions.
Show quoted text
The client does have to track the last_poll_timestamp in that
case.[0] /messages/by-id/CAA5RZ0s9SDOu+Z6veoJCHWk+kDeTktAtC-KY9fQ9Z6BJdDUirQ@mail.gmail.com
[1] /messages/by-id/03f82e6f-66a3-4c4d-935c-ea4d93871dc1@gmail.com--
Sami Imseih
Amazon Web Services (AWS)
Can pg_stat_statements.stats_since help here?
for example "where stats_since > last_poll_timestamp" ?
Actually no, monitoring tools fetch snapshots to find the difference
between snapshots.
Data for every statement is changes after each execution.But stats_since is inserted only once when the new statement execution
appears and is never updated during next executions.
I was thinking of using stats_since to avoid fetching query text,
since that does not change. But you are talking about avoiding all
the stats if they have not changed. I see that now.
FWIW, this was discussed back in 2017 [0]/messages/by-id/CA+TgmoZgZMeuN8t9pawSt6M=mvxKiAZ4CvPofBWwwVWeZwHe4w@mail.gmail.com, and at that time there was
some support for last_executed, but the patch did not go anywhere.
After looking at the patch, I have a few comments:
1/ There are whitespace errors when applying.
2/ Calling GetCurrentTimestamp while holding a spinlock is
not a good idea and should be avoided. This was also a point
raised in [0]/messages/by-id/CA+TgmoZgZMeuN8t9pawSt6M=mvxKiAZ4CvPofBWwwVWeZwHe4w@mail.gmail.com. Even when we move pg_stat_statements
to cumulative stats and not at the mercy of the spinlock for updating
entries, i would still hesitate to add an additional GetCurrentTimestamp()
for every call.
I wonder if we can use GetCurrentStatementStartTimestamp()
instead?
```
/*
* GetCurrentStatementStartTimestamp
*/
TimestampTz
GetCurrentStatementStartTimestamp(void)
{
return stmtStartTimestamp;
}
```
stmtStartTimestamp is the time the query started, which seems OK for
the use-case you are mentioning. But also, stmtStartTimestamp gets
set at the top-level so nested entries (toplevel = false ) will just
inherit the timestamp of the top-level entry.
IMO, this is the most important point in the patch for now.
3/ last_executed, or maybe (last_toplevel_start) if we go with #2 should not
be added under pgssEntry->Counters, but rather directory under pgssEntry.
@@ -213,6 +214,7 @@ typedef struct Counters
* launched */
int64 generic_plan_calls; /* number of calls using a generic plan */
int64 custom_plan_calls; /* number of calls using a
custom plan */
+ TimestampTz last_executed; /* timestamp of last statement execution */
} Counters;
4/ instead of a " last_executed" maybe the tests should be added to
entry_timestamp.sql?
[0]: /messages/by-id/CA+TgmoZgZMeuN8t9pawSt6M=mvxKiAZ4CvPofBWwwVWeZwHe4w@mail.gmail.com
--
Sami Imseih
Amazon Web Services (AWS)