Skip to content

Commit 74cfaf4

Browse files
committed
Normalized slow query logging
Replaces the previous slow query metric with a new version that normalizes queries and sequentially number parameters without limit, improving PII safety and query pattern analysis.
1 parent ab0b92e commit 74cfaf4

File tree

1 file changed

+85
-22
lines changed

1 file changed

+85
-22
lines changed

metrics/slow_queries.yml

Lines changed: 85 additions & 22 deletions
Original file line numberDiff line numberDiff line change
@@ -1,27 +1,90 @@
1-
#==============================================================#
2-
# Slow Query Monitoring using pg_stat_monitor
3-
#==============================================================#
1+
#==============================================================================#
2+
# Slow Query Monitoring with Unlimited Sequential Parameter Numbering (Pure SQL)
3+
#==============================================================================#
44
# Tracks queries that exceed performance thresholds
55
# Requires pg_stat_monitor extension
66

7-
slow_queries:
8-
name: slow_queries
9-
desc: Queries exceeding execution time thresholds from pg_stat_monitor
7+
pg_slow_queries:
8+
name: pg_slow_queries
9+
desc: Queries exceeding execution time thresholds with normalized text (no PII) and unlimited sequential parameters
1010
query: |
11-
SELECT
12-
COALESCE(userid::regrole::text, 'unknown') as user,
13-
COALESCE(datname, current_database()) as datname,
14-
queryid::text as queryid,
15-
left(regexp_replace(query, '\s+', ' ', 'g'), 100) as query_text,
16-
calls::float8 as calls,
17-
mean_exec_time::float8 as mean_exec_time,
18-
max_exec_time::float8 as max_exec_time,
19-
total_exec_time::float8 as total_exec_time,
20-
rows::float8 as rows_retrieved,
21-
(COALESCE(shared_blks_hit, 0) + COALESCE(shared_blks_read, 0))::float8 as total_blocks,
22-
(COALESCE(cpu_user_time, 0) + COALESCE(cpu_sys_time, 0))::float8 as total_cpu_time
23-
FROM pg_stat_monitor
24-
WHERE mean_exec_time > 1000 -- Queries averaging over 1 second
11+
WITH RECURSIVE
12+
base_queries AS (
13+
SELECT
14+
COALESCE(userid::regrole::text, 'unknown') as user,
15+
COALESCE(datname, current_database()) as datname,
16+
queryid::text as queryid,
17+
calls::float8 as calls,
18+
mean_exec_time::float8 as mean_exec_time,
19+
max_exec_time::float8 as max_exec_time,
20+
total_exec_time::float8 as total_exec_time,
21+
rows::float8 as rows_retrieved,
22+
(COALESCE(shared_blks_hit, 0) + COALESCE(shared_blks_read, 0))::float8 as total_blocks,
23+
(COALESCE(cpu_user_time, 0) + COALESCE(cpu_sys_time, 0))::float8 as total_cpu_time,
24+
-- Mark all parameters with ¤P¤
25+
regexp_replace(
26+
regexp_replace(
27+
regexp_replace(
28+
regexp_replace(
29+
regexp_replace(
30+
regexp_replace(query, '\s+', ' ', 'g'),
31+
'''[^'']*''', '¤P¤', 'g'
32+
),
33+
'\m\d+\.?\d*\M', '¤P¤', 'g'
34+
),
35+
'0x[0-9a-fA-F]+', '¤P¤', 'g'
36+
),
37+
'[0-9a-fA-F]{8}-[0-9a-fA-F]{4}-[0-9a-fA-F]{4}-[0-9a-fA-F]{4}-[0-9a-fA-F]{12}', '¤P¤', 'g'
38+
),
39+
'[a-zA-Z0-9._%+-]+@[a-zA-Z0-9.-]+\.[a-zA-Z]{2,}', '¤P¤', 'g'
40+
) as query_text,
41+
1 as param_num
42+
FROM pg_stat_monitor
43+
WHERE mean_exec_time > 1000
44+
),
45+
-- Recursive CTE to number parameters sequentially
46+
numbered_queries AS (
47+
-- Base case: queries to process
48+
SELECT
49+
user, datname, queryid, calls, mean_exec_time, max_exec_time,
50+
total_exec_time, rows_retrieved, total_blocks, total_cpu_time,
51+
query_text, param_num
52+
FROM base_queries
53+
54+
UNION ALL
55+
56+
-- Recursive case: replace one ¤P¤ at a time with incrementing numbers
57+
SELECT
58+
user, datname, queryid, calls, mean_exec_time, max_exec_time,
59+
total_exec_time, rows_retrieved, total_blocks, total_cpu_time,
60+
regexp_replace(query_text, '¤P¤', '$' || param_num::text, 1) as query_text,
61+
param_num + 1 as param_num
62+
FROM numbered_queries
63+
WHERE position('¤P¤' in query_text) > 0
64+
AND param_num <= 50 -- Safety limit to prevent infinite recursion
65+
),
66+
-- Get the final result (highest param_num for each query)
67+
final_queries AS (
68+
SELECT DISTINCT ON (queryid)
69+
user, datname, queryid, calls, mean_exec_time, max_exec_time,
70+
total_exec_time, rows_retrieved, total_blocks, total_cpu_time,
71+
query_text as query_pattern
72+
FROM numbered_queries
73+
ORDER BY queryid, param_num DESC
74+
)
75+
SELECT
76+
user,
77+
datname,
78+
queryid,
79+
left(query_pattern, 100) as query_pattern,
80+
calls,
81+
mean_exec_time,
82+
max_exec_time,
83+
total_exec_time,
84+
rows_retrieved,
85+
total_blocks,
86+
total_cpu_time
87+
FROM final_queries
2588
ORDER BY mean_exec_time DESC
2689
LIMIT 20;
2790
ttl: 60
@@ -37,9 +100,9 @@ slow_queries:
37100
- queryid:
38101
usage: LABEL
39102
description: Query identifier
40-
- query_text:
103+
- query_pattern:
41104
usage: LABEL
42-
description: Normalized query text (first 100 chars)
105+
description: Normalized query pattern
43106
- calls:
44107
usage: GAUGE
45108
description: Number of times this query was executed

0 commit comments

Comments
 (0)