@@ -261,6 +261,87 @@ autovacuum:
261
261
usage : " GAUGE"
262
262
description : " Number of active autovacuum processes running"
263
263
264
+ autovacuum_queue :
265
+ # https://gist.github.com/lesovsky/b0e4033380b0992789118ab35c4c323f
266
+ query : >-
267
+ WITH table_opts AS (
268
+ SELECT
269
+ c.oid, c.relname, c.relfrozenxid, c.relminmxid, n.nspname, array_to_string(c.reloptions, '') AS relopts
270
+ FROM pg_class c
271
+ INNER JOIN pg_namespace n ON c.relnamespace = n.oid
272
+ WHERE c.relkind IN ('r', 't') AND n.nspname NOT IN ('pg_catalog', 'information_schema') AND n.nspname !~ '^pg_temp'
273
+ ),
274
+ vacuum_settings AS (
275
+ SELECT
276
+ oid, relname, nspname, relfrozenxid, relminmxid,
277
+ CASE
278
+ WHEN relopts LIKE '%autovacuum_vacuum_threshold%'
279
+ THEN regexp_replace(relopts, '.*autovacuum_vacuum_threshold=([0-9.]+).*', E'\\1')::integer
280
+ ELSE current_setting('autovacuum_vacuum_threshold')::integer
281
+ END AS autovacuum_vacuum_threshold,
282
+ CASE
283
+ WHEN relopts LIKE '%autovacuum_vacuum_scale_factor%'
284
+ THEN regexp_replace(relopts, '.*autovacuum_vacuum_scale_factor=([0-9.]+).*', E'\\1')::real
285
+ ELSE current_setting('autovacuum_vacuum_scale_factor')::real
286
+ END AS autovacuum_vacuum_scale_factor,
287
+ CASE
288
+ WHEN relopts LIKE '%autovacuum_analyze_threshold%'
289
+ THEN regexp_replace(relopts, '.*autovacuum_analyze_threshold=([0-9.]+).*', E'\\1')::integer
290
+ ELSE current_setting('autovacuum_analyze_threshold')::integer
291
+ END AS autovacuum_analyze_threshold,
292
+ CASE
293
+ WHEN relopts LIKE '%autovacuum_analyze_scale_factor%'
294
+ THEN regexp_replace(relopts, '.*autovacuum_analyze_scale_factor=([0-9.]+).*', E'\\1')::real
295
+ ELSE current_setting('autovacuum_analyze_scale_factor')::real
296
+ END AS autovacuum_analyze_scale_factor,
297
+ CASE
298
+ WHEN relopts LIKE '%autovacuum_freeze_max_age%'
299
+ THEN least(regexp_replace(relopts, '.*autovacuum_freeze_max_age=([0-9.]+).*', E'\\1')::bigint,current_setting('autovacuum_freeze_max_age')::bigint)
300
+ ELSE current_setting('autovacuum_freeze_max_age')::bigint
301
+ END AS autovacuum_freeze_max_age,
302
+ CASE
303
+ WHEN relopts LIKE '%autovacuum_multixact_freeze_max_age%'
304
+ THEN least(regexp_replace(relopts, '.*autovacuum_multixact_freeze_max_age=([0-9.]+).*', E'\\1')::bigint,current_setting('autovacuum_multixact_freeze_max_age')::bigint)
305
+ ELSE current_setting('autovacuum_multixact_freeze_max_age')::bigint
306
+ END AS autovacuum_multixact_freeze_max_age
307
+ FROM table_opts
308
+ )
309
+ SELECT
310
+ current_database() as datname,
311
+ count(CASE
312
+ WHEN v.autovacuum_vacuum_threshold + (v.autovacuum_vacuum_scale_factor::numeric * c.reltuples) < s.n_dead_tup
313
+ THEN true
314
+ END) AS need_vacuum_cnt,
315
+ count(CASE
316
+ WHEN v.autovacuum_analyze_threshold + (v.autovacuum_analyze_scale_factor::numeric * c.reltuples) < s.n_mod_since_analyze
317
+ THEN true
318
+ END) AS need_analyze_cnt,
319
+ count(CASE
320
+ WHEN (age(v.relfrozenxid)::bigint > v.autovacuum_freeze_max_age) OR (mxid_age(v.relminmxid)::bigint > v.autovacuum_multixact_freeze_max_age)
321
+ THEN true
322
+ END) AS need_wraparound_cnt
323
+ FROM pg_stat_user_tables s
324
+ INNER JOIN pg_class c ON s.relid = c.oid
325
+ INNER JOIN vacuum_settings v ON c.oid = v.oid
326
+ WHERE
327
+ (v.autovacuum_vacuum_threshold + (v.autovacuum_vacuum_scale_factor::numeric * c.reltuples) < s.n_dead_tup)
328
+ OR (v.autovacuum_analyze_threshold + (v.autovacuum_analyze_scale_factor::numeric * c.reltuples) < s.n_mod_since_analyze)
329
+ OR (age(v.relfrozenxid)::bigint > v.autovacuum_freeze_max_age) OR (mxid_age(v.relminmxid)::bigint > v.autovacuum_multixact_freeze_max_age)
330
+
331
+ metrics :
332
+ - datname :
333
+ usage : " LABEL"
334
+ description : " Database name"
335
+ - need_vacuum_cnt :
336
+ usage : " GAUGE"
337
+ description : " Number of tables which need vacuum"
338
+ - need_analyze_cnt :
339
+ usage : " GAUGE"
340
+ description : " Number of tables which need analyze"
341
+ - need_wraparound_cnt :
342
+ usage : " GAUGE"
343
+ description : " Number of tables which need vacuum to prevent wraparound"
344
+
264
345
config_time :
265
346
query : " select round(extract(epoch from pg_conf_load_time()) * 1000) as conf_time"
266
347
metrics :
0 commit comments