Skip to content

Commit

Permalink
Track statement entry timestamp in contrib/pg_stat_statements
Browse files Browse the repository at this point in the history
This patch adds 'stats_since' and 'minmax_stats_since' columns to the
pg_stat_statements view and pg_stat_statements() function.  The new min/max
reset mode for the pg_stat_stetments_reset() function is controlled by the
parameter minmax_only.

'stat_since' column is populated with the current timestamp when a new
statement is added to the pg_stat_statements hashtable.  It provides clean
information about statistics collection time intervals for each statement.
Besides it can be used by sampling solutions to detect situations when a
statement was evicted and stored again between samples.

Such a sampling solution could derive any pg_stat_statements statistic values
for an interval between two samples with the exception of all min/max
statistics. To address this issue this patch adds the ability to reset
min/max statistics independently of the statement reset using the new
minmax_only parameter of the pg_stat_statements_reset(userid oid, dbid oid,
queryid bigint, minmax_only boolean) function. The timestamp of such reset
is stored in the minmax_stats_since field for each statement.
pg_stat_statements_reset() function now returns the timestamp of a reset as the
result.

Discussion: https://postgr.es/m/flat/72e80e7b160a6eb189df9ef6f068cce3765d37f8.camel%40moonset.ru
Author: Andrei Zubkov
Reviewed-by: Julien Rouhaud, Hayato Kuroda, Yuki Seino, Chengxi Sun
Reviewed-by: Anton Melnikov, Darren Rush, Michael Paquier, Sergei Kornilov
Reviewed-by: Alena Rybakina, Andrei Lepikhov
  • Loading branch information
akorotkov committed Nov 27, 2023
1 parent 6ab1dbd commit dc9f8a7
Show file tree
Hide file tree
Showing 9 changed files with 511 additions and 96 deletions.
2 changes: 1 addition & 1 deletion contrib/pg_stat_statements/Makefile
Original file line number Diff line number Diff line change
Expand Up @@ -19,7 +19,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 cleanup oldextversions
user_activity wal entry_timestamp cleanup oldextversions
# 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
Expand Down
159 changes: 159 additions & 0 deletions contrib/pg_stat_statements/expected/entry_timestamp.out
Original file line number Diff line number Diff line change
@@ -0,0 +1,159 @@
--
-- statement timestamps
--
-- planning time is needed during tests
SET pg_stat_statements.track_planning = TRUE;
SELECT 1 AS "STMTTS1";
STMTTS1
---------
1
(1 row)

SELECT now() AS ref_ts \gset
SELECT 1,2 AS "STMTTS2";
?column? | STMTTS2
----------+---------
1 | 2
(1 row)

SELECT stats_since >= :'ref_ts', count(*) FROM pg_stat_statements
WHERE query LIKE '%STMTTS%'
GROUP BY stats_since >= :'ref_ts'
ORDER BY stats_since >= :'ref_ts';
?column? | count
----------+-------
f | 1
t | 1
(2 rows)

SELECT now() AS ref_ts \gset
SELECT
count(*) as total,
count(*) FILTER (
WHERE min_plan_time + max_plan_time = 0
) as minmax_plan_zero,
count(*) FILTER (
WHERE min_exec_time + max_exec_time = 0
) as minmax_exec_zero,
count(*) FILTER (
WHERE minmax_stats_since >= :'ref_ts'
) as minmax_stats_since_after_ref,
count(*) FILTER (
WHERE stats_since >= :'ref_ts'
) as stats_since_after_ref
FROM pg_stat_statements
WHERE query LIKE '%STMTTS%';
total | minmax_plan_zero | minmax_exec_zero | minmax_stats_since_after_ref | stats_since_after_ref
-------+------------------+------------------+------------------------------+-----------------------
2 | 0 | 0 | 0 | 0
(1 row)

-- Perform single min/max reset
SELECT pg_stat_statements_reset(0, 0, queryid, true) AS minmax_reset_ts
FROM pg_stat_statements
WHERE query LIKE '%STMTTS1%' \gset
-- check
SELECT
count(*) as total,
count(*) FILTER (
WHERE min_plan_time + max_plan_time = 0
) as minmax_plan_zero,
count(*) FILTER (
WHERE min_exec_time + max_exec_time = 0
) as minmax_exec_zero,
count(*) FILTER (
WHERE minmax_stats_since >= :'ref_ts'
) as minmax_stats_since_after_ref,
count(*) FILTER (
WHERE stats_since >= :'ref_ts'
) as stats_since_after_ref
FROM pg_stat_statements
WHERE query LIKE '%STMTTS%';
total | minmax_plan_zero | minmax_exec_zero | minmax_stats_since_after_ref | stats_since_after_ref
-------+------------------+------------------+------------------------------+-----------------------
2 | 1 | 1 | 1 | 0
(1 row)

-- check minmax reset timestamps
SELECT
query, minmax_stats_since = :'minmax_reset_ts' AS reset_ts_match
FROM pg_stat_statements
WHERE query LIKE '%STMTTS%'
ORDER BY query COLLATE "C";
query | reset_ts_match
---------------------------+----------------
SELECT $1 AS "STMTTS1" | t
SELECT $1,$2 AS "STMTTS2" | f
(2 rows)

-- check that minmax reset does not set stats_reset
SELECT
stats_reset = :'minmax_reset_ts' AS stats_reset_ts_match
FROM pg_stat_statements_info;
stats_reset_ts_match
----------------------
f
(1 row)

-- Perform common min/max reset
SELECT pg_stat_statements_reset(0, 0, 0, true) AS minmax_reset_ts \gset
-- check again
SELECT
count(*) as total,
count(*) FILTER (
WHERE min_plan_time + max_plan_time = 0
) as minmax_plan_zero,
count(*) FILTER (
WHERE min_exec_time + max_exec_time = 0
) as minmax_exec_zero,
count(*) FILTER (
WHERE minmax_stats_since >= :'ref_ts'
) as minmax_ts_after_ref,
count(*) FILTER (
WHERE minmax_stats_since = :'minmax_reset_ts'
) as minmax_ts_match,
count(*) FILTER (
WHERE stats_since >= :'ref_ts'
) as stats_since_after_ref
FROM pg_stat_statements
WHERE query LIKE '%STMTTS%';
total | minmax_plan_zero | minmax_exec_zero | minmax_ts_after_ref | minmax_ts_match | stats_since_after_ref
-------+------------------+------------------+---------------------+-----------------+-----------------------
2 | 2 | 2 | 2 | 2 | 0
(1 row)

-- Execute first query once more to check stats update
SELECT 1 AS "STMTTS1";
STMTTS1
---------
1
(1 row)

-- check
-- we don't check planing times here to be independent of
-- plan caching approach
SELECT
count(*) as total,
count(*) FILTER (
WHERE min_exec_time + max_exec_time = 0
) as minmax_exec_zero,
count(*) FILTER (
WHERE minmax_stats_since >= :'ref_ts'
) as minmax_ts_after_ref,
count(*) FILTER (
WHERE stats_since >= :'ref_ts'
) as stats_since_after_ref
FROM pg_stat_statements
WHERE query LIKE '%STMTTS%';
total | minmax_exec_zero | minmax_ts_after_ref | stats_since_after_ref
-------+------------------+---------------------+-----------------------
2 | 1 | 2 | 0
(1 row)

-- Cleanup
SELECT pg_stat_statements_reset() IS NOT NULL AS t;
t
---
t
(1 row)

116 changes: 65 additions & 51 deletions contrib/pg_stat_statements/expected/oldextversions.out
Original file line number Diff line number Diff line change
Expand Up @@ -250,64 +250,78 @@ SELECT count(*) > 0 AS has_data FROM pg_stat_statements;
t
(1 row)

-- New views for pg_stat_statements in 1.11
-- New functions and views for pg_stat_statements in 1.11
AlTER EXTENSION pg_stat_statements UPDATE TO '1.11';
\d pg_stat_statements
View "public.pg_stat_statements"
Column | Type | Collation | Nullable | Default
------------------------+------------------+-----------+----------+---------
userid | oid | | |
dbid | oid | | |
toplevel | boolean | | |
queryid | bigint | | |
query | text | | |
plans | bigint | | |
total_plan_time | double precision | | |
min_plan_time | double precision | | |
max_plan_time | double precision | | |
mean_plan_time | double precision | | |
stddev_plan_time | double precision | | |
calls | bigint | | |
total_exec_time | double precision | | |
min_exec_time | double precision | | |
max_exec_time | double precision | | |
mean_exec_time | double precision | | |
stddev_exec_time | double precision | | |
rows | bigint | | |
shared_blks_hit | bigint | | |
shared_blks_read | bigint | | |
shared_blks_dirtied | bigint | | |
shared_blks_written | bigint | | |
local_blks_hit | bigint | | |
local_blks_read | bigint | | |
local_blks_dirtied | bigint | | |
local_blks_written | bigint | | |
temp_blks_read | bigint | | |
temp_blks_written | bigint | | |
shared_blk_read_time | double precision | | |
shared_blk_write_time | double precision | | |
local_blk_read_time | double precision | | |
local_blk_write_time | double precision | | |
temp_blk_read_time | double precision | | |
temp_blk_write_time | double precision | | |
wal_records | bigint | | |
wal_fpi | bigint | | |
wal_bytes | numeric | | |
jit_functions | bigint | | |
jit_generation_time | double precision | | |
jit_inlining_count | bigint | | |
jit_inlining_time | double precision | | |
jit_optimization_count | bigint | | |
jit_optimization_time | double precision | | |
jit_emission_count | bigint | | |
jit_emission_time | double precision | | |
jit_deform_count | bigint | | |
jit_deform_time | double precision | | |
View "public.pg_stat_statements"
Column | Type | Collation | Nullable | Default
------------------------+--------------------------+-----------+----------+---------
userid | oid | | |
dbid | oid | | |
toplevel | boolean | | |
queryid | bigint | | |
query | text | | |
plans | bigint | | |
total_plan_time | double precision | | |
min_plan_time | double precision | | |
max_plan_time | double precision | | |
mean_plan_time | double precision | | |
stddev_plan_time | double precision | | |
calls | bigint | | |
total_exec_time | double precision | | |
min_exec_time | double precision | | |
max_exec_time | double precision | | |
mean_exec_time | double precision | | |
stddev_exec_time | double precision | | |
rows | bigint | | |
shared_blks_hit | bigint | | |
shared_blks_read | bigint | | |
shared_blks_dirtied | bigint | | |
shared_blks_written | bigint | | |
local_blks_hit | bigint | | |
local_blks_read | bigint | | |
local_blks_dirtied | bigint | | |
local_blks_written | bigint | | |
temp_blks_read | bigint | | |
temp_blks_written | bigint | | |
shared_blk_read_time | double precision | | |
shared_blk_write_time | double precision | | |
local_blk_read_time | double precision | | |
local_blk_write_time | double precision | | |
temp_blk_read_time | double precision | | |
temp_blk_write_time | double precision | | |
wal_records | bigint | | |
wal_fpi | bigint | | |
wal_bytes | numeric | | |
jit_functions | bigint | | |
jit_generation_time | double precision | | |
jit_inlining_count | bigint | | |
jit_inlining_time | double precision | | |
jit_optimization_count | bigint | | |
jit_optimization_time | double precision | | |
jit_emission_count | bigint | | |
jit_emission_time | double precision | | |
jit_deform_count | bigint | | |
jit_deform_time | double precision | | |
stats_since | timestamp with time zone | | |
minmax_stats_since | timestamp with time zone | | |

SELECT count(*) > 0 AS has_data FROM pg_stat_statements;
has_data
----------
t
(1 row)

-- New parameter minmax_only of pg_stat_statements_reset function
SELECT pg_get_functiondef('pg_stat_statements_reset'::regproc);
pg_get_functiondef
-------------------------------------------------------------------------------------------------------------------------------------------------------------------
CREATE OR REPLACE FUNCTION public.pg_stat_statements_reset(userid oid DEFAULT 0, dbid oid DEFAULT 0, queryid bigint DEFAULT 0, minmax_only boolean DEFAULT false)+
RETURNS timestamp with time zone +
LANGUAGE c +
PARALLEL SAFE STRICT +
AS '$libdir/pg_stat_statements', $function$pg_stat_statements_reset_1_11$function$ +

(1 row)

DROP EXTENSION pg_stat_statements;
1 change: 1 addition & 0 deletions contrib/pg_stat_statements/meson.build
Original file line number Diff line number Diff line change
Expand Up @@ -49,6 +49,7 @@ tests += {
'planning',
'user_activity',
'wal',
'entry_timestamp',
'cleanup',
'oldextversions',
],
Expand Down
23 changes: 17 additions & 6 deletions contrib/pg_stat_statements/pg_stat_statements--1.10--1.11.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3,13 +3,10 @@
-- complain if script is sourced in psql, rather than via ALTER EXTENSION
\echo Use "ALTER EXTENSION pg_stat_statements UPDATE TO '1.11'" 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 old versions */
DROP VIEW pg_stat_statements;
DROP FUNCTION pg_stat_statements(boolean);
DROP FUNCTION pg_stat_statements_reset(Oid, Oid, bigint);

/* Now redefine */
CREATE FUNCTION pg_stat_statements(IN showtext boolean,
Expand Down Expand Up @@ -59,7 +56,9 @@ CREATE FUNCTION pg_stat_statements(IN showtext boolean,
OUT jit_emission_count int8,
OUT jit_emission_time float8,
OUT jit_deform_count int8,
OUT jit_deform_time float8
OUT jit_deform_time float8,
OUT stats_since timestamp with time zone,
OUT minmax_stats_since timestamp with time zone
)
RETURNS SETOF record
AS 'MODULE_PATHNAME', 'pg_stat_statements_1_11'
Expand All @@ -69,3 +68,15 @@ CREATE VIEW pg_stat_statements AS
SELECT * FROM pg_stat_statements(true);

GRANT SELECT ON pg_stat_statements TO PUBLIC;

CREATE FUNCTION pg_stat_statements_reset(IN userid Oid DEFAULT 0,
IN dbid Oid DEFAULT 0,
IN queryid bigint DEFAULT 0,
IN minmax_only boolean DEFAULT false
)
RETURNS timestamp with time zone
AS 'MODULE_PATHNAME', 'pg_stat_statements_reset_1_11'
LANGUAGE C STRICT PARALLEL SAFE;

-- Don't want this to be available to non-superusers.
REVOKE ALL ON FUNCTION pg_stat_statements_reset(Oid, Oid, bigint, boolean) FROM PUBLIC;
Loading

0 comments on commit dc9f8a7

Please sign in to comment.