-
Notifications
You must be signed in to change notification settings - Fork 7
/
Copy pathmonitoring-queries.json
98 lines (98 loc) · 6.81 KB
/
monitoring-queries.json
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
[
{
"query": "SELECT count(*) FROM pg_stat_activity WHERE state='idle';",
"name": "IdleConnections",
"unit": "Count",
"type": "value"
},
{
"query": "SELECT count(*) FROM pg_stat_activity WHERE state='active';",
"name": "ActiveConnections",
"unit": "Count",
"type": "value"
},
{
"query": "SELECT count(*) FROM pg_stat_activity WHERE query LIKE '%autovacuum%' AND query NOT LIKE '%pg_stat_activity%' AND state='active';",
"name": "VacuumRunning",
"unit": "Count",
"type": "value"
},
{
"query": "SELECT COUNT(*) FROM pg_stat_activity WHERE query like '%to prevent wraparound%' AND query NOT LIKE '%pg_stat_activity%' AND state='active' ;",
"name": "VacuumToPreventWraparound",
"unit": "Count",
"type": "value"
},
{
"query": "SELECT max(age(datfrozenxid)) FROM pg_database;",
"name": "DatabaseAge",
"unit": "Count",
"type": "value"
},
{
"query": "SELECT SUM(wastedbytes) FROM (SELECT distinct tablename, wastedbytes FROM (SELECT current_database(), schemaname, tablename, /*reltuples::bigint, relpages::bigint, otta,*/ ROUND((CASE WHEN otta=0 THEN 0.0 ELSE sml.relpages::FLOAT/otta END)::NUMERIC,1) AS tbloat, CASE WHEN relpages < otta THEN 0 ELSE bs*(sml.relpages-otta)::BIGINT END AS wastedbytes, iname, /*ituples::bigint, ipages::bigint, iotta,*/ ROUND((CASE WHEN iotta=0 OR ipages=0 THEN 0.0 ELSE ipages::FLOAT/iotta END)::NUMERIC,1) AS ibloat, CASE WHEN ipages < iotta THEN 0 ELSE bs*(ipages-iotta) END AS wastedibytes FROM (SELECT schemaname, tablename, cc.reltuples, cc.relpages, bs, CEIL((cc.reltuples*((datahdr+ma- (CASE WHEN datahdr%ma=0 THEN ma ELSE datahdr%ma END))+nullhdr2+4))/(bs-20::FLOAT)) AS otta, COALESCE(c2.relname,'?') AS iname, COALESCE(c2.reltuples,0) AS ituples, COALESCE(c2.relpages,0) AS ipages, COALESCE(CEIL((c2.reltuples*(datahdr-12))/(bs-20::FLOAT)),0) AS iotta FROM ( SELECT ma,bs,schemaname,tablename, (datawidth+(hdr+ma-(CASE WHEN hdr%ma=0 THEN ma ELSE hdr%ma END)))::NUMERIC AS datahdr, (maxfracsum*(nullhdr+ma-(CASE WHEN nullhdr%ma=0 THEN ma ELSE nullhdr%ma END))) AS nullhdr2 FROM ( SELECT schemaname, tablename, hdr, ma, bs, SUM((1-null_frac)*avg_width) AS datawidth, MAX(null_frac) AS maxfracsum, hdr+( SELECT 1+COUNT(*)/8 FROM pg_stats s2 WHERE null_frac<>0 AND s2.schemaname = s.schemaname AND s2.tablename = s.tablename ) AS nullhdr FROM pg_stats s, ( SELECT (SELECT current_setting('block_size')::NUMERIC) AS bs, CASE WHEN SUBSTRING(v,12,3) IN ('8.0','8.1','8.2') THEN 27 ELSE 23 END AS hdr, CASE WHEN v ~ 'mingw32' THEN 8 ELSE 4 END AS ma FROM (SELECT version() AS v) AS foo ) AS constants GROUP BY 1,2,3,4,5 ) AS foo ) AS rs JOIN pg_class cc ON cc.relname = rs.tablename JOIN pg_namespace nn ON cc.relnamespace = nn.oid AND nn.nspname = rs.schemaname AND nn.nspname <> 'information_schema' LEFT JOIN pg_index i ON indrelid = cc.oid LEFT JOIN pg_class c2 ON c2.oid = i.indexrelid ) AS sml) a) b;",
"name": "TotalTableBloat",
"unit": "Count",
"type": "value"
},
{
"query": "SELECT SUM(wastedibytes) FROM (SELECT distinct iname, wastedibytes FROM (SELECT current_database(), schemaname, tablename, /*reltuples::bigint, relpages::bigint, otta,*/ ROUND((CASE WHEN otta=0 THEN 0.0 ELSE sml.relpages::FLOAT/otta END)::NUMERIC,1) AS tbloat, CASE WHEN relpages < otta THEN 0 ELSE bs*(sml.relpages-otta)::BIGINT END AS wastedbytes, iname, /*ituples::bigint, ipages::bigint, iotta,*/ ROUND((CASE WHEN iotta=0 OR ipages=0 THEN 0.0 ELSE ipages::FLOAT/iotta END)::NUMERIC,1) AS ibloat, CASE WHEN ipages < iotta THEN 0 ELSE bs*(ipages-iotta) END AS wastedibytes FROM ( SELECT schemaname, tablename, cc.reltuples, cc.relpages, bs, CEIL((cc.reltuples*((datahdr+ma- (CASE WHEN datahdr%ma=0 THEN ma ELSE datahdr%ma END))+nullhdr2+4))/(bs-20::FLOAT)) AS otta, COALESCE(c2.relname,'?') AS iname, COALESCE(c2.reltuples,0) AS ituples, COALESCE(c2.relpages,0) AS ipages, COALESCE(CEIL((c2.reltuples*(datahdr-12))/(bs-20::FLOAT)),0) AS iotta FROM ( SELECT ma,bs,schemaname,tablename, (datawidth+(hdr+ma-(CASE WHEN hdr%ma=0 THEN ma ELSE hdr%ma END)))::NUMERIC AS datahdr, (maxfracsum*(nullhdr+ma-(CASE WHEN nullhdr%ma=0 THEN ma ELSE nullhdr%ma END))) AS nullhdr2 FROM ( SELECT schemaname, tablename, hdr, ma, bs, SUM((1-null_frac)*avg_width) AS datawidth, MAX(null_frac) AS maxfracsum, hdr+( SELECT 1+COUNT(*)/8 FROM pg_stats s2 WHERE null_frac<>0 AND s2.schemaname = s.schemaname AND s2.tablename = s.tablename ) AS nullhdr FROM pg_stats s, ( SELECT (SELECT current_setting('block_size')::NUMERIC) AS bs, CASE WHEN SUBSTRING(v,12,3) IN ('8.0','8.1','8.2') THEN 27 ELSE 23 END AS hdr, CASE WHEN v ~ 'mingw32' THEN 8 ELSE 4 END AS ma FROM (SELECT version() AS v) AS foo ) AS constants GROUP BY 1,2,3,4,5 ) AS foo ) AS rs JOIN pg_class cc ON cc.relname = rs.tablename JOIN pg_namespace nn ON cc.relnamespace = nn.oid AND nn.nspname = rs.schemaname AND nn.nspname <> 'information_schema' LEFT JOIN pg_index i ON indrelid = cc.oid LEFT JOIN pg_class c2 ON c2.oid = i.indexrelid ) AS sml) a) b;",
"name": "TotalIndexBloat",
"unit": "Count",
"type": "value"
},
{
"query": "SELECT sum(idx_blks_hit) / (sum(idx_blks_hit) + sum(idx_blks_read)) as hit_ratio FROM pg_statio_user_indexes;",
"name": "IndexHitRatio",
"unit": "Count",
"type": "value"
},
{
"query": "SELECT count(*) FROM (SELECT s.schemaname, s.relname AS tablename, s.indexrelname AS indexname, pg_size_pretty(pg_relation_size(s.indexrelid)) AS index_size FROM pg_catalog.pg_stat_user_indexes s JOIN pg_catalog.pg_index i ON s.indexrelid = i.indexrelid WHERE s.idx_scan = 0 AND 0 <>ALL (i.indkey) AND NOT EXISTS (SELECT 1 FROM pg_catalog.pg_constraint c WHERE c.conindid = s.indexrelid)) a;",
"name": "UnusedIndexes",
"unit": "Count",
"type": "value"
},
{
"query": "SELECT sum(db_size)/(1024 * 1024 * 1024) as Total_DB_Size FROM (select t1.datname AS db_name,pg_database_size(t1.datname) as db_size from pg_database t1 order by pg_database_size(t1.datname)) a;",
"name": "DBSize",
"unit": "Count",
"type": "value"
},
{
"query": "SELECT sum(n_tup_ins) FROM pg_stat_user_tables;",
"name": "TotalInsert",
"unit": "Count",
"type": "value"
},
{
"query": "SELECT sum(n_tup_upd) FROM pg_stat_user_tables;",
"name": "TotalUpdate",
"unit": "Count",
"type": "value"
},
{
"query": "SELECT sum(n_tup_del) FROM pg_stat_user_tables;",
"name": "TotalDelete",
"unit": "Count",
"type": "value"
},
{
"query": "SELECT sum(n_tup_hot_upd) FROM pg_stat_user_tables;",
"name": "TotalHotUpdate",
"unit": "Count",
"type": "value"
},
{
"query": "SELECT count(*) FROM ( SELECT pid, usename, pg_blocking_pids(pid) as blocked_by, query as blocked_query FROM pg_stat_activity WHERE cardinality(pg_blocking_pids(pid)) > 0) a;",
"name": "BlockedQueries",
"unit": "Count",
"type": "value"
},
{
"query": "SELECT sum(heap_blks_hit) / (sum(heap_blks_hit) + sum(heap_blks_read)) as hit_ratio FROM pg_statio_user_tables;",
"name": "TableHitRatio",
"unit": "Count",
"type": "value"
}
]