Skip to content

Commit 3e66693

Browse files
committed
pg_stat_statements: Add rows_filtered column
Add a new rows_filtered column to pg_stat_statements that tracks the total number of rows removed by filter conditions across all plan nodes. This helps identify queries that would benefit from better indexing. The feature is controlled by a new GUC pg_stat_statements.track_rows_filtered (default: off). When enabled, the module uses INSTRUMENT_ROWS instrumentation to collect nfiltered1 (scan/join qual) and nfiltered2 (recheck conditions) from all plan nodes via planstate_tree_walker. Key implementation details: - Uses INSTRUMENT_ROWS (not INSTRUMENT_ALL) to avoid timing overhead - Only increments tuple counters, which has negligible performance impact - GUC is superuser-only (PGC_SUSET), can be changed at runtime - Stats file header bumped to invalidate old stats files This addresses a common DBA need to identify inefficient sequential scans where adding an index could significantly improve performance.
1 parent d625d77 commit 3e66693

File tree

8 files changed

+555
-3
lines changed

8 files changed

+555
-3
lines changed

contrib/pg_stat_statements/Makefile

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -7,6 +7,7 @@ OBJS = \
77

88
EXTENSION = pg_stat_statements
99
DATA = pg_stat_statements--1.4.sql \
10+
pg_stat_statements--1.13--1.14.sql \
1011
pg_stat_statements--1.12--1.13.sql \
1112
pg_stat_statements--1.11--1.12.sql pg_stat_statements--1.10--1.11.sql \
1213
pg_stat_statements--1.9--1.10.sql pg_stat_statements--1.8--1.9.sql \
Lines changed: 205 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,205 @@
1+
--
2+
-- Test rows_filtered tracking
3+
--
4+
-- rows_filtered tracks the number of rows removed by filter conditions
5+
-- across all plan nodes. This requires pg_stat_statements.track_rows_filtered
6+
-- to be enabled.
7+
-- Ensure the extension is set up
8+
SELECT pg_stat_statements_reset() IS NOT NULL AS t;
9+
t
10+
---
11+
t
12+
(1 row)
13+
14+
-- Create test table
15+
CREATE TABLE filter_test (id int PRIMARY KEY, val int);
16+
INSERT INTO filter_test SELECT g, g FROM generate_series(1, 1000) g;
17+
ANALYZE filter_test;
18+
--
19+
-- Test 1: rows_filtered is 0 when tracking is disabled (default)
20+
--
21+
SHOW pg_stat_statements.track_rows_filtered;
22+
pg_stat_statements.track_rows_filtered
23+
----------------------------------------
24+
off
25+
(1 row)
26+
27+
SELECT pg_stat_statements_reset() IS NOT NULL AS t;
28+
t
29+
---
30+
t
31+
(1 row)
32+
33+
-- Force a sequential scan with filter
34+
SET enable_indexscan = off;
35+
SET enable_bitmapscan = off;
36+
SELECT count(*) FROM filter_test WHERE val > 900;
37+
count
38+
-------
39+
100
40+
(1 row)
41+
42+
RESET enable_indexscan;
43+
RESET enable_bitmapscan;
44+
-- rows_filtered should be 0 because tracking is disabled
45+
SELECT query, calls, rows, rows_filtered
46+
FROM pg_stat_statements
47+
WHERE query LIKE '%filter_test WHERE val%'
48+
ORDER BY query COLLATE "C";
49+
query | calls | rows | rows_filtered
50+
---------------------------------------------------+-------+------+---------------
51+
SELECT count(*) FROM filter_test WHERE val > $1 | 1 | 1 | 0
52+
(1 row)
53+
54+
--
55+
-- Test 2: rows_filtered is tracked when enabled
56+
--
57+
SET pg_stat_statements.track_rows_filtered = on;
58+
SHOW pg_stat_statements.track_rows_filtered;
59+
pg_stat_statements.track_rows_filtered
60+
----------------------------------------
61+
on
62+
(1 row)
63+
64+
SELECT pg_stat_statements_reset() IS NOT NULL AS t;
65+
t
66+
---
67+
t
68+
(1 row)
69+
70+
-- Force a sequential scan with filter: 100 rows pass (val > 900), 900 filtered
71+
SET enable_indexscan = off;
72+
SET enable_bitmapscan = off;
73+
SELECT count(*) FROM filter_test WHERE val > 900;
74+
count
75+
-------
76+
100
77+
(1 row)
78+
79+
RESET enable_indexscan;
80+
RESET enable_bitmapscan;
81+
-- rows_filtered should be 900 (the 900 rows that didn't pass the filter)
82+
SELECT query, calls, rows, rows_filtered
83+
FROM pg_stat_statements
84+
WHERE query LIKE '%filter_test WHERE val%'
85+
ORDER BY query COLLATE "C";
86+
query | calls | rows | rows_filtered
87+
---------------------------------------------------+-------+------+---------------
88+
SELECT count(*) FROM filter_test WHERE val > $1 | 1 | 1 | 900
89+
(1 row)
90+
91+
--
92+
-- Test 3: rows_filtered accumulates across multiple executions
93+
--
94+
SELECT count(*) FROM filter_test WHERE val > 900;
95+
count
96+
-------
97+
100
98+
(1 row)
99+
100+
SELECT count(*) FROM filter_test WHERE val > 900;
101+
count
102+
-------
103+
100
104+
(1 row)
105+
106+
-- After 3 total executions (with index scan now), rows_filtered should still
107+
-- reflect filtering. Note: with index scan, fewer rows are filtered.
108+
SELECT query, calls, rows, rows_filtered
109+
FROM pg_stat_statements
110+
WHERE query LIKE '%filter_test WHERE val%'
111+
ORDER BY query COLLATE "C";
112+
query | calls | rows | rows_filtered
113+
---------------------------------------------------+-------+------+---------------
114+
SELECT count(*) FROM filter_test WHERE val > $1 | 3 | 3 | 900
115+
(1 row)
116+
117+
--
118+
-- Test 4: Different filter selectivities
119+
--
120+
SELECT pg_stat_statements_reset() IS NOT NULL AS t;
121+
t
122+
---
123+
t
124+
(1 row)
125+
126+
SET enable_indexscan = off;
127+
SET enable_bitmapscan = off;
128+
-- Highly selective: 1 row passes, 999 filtered
129+
SELECT * FROM filter_test WHERE val = 500;
130+
id | val
131+
-----+-----
132+
500 | 500
133+
(1 row)
134+
135+
-- Low selectivity: 500 rows pass, 500 filtered
136+
SELECT count(*) FROM filter_test WHERE val > 500;
137+
count
138+
-------
139+
500
140+
(1 row)
141+
142+
RESET enable_indexscan;
143+
RESET enable_bitmapscan;
144+
SELECT query, calls, rows, rows_filtered
145+
FROM pg_stat_statements
146+
WHERE query LIKE '%filter_test WHERE val%'
147+
ORDER BY query COLLATE "C";
148+
query | calls | rows | rows_filtered
149+
---------------------------------------------------+-------+------+---------------
150+
SELECT * FROM filter_test WHERE val = $1 | 1 | 1 | 999
151+
SELECT count(*) FROM filter_test WHERE val > $1 | 1 | 1 | 500
152+
(2 rows)
153+
154+
--
155+
-- Test 5: Verify rows_filtered with JOIN queries
156+
--
157+
CREATE TABLE filter_test2 (id int PRIMARY KEY, ref_id int);
158+
INSERT INTO filter_test2 SELECT g, g % 100 FROM generate_series(1, 500) g;
159+
ANALYZE filter_test2;
160+
SELECT pg_stat_statements_reset() IS NOT NULL AS t;
161+
t
162+
---
163+
t
164+
(1 row)
165+
166+
SET enable_indexscan = off;
167+
SET enable_bitmapscan = off;
168+
SET enable_hashjoin = off;
169+
SET enable_mergejoin = off;
170+
-- Nested loop join with filter on inner table
171+
SELECT count(*)
172+
FROM filter_test2 t2
173+
JOIN filter_test t1 ON t1.id = t2.ref_id
174+
WHERE t1.val < 50;
175+
count
176+
-------
177+
245
178+
(1 row)
179+
180+
RESET enable_indexscan;
181+
RESET enable_bitmapscan;
182+
RESET enable_hashjoin;
183+
RESET enable_mergejoin;
184+
SELECT query, calls, rows, rows_filtered
185+
FROM pg_stat_statements
186+
WHERE query LIKE '%filter_test2%'
187+
AND query LIKE '%JOIN%'
188+
ORDER BY query COLLATE "C";
189+
query | calls | rows | rows_filtered
190+
----------------------------------------------------------------------------------------+-------+------+---------------
191+
SELECT count(*) +| 1 | 1 | 475255
192+
FROM filter_test2 t2 +| | |
193+
JOIN filter_test t1 ON t1.id = t2.ref_id +| | |
194+
WHERE t1.val < $1 | | |
195+
(1 row)
196+
197+
-- Cleanup
198+
RESET pg_stat_statements.track_rows_filtered;
199+
DROP TABLE filter_test, filter_test2;
200+
SELECT pg_stat_statements_reset() IS NOT NULL AS t;
201+
t
202+
---
203+
t
204+
(1 row)
205+

contrib/pg_stat_statements/meson.build

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -21,6 +21,7 @@ contrib_targets += pg_stat_statements
2121
install_data(
2222
'pg_stat_statements.control',
2323
'pg_stat_statements--1.4.sql',
24+
'pg_stat_statements--1.13--1.14.sql',
2425
'pg_stat_statements--1.12--1.13.sql',
2526
'pg_stat_statements--1.11--1.12.sql',
2627
'pg_stat_statements--1.10--1.11.sql',
@@ -56,6 +57,7 @@ tests += {
5657
'extended',
5758
'parallel',
5859
'plancache',
60+
'rows_filtered',
5961
'cleanup',
6062
'oldextversions',
6163
'squashing',
Lines changed: 79 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,79 @@
1+
/* contrib/pg_stat_statements/pg_stat_statements--1.13--1.14.sql */
2+
3+
-- complain if script is sourced in psql, rather than via ALTER EXTENSION
4+
\echo Use "ALTER EXTENSION pg_stat_statements UPDATE TO '1.14'" to load this file. \quit
5+
6+
/* First we have to remove them from the extension */
7+
ALTER EXTENSION pg_stat_statements DROP VIEW pg_stat_statements;
8+
ALTER EXTENSION pg_stat_statements DROP FUNCTION pg_stat_statements(boolean);
9+
10+
/* Then we can drop them */
11+
DROP VIEW pg_stat_statements;
12+
DROP FUNCTION pg_stat_statements(boolean);
13+
14+
/* Now redefine */
15+
CREATE FUNCTION pg_stat_statements(IN showtext boolean,
16+
OUT userid oid,
17+
OUT dbid oid,
18+
OUT toplevel bool,
19+
OUT queryid bigint,
20+
OUT query text,
21+
OUT plans int8,
22+
OUT total_plan_time float8,
23+
OUT min_plan_time float8,
24+
OUT max_plan_time float8,
25+
OUT mean_plan_time float8,
26+
OUT stddev_plan_time float8,
27+
OUT calls int8,
28+
OUT total_exec_time float8,
29+
OUT min_exec_time float8,
30+
OUT max_exec_time float8,
31+
OUT mean_exec_time float8,
32+
OUT stddev_exec_time float8,
33+
OUT rows int8,
34+
OUT rows_filtered int8,
35+
OUT shared_blks_hit int8,
36+
OUT shared_blks_read int8,
37+
OUT shared_blks_dirtied int8,
38+
OUT shared_blks_written int8,
39+
OUT local_blks_hit int8,
40+
OUT local_blks_read int8,
41+
OUT local_blks_dirtied int8,
42+
OUT local_blks_written int8,
43+
OUT temp_blks_read int8,
44+
OUT temp_blks_written int8,
45+
OUT shared_blk_read_time float8,
46+
OUT shared_blk_write_time float8,
47+
OUT local_blk_read_time float8,
48+
OUT local_blk_write_time float8,
49+
OUT temp_blk_read_time float8,
50+
OUT temp_blk_write_time float8,
51+
OUT wal_records int8,
52+
OUT wal_fpi int8,
53+
OUT wal_bytes numeric,
54+
OUT wal_buffers_full int8,
55+
OUT jit_functions int8,
56+
OUT jit_generation_time float8,
57+
OUT jit_inlining_count int8,
58+
OUT jit_inlining_time float8,
59+
OUT jit_optimization_count int8,
60+
OUT jit_optimization_time float8,
61+
OUT jit_emission_count int8,
62+
OUT jit_emission_time float8,
63+
OUT jit_deform_count int8,
64+
OUT jit_deform_time float8,
65+
OUT parallel_workers_to_launch int8,
66+
OUT parallel_workers_launched int8,
67+
OUT generic_plan_calls int8,
68+
OUT custom_plan_calls int8,
69+
OUT stats_since timestamp with time zone,
70+
OUT minmax_stats_since timestamp with time zone
71+
)
72+
RETURNS SETOF record
73+
AS 'MODULE_PATHNAME', 'pg_stat_statements_1_14'
74+
LANGUAGE C STRICT VOLATILE PARALLEL SAFE;
75+
76+
CREATE VIEW pg_stat_statements AS
77+
SELECT * FROM pg_stat_statements(true);
78+
79+
GRANT SELECT ON pg_stat_statements TO PUBLIC;

0 commit comments

Comments
 (0)