forked from NikolayS/postgres_dba
-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy paths2_pg_stat_statements_report.sql
321 lines (319 loc) · 14.7 KB
/
s2_pg_stat_statements_report.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
--Slowest queries report (requires pg_stat_statements)
--Original version – Data Egret: https://github.com/dataegret/pg-utils/blob/master/sql/global_reports/query_stat_total.sql
\if :postgres_dba_pgvers_13plus
with pg_stat_statements_slice as (
select *
from pg_stat_statements
-- if current database is postgres then generate report for all databases,
-- otherwise generate for current database only
where
current_database() = 'postgres'
or dbid = (
select oid
from pg_database
where datname = current_database()
)
), pg_stat_statements_normalized as (
select
*,
translate(
regexp_replace(
regexp_replace(
regexp_replace(
regexp_replace(
query,
e'\\?(::[a-zA-Z_]+)?( *, *\\?(::[a-zA-Z_]+)?)+', '?', 'g'
),
e'\\$[0-9]+(::[a-zA-Z_]+)?( *, *\\$[0-9]+(::[a-zA-Z_]+)?)*', '$N', 'g'
),
e'--.*$', '', 'ng'
),
e'/\\*.*?\\*/', '', 'g'
),
e'\r', ''
) as query_normalized
from pg_stat_statements_slice
), totals as (
select
sum(total_exec_time) as total_exec_time,
sum(blk_read_time+blk_write_time) as io_time,
sum(total_exec_time-blk_read_time-blk_write_time) as non_io_time,
sum(calls) as ncalls,
sum(rows) as total_rows
from pg_stat_statements_slice
), _pg_stat_statements as (
select
(select datname from pg_database where oid = p.dbid) as database,
(select rolname from pg_roles where oid = p.userid) as username,
--select shortest query, replace \n\n-- strings to avoid email clients format text as footer
substring(
translate(
replace(
(array_agg(query order by length(query)))[1],
e'-- \n',
e'--\n'
),
e'\r', ''
),
1,
8192
) as query,
sum(total_exec_time) as total_exec_time,
sum(blk_read_time) as blk_read_time, sum(blk_write_time) as blk_write_time,
sum(calls) as calls, sum(rows) as rows
from pg_stat_statements_normalized p
group by dbid, userid, md5(query_normalized)
), totals_readable as (
select
to_char(interval '1 millisecond' * total_exec_time, 'HH24:MI:SS') as total_exec_time,
(100*io_time/total_exec_time)::numeric(20,2) as io_time_percent,
to_char(ncalls, 'FM999,999,999,990') as total_queries,
(select to_char(count(distinct md5(query)), 'FM999,999,990') from _pg_stat_statements) as unique_queries
from totals
), statements as (
select
(100*total_exec_time/(select total_exec_time from totals)) as time_percent,
(100*(blk_read_time+blk_write_time)/(select greatest(io_time, 1) from totals)) as io_time_percent,
(100*(total_exec_time-blk_read_time-blk_write_time)/(select non_io_time from totals)) as non_io_time_percent,
to_char(interval '1 millisecond' * total_exec_time, 'HH24:MI:SS') as total_exec_time,
(total_exec_time::numeric/calls)::numeric(20,2) as avg_time,
((total_exec_time-blk_read_time-blk_write_time)::numeric/calls)::numeric(20, 2) as avg_non_io_time,
((blk_read_time+blk_write_time)::numeric/calls)::numeric(20, 2) as avg_io_time,
to_char(calls, 'FM999,999,999,990') as calls,
(100*calls/(select ncalls from totals))::numeric(20, 2) as calls_percent,
to_char(rows, 'FM999,999,999,990') as rows,
(100*rows/(select total_rows from totals))::numeric(20, 2) as row_percent,
database,
username,
query
from _pg_stat_statements
where
(total_exec_time-blk_read_time-blk_write_time)/(select non_io_time from totals) >= 0.01
or (blk_read_time+blk_write_time)/(
select greatest(io_time, 1) from totals
) >= 0.01
or calls/(select ncalls from totals) >= 0.02
or rows/(select total_rows from totals) >= 0.02
union all
select
(100*sum(total_exec_time)::numeric/(select total_exec_time from totals)) as time_percent,
(100*sum(blk_read_time+blk_write_time)::numeric/(select greatest(io_time, 1) from totals)) as io_time_percent,
(100*sum(total_exec_time-blk_read_time-blk_write_time)::numeric/(select non_io_time from totals)) as non_io_time_percent,
to_char(interval '1 millisecond' * sum(total_exec_time), 'HH24:MI:SS') as total_exec_time,
(sum(total_exec_time)::numeric/sum(calls))::numeric(20,2) as avg_time,
(sum(total_exec_time-blk_read_time-blk_write_time)::numeric/sum(calls))::numeric(20, 2) as avg_non_io_time,
(sum(blk_read_time+blk_write_time)::numeric/sum(calls))::numeric(20, 2) as avg_io_time,
to_char(sum(calls), 'FM999,999,999,990') as calls,
(100*sum(calls)/(select ncalls from totals))::numeric(20, 2) as calls_percent,
to_char(sum(rows), 'FM999,999,999,990') as rows,
(100*sum(rows)/(select total_rows from totals))::numeric(20, 2) as row_percent,
'all' as database,
'all' as username,
'other' as query
from _pg_stat_statements
where
not (
(total_exec_time-blk_read_time-blk_write_time)/(select non_io_time from totals) >= 0.01
or (blk_read_time+blk_write_time)/(select greatest(io_time, 1) from totals) >= 0.01
or calls/(select ncalls from totals)>=0.02 or rows/(select total_rows from totals) >= 0.02
)
), statements_readable as (
select row_number() over (order by s.time_percent desc) as pos,
to_char(time_percent, 'FM990.0') || '%' as time_percent,
to_char(io_time_percent, 'FM990.0') || '%' as io_time_percent,
to_char(non_io_time_percent, 'FM990.0') || '%' as non_io_time_percent,
to_char(avg_io_time*100/(coalesce(nullif(avg_time, 0), 1)), 'FM990.0') || '%' as avg_io_time_percent,
total_exec_time, avg_time, avg_non_io_time, avg_io_time, calls, calls_percent, rows, row_percent,
database, username, query
from statements s
where calls is not null
)
select
e'total time:\t' || total_exec_time || ' (IO: ' || io_time_percent || E'%)\n'
|| e'total queries:\t' || total_queries || ' (unique: ' || unique_queries || E')\n'
|| 'report for ' || (select case when current_database() = 'postgres' then 'all databases' else current_database() || ' database' end)
|| E', version b0.9.6'
|| ' @ PostgreSQL '
|| (select setting from pg_settings where name='server_version') || E'\ntracking '
|| (select setting from pg_settings where name='pg_stat_statements.track') || ' '
|| (select setting from pg_settings where name='pg_stat_statements.max') || ' queries, utilities '
|| (select setting from pg_settings where name='pg_stat_statements.track_utility')
|| ', logging ' || (select (case when setting = '0' then 'all' when setting = '-1' then 'none' when setting::int > 1000 then (setting::numeric/1000)::numeric(20, 1) || 's+' else setting || 'ms+' end) from pg_settings where name='log_min_duration_statement')
|| E' queries\n'
|| (
select coalesce(string_agg('WARNING: database ' || datname || ' must be vacuumed within ' || to_char(2147483647 - age(datfrozenxid), 'FM999,999,999,990') || ' transactions', E'\n' order by age(datfrozenxid) desc) || E'\n', '')
from pg_database where (2147483647 - age(datfrozenxid)) < 200000000
) || E'\n'
from totals_readable
union all
(
select
e'=============================================================================================================\n'
|| 'pos:' || pos || E'\t total time: ' || total_exec_time || ' (' || time_percent
|| ', IO: ' || io_time_percent || ', Non-IO: ' || non_io_time_percent || E')\t calls: '
|| calls || ' (' || calls_percent || E'%)\t avg_time: ' || avg_time
|| 'ms (IO: ' || avg_io_time_percent || E')\n' || 'user: '
|| username || E'\t db: ' || database || E'\t rows: ' || rows
|| ' (' || row_percent || '%)' || E'\t query:\n' || query || E'\n'
from statements_readable
order by pos
);
\else
with pg_stat_statements_slice as (
select *
from pg_stat_statements
-- if current database is postgres then generate report for all databases,
-- otherwise generate for current database only
where
current_database() = 'postgres'
or dbid = (
select oid
from pg_database
where datname = current_database()
)
), pg_stat_statements_normalized as (
select
*,
translate(
regexp_replace(
regexp_replace(
regexp_replace(
regexp_replace(
query,
e'\\?(::[a-zA-Z_]+)?( *, *\\?(::[a-zA-Z_]+)?)+', '?', 'g'
),
e'\\$[0-9]+(::[a-zA-Z_]+)?( *, *\\$[0-9]+(::[a-zA-Z_]+)?)*', '$N', 'g'
),
e'--.*$', '', 'ng'
),
e'/\\*.*?\\*/', '', 'g'
),
e'\r', ''
) as query_normalized
from pg_stat_statements_slice
), totals as (
select
sum(total_time) as total_time,
sum(blk_read_time+blk_write_time) as io_time,
sum(total_time-blk_read_time-blk_write_time) as non_io_time,
sum(calls) as ncalls,
sum(rows) as total_rows
from pg_stat_statements_slice
), _pg_stat_statements as (
select
(select datname from pg_database where oid = p.dbid) as database,
(select rolname from pg_roles where oid = p.userid) as username,
--select shortest query, replace \n\n-- strings to avoid email clients format text as footer
substring(
translate(
replace(
(array_agg(query order by length(query)))[1],
e'-- \n',
e'--\n'
),
e'\r', ''
),
1,
8192
) as query,
sum(total_time) as total_time,
sum(blk_read_time) as blk_read_time, sum(blk_write_time) as blk_write_time,
sum(calls) as calls, sum(rows) as rows
from pg_stat_statements_normalized p
group by dbid, userid, md5(query_normalized)
), totals_readable as (
select
to_char(interval '1 millisecond' * total_time, 'HH24:MI:SS') as total_time,
(100*io_time/total_time)::numeric(20,2) as io_time_percent,
to_char(ncalls, 'FM999,999,999,990') as total_queries,
(select to_char(count(distinct md5(query)), 'FM999,999,990') from _pg_stat_statements) as unique_queries
from totals
), statements as (
select
(100*total_time/(select total_time from totals)) as time_percent,
(100*(blk_read_time+blk_write_time)/(select greatest(io_time, 1) from totals)) as io_time_percent,
(100*(total_time-blk_read_time-blk_write_time)/(select non_io_time from totals)) as non_io_time_percent,
to_char(interval '1 millisecond' * total_time, 'HH24:MI:SS') as total_time,
(total_time::numeric/calls)::numeric(20,2) as avg_time,
((total_time-blk_read_time-blk_write_time)::numeric/calls)::numeric(20, 2) as avg_non_io_time,
((blk_read_time+blk_write_time)::numeric/calls)::numeric(20, 2) as avg_io_time,
to_char(calls, 'FM999,999,999,990') as calls,
(100*calls/(select ncalls from totals))::numeric(20, 2) as calls_percent,
to_char(rows, 'FM999,999,999,990') as rows,
(100*rows/(select total_rows from totals))::numeric(20, 2) as row_percent,
database,
username,
query
from _pg_stat_statements
where
(total_time-blk_read_time-blk_write_time)/(select non_io_time from totals) >= 0.01
or (blk_read_time+blk_write_time)/(
select greatest(io_time, 1) from totals
) >= 0.01
or calls/(select ncalls from totals) >= 0.02
or rows/(select total_rows from totals) >= 0.02
union all
select
(100*sum(total_time)::numeric/(select total_time from totals)) as time_percent,
(100*sum(blk_read_time+blk_write_time)::numeric/(select greatest(io_time, 1) from totals)) as io_time_percent,
(100*sum(total_time-blk_read_time-blk_write_time)::numeric/(select non_io_time from totals)) as non_io_time_percent,
to_char(interval '1 millisecond' * sum(total_time), 'HH24:MI:SS') as total_time,
(sum(total_time)::numeric/sum(calls))::numeric(20,2) as avg_time,
(sum(total_time-blk_read_time-blk_write_time)::numeric/sum(calls))::numeric(20, 2) as avg_non_io_time,
(sum(blk_read_time+blk_write_time)::numeric/sum(calls))::numeric(20, 2) as avg_io_time,
to_char(sum(calls), 'FM999,999,999,990') as calls,
(100*sum(calls)/(select ncalls from totals))::numeric(20, 2) as calls_percent,
to_char(sum(rows), 'FM999,999,999,990') as rows,
(100*sum(rows)/(select total_rows from totals))::numeric(20, 2) as row_percent,
'all' as database,
'all' as username,
'other' as query
from _pg_stat_statements
where
not (
(total_time-blk_read_time-blk_write_time)/(select non_io_time from totals) >= 0.01
or (blk_read_time+blk_write_time)/(select greatest(io_time, 1) from totals) >= 0.01
or calls/(select ncalls from totals)>=0.02 or rows/(select total_rows from totals) >= 0.02
)
), statements_readable as (
select row_number() over (order by s.time_percent desc) as pos,
to_char(time_percent, 'FM990.0') || '%' as time_percent,
to_char(io_time_percent, 'FM990.0') || '%' as io_time_percent,
to_char(non_io_time_percent, 'FM990.0') || '%' as non_io_time_percent,
to_char(avg_io_time*100/(coalesce(nullif(avg_time, 0), 1)), 'FM990.0') || '%' as avg_io_time_percent,
total_time, avg_time, avg_non_io_time, avg_io_time, calls, calls_percent, rows, row_percent,
database, username, query
from statements s
where calls is not null
)
select
e'total time:\t' || total_time || ' (IO: ' || io_time_percent || E'%)\n'
|| e'total queries:\t' || total_queries || ' (unique: ' || unique_queries || E')\n'
|| 'report for ' || (select case when current_database() = 'postgres' then 'all databases' else current_database() || ' database' end)
|| E', version b0.9.6'
|| ' @ PostgreSQL '
|| (select setting from pg_settings where name='server_version') || E'\ntracking '
|| (select setting from pg_settings where name='pg_stat_statements.track') || ' '
|| (select setting from pg_settings where name='pg_stat_statements.max') || ' queries, utilities '
|| (select setting from pg_settings where name='pg_stat_statements.track_utility')
|| ', logging ' || (select (case when setting = '0' then 'all' when setting = '-1' then 'none' when setting::int > 1000 then (setting::numeric/1000)::numeric(20, 1) || 's+' else setting || 'ms+' end) from pg_settings where name='log_min_duration_statement')
|| E' queries\n'
|| (
select coalesce(string_agg('WARNING: database ' || datname || ' must be vacuumed within ' || to_char(2147483647 - age(datfrozenxid), 'FM999,999,999,990') || ' transactions', E'\n' order by age(datfrozenxid) desc) || E'\n', '')
from pg_database where (2147483647 - age(datfrozenxid)) < 200000000
) || E'\n'
from totals_readable
union all
(
select
e'=============================================================================================================\n'
|| 'pos:' || pos || E'\t total time: ' || total_time || ' (' || time_percent
|| ', IO: ' || io_time_percent || ', Non-IO: ' || non_io_time_percent || E')\t calls: '
|| calls || ' (' || calls_percent || E'%)\t avg_time: ' || avg_time
|| 'ms (IO: ' || avg_io_time_percent || E')\n' || 'user: '
|| username || E'\t db: ' || database || E'\t rows: ' || rows
|| ' (' || row_percent || '%)' || E'\t query:\n' || query || E'\n'
from statements_readable
order by pos
);
\endif