forked from percona/pg_stat_monitor
-
Notifications
You must be signed in to change notification settings - Fork 1
/
Copy pathpg_stat_monitor--1.0.13.sql.in
267 lines (239 loc) · 6.76 KB
/
pg_stat_monitor--1.0.13.sql.in
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
/* contrib/pg_stat_monitor/pg_stat_monitor--1.0.sql */
-- complain if script is sourced in psql, rather than via CREATE EXTENSION
\echo Use "CREATE EXTENSION pg_stat_monitor" to load this file. \quit
-- Register functions.
CREATE FUNCTION pg_stat_monitor_reset()
RETURNS void
AS 'MODULE_PATHNAME'
LANGUAGE C PARALLEL SAFE;
CREATE FUNCTION pg_stat_monitor_version()
RETURNS text
AS 'MODULE_PATHNAME'
LANGUAGE C PARALLEL SAFE;
CREATE FUNCTION get_histogram_timings()
RETURNS text
AS 'MODULE_PATHNAME'
LANGUAGE C PARALLEL SAFE;
CREATE FUNCTION range()
RETURNS text[] AS $$
SELECT string_to_array(get_histogram_timings(), ',');
$$ LANGUAGE SQL;
CREATE FUNCTION pg_stat_monitor_internal(IN showtext boolean,
OUT bucket int8, -- 0
OUT userid oid,
OUT dbid oid,
OUT client_ip int8,
OUT queryid text, -- 4
OUT planid text,
OUT query text,
OUT query_plan text,
OUT state_code int8,
OUT top_queryid text,
OUT top_query text,
OUT application_name text,
OUT bind_variables text,
OUT relations text, -- 11
OUT cmd_type int,
OUT elevel int,
OUT sqlcode TEXT,
OUT message text,
OUT bucket_start_time text,
OUT calls int8, -- 16
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_retrieved int8,
OUT plans_calls int8, -- 23
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 shared_blks_hit int8, -- 29
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 blk_read_time float8,
OUT blk_write_time float8,
OUT resp_calls text, -- 41
OUT cpu_user_time float8,
OUT cpu_sys_time float8,
OUT wal_records int8,
OUT wal_fpi int8,
OUT wal_bytes numeric,
OUT comments TEXT,
OUT toplevel BOOLEAN
)
RETURNS SETOF record
AS 'MODULE_PATHNAME', 'pg_stat_monitor'
LANGUAGE C STRICT VOLATILE PARALLEL SAFE;
CREATE FUNCTION get_state(state_code int8) RETURNS TEXT AS
$$
SELECT
CASE
WHEN state_code = 0 THEN 'PARSING'
WHEN state_code = 1 THEN 'PLANNING'
WHEN state_code = 2 THEN 'ACTIVE'
WHEN state_code = 3 THEN 'FINISHED'
WHEN state_code = 4 THEN 'FINISHED WITH ERROR'
END
$$
LANGUAGE SQL PARALLEL SAFE;
CREATE FUNCTION get_cmd_type (cmd_type INTEGER) RETURNS TEXT AS
$$
SELECT
CASE
WHEN cmd_type = 0 THEN ''
WHEN cmd_type = 1 THEN 'SELECT'
WHEN cmd_type = 2 THEN 'UPDATE'
WHEN cmd_type = 3 THEN 'INSERT'
WHEN cmd_type = 4 THEN 'DELETE'
WHEN cmd_type = 5 THEN 'UTILITY'
WHEN cmd_type = 6 THEN 'NOTHING'
END
$$
LANGUAGE SQL PARALLEL SAFE;
CREATE FUNCTION pg_stat_monitor_settings(
OUT name text,
OUT value text,
OUT default_value text,
OUT description text,
OUT minimum INTEGER,
OUT maximum INTEGER,
OUT options text,
OUT restart text
)
RETURNS SETOF record
AS 'MODULE_PATHNAME', 'pg_stat_monitor_settings'
LANGUAGE C STRICT VOLATILE PARALLEL SAFE;
CREATE VIEW pg_stat_monitor_settings AS SELECT
name,
value,
default_value,
description,
minimum,
maximum,
options,
restart
FROM pg_stat_monitor_settings();
-- Register a view on the function for ease of use.
CREATE VIEW pg_stat_monitor AS SELECT
bucket,
bucket_start_time AS bucket_start_time,
userid::regrole,
datname,
'0.0.0.0'::inet + client_ip AS client_ip,
queryid,
top_queryid,
query,
comments,
planid,
query_plan,
top_query,
application_name,
bind_variables,
string_to_array(relations, ',') AS relations,
cmd_type,
get_cmd_type(cmd_type) AS cmd_type_text,
elevel,
sqlcode,
message,
calls,
total_exec_time,
min_exec_time,
max_exec_time,
mean_exec_time,
stddev_exec_time,
rows_retrieved,
plans_calls,
total_plan_time,
min_plan_time,
max_plan_time,
mean_plan_time,
stddev_plan_time,
shared_blks_hit,
shared_blks_read,
shared_blks_dirtied,
shared_blks_written,
local_blks_hit,
local_blks_read,
local_blks_dirtied,
local_blks_written,
temp_blks_read,
temp_blks_written,
blk_read_time,
blk_write_time,
(string_to_array(resp_calls, ',')) resp_calls,
cpu_user_time,
cpu_sys_time,
wal_records,
wal_fpi,
wal_bytes,
state_code,
get_state(state_code) as state
FROM pg_stat_monitor_internal(TRUE) p, pg_database d WHERE dbid = oid
ORDER BY bucket_start_time;
CREATE FUNCTION decode_error_level(elevel int)
RETURNS text
AS
$$
SELECT
CASE
WHEN elevel = 0 THEN ''
WHEN elevel = 10 THEN 'DEBUG5'
WHEN elevel = 11 THEN 'DEBUG4'
WHEN elevel = 12 THEN 'DEBUG3'
WHEN elevel = 13 THEN 'DEBUG2'
WHEN elevel = 14 THEN 'DEBUG1'
WHEN elevel = 15 THEN 'LOG'
WHEN elevel = 16 THEN 'LOG_SERVER_ONLY'
WHEN elevel = 17 THEN 'INFO'
WHEN elevel = 18 THEN 'NOTICE'
WHEN elevel = 19 THEN 'WARNING'
WHEN elevel = 20 THEN 'ERROR'
END
$$
LANGUAGE SQL PARALLEL SAFE;
CREATE FUNCTION histogram(_bucket int, _quryid text)
RETURNS SETOF RECORD AS $$
DECLARE
rec record;
BEGIN
for rec in
with stat as (select queryid, bucket, unnest(range()) as range, unnest(resp_calls)::int freq from pg_stat_monitor) select range, freq, repeat('■', (freq::float / max(freq) over() * 30)::int) as bar from stat where queryid = _quryid and bucket = _bucket
loop
return next rec;
end loop;
END
$$ language plpgsql;
--CREATE FUNCTION pg_stat_monitor_hook_stats(
-- OUT hook text,
-- OUT min_time float8,
-- OUT max_time float8,
-- OUT total_time float8,
-- OUT ncalls int8
--)
--RETURNS SETOF record
--AS 'MODULE_PATHNAME', 'pg_stat_monitor_hook_stats'
--LANGUAGE C STRICT VOLATILE PARALLEL SAFE;
--CREATE VIEW pg_stat_monitor_hook_stats AS SELECT
-- hook,
-- min_time,
-- max_time,
-- total_time,
-- total_time / greatest(ncalls, 1) as avg_time,
-- ncalls,
-- ROUND(CAST(total_time / greatest(sum(total_time) OVER(), 0.00000001) * 100 as numeric), 2)::text || '%' as load_comparison
-- FROM pg_stat_monitor_hook_stats();
GRANT SELECT ON pg_stat_monitor TO PUBLIC;
GRANT SELECT ON pg_stat_monitor_settings TO PUBLIC;
-- Don't want this to be available to non-superusers.
REVOKE ALL ON FUNCTION pg_stat_monitor_reset() FROM PUBLIC;