├── LICENSE ├── PostgreSQL ├── 10 │ └── userparameter_postgresql.conf ├── 9.6 │ └── userparameter_postgresql.conf ├── README.md └── Template_PostgreSQL.xml ├── README.md ├── pgBarman └── README.md └── pgBouncer └── README.md /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2018 2ndQuadrant 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /PostgreSQL/10/userparameter_postgresql.conf: -------------------------------------------------------------------------------- 1 | # On Postgres terminal, create the "pg_buffercache" extension: 2 | # postgres=# CREATE EXTENSION pg_buffercache; 3 | # CREATE EXTENSION 4 | # Note: You should create the extension for you own database. Example: 5 | # postgres=# \c zabbix 6 | # You are now connected to database "zabbix" as user "postgres". 7 | # zabbix=# create extension pg_buffercache; 8 | # CREATE EXTENSION 9 | # zabbix=# 10 | 11 | # EXTERNAL EXTENSIONS # 12 | UserParameter=pgsql.buffercache.clear[*],psql -qAtX $1 -c "select count(*) from pg_buffercache where not isdirty" 13 | UserParameter=pgsql.buffercache.dirty[*],psql -qAtX $1 -c "select count(*) from pg_buffercache where isdirty" 14 | UserParameter=pgsql.buffercache.used[*],psql -qAtX $1 -c "select count(*) from pg_buffercache where reldatabase is not null" 15 | UserParameter=pgsql.buffercache.total[*],psql -qAtX $1 -c "select count(*) from pg_buffercache" 16 | 17 | # Database Discovery 18 | UserParameter=pgsql.db.discovery[*],/bin/echo -n '{"data":['; for db in $(psql -qAtX $1 -c "select datname from pg_database where not datistemplate and datallowconn and datname!='postgres'"); do /bin/echo -n "{\"{#DBNAME}\": \"$db\"},"; done |sed -e 's:,$::'; /bin/echo -n ']}' 19 | 20 | # Database Statistics 21 | UserParameter=pgsql.db.size[*],psql -qAtX $1 -c "select pg_database_size('$2')" 22 | UserParameter=pgsql.db.autovac_freeze[*],psql -qAtX $1 -c "SELECT txns, ROUND(100*(txns/freez::float)) AS perc FROM (SELECT foo.freez::int, age(datfrozenxid) AS txns FROM pg_database d JOIN (SELECT setting AS freez FROM pg_settings WHERE name = 'autovacuum_freeze_max_age') AS foo ON (true) WHERE d.datallowconn AND datname = '$2') AS foo2;" | awk -F\| '{printf("{\"{#DBNAME}\":\"$2\", \"TXNS\":\"%d\", \"TXNS_PERCENT\":\"%d\"}", $$1, $$2)}' 23 | 24 | # GENERAL INFORMATION # 25 | UserParameter=pgsql.ping[*],/bin/echo -e "\\\timing \n select 1" | psql -qAtX $1 | tail -n 1 |cut -d' ' -f2 26 | UserParameter=pgsql.uptime[*],psql -qAtX $1 -c "select date_part('epoch', now() - pg_postmaster_start_time())::int" 27 | UserParameter=pgsql.cache.hit[*],psql -qAtX $1 -c "select round(sum(blks_hit)*100/sum(blks_hit+blks_read), 2) from pg_stat_database" 28 | UserParameter=pgsql.version[*],psql -qAtX $1 -c "SELECT version() AS pg_version" 29 | 30 | # OTHER INFORMATION # 31 | UserParameter=pgsql.table.tuples[*],psql -qAtX $1 -d $2 -c "select count(*) from $3" 32 | UserParameter=pgsql.setting[*],psql -qAtX $1 -c "select current_setting('$2')" 33 | UserParameter=pgsql.trigger[*],psql -qAtX $1 -c "select count(*) from pg_trigger where tgenabled='O' and tgname='$2'" 34 | UserParameter=pgsql.wal.write[*],psql -qAtX $1 -c "select pg_xlog_location_diff(pg_current_xlog_location(),'0/00000000')" 35 | UserParameter=pgsql.wal.count[*],psql -qAtX $1 -c "select count(*) from pg_ls_dir('pg_xlog')" 36 | 37 | # BACKGROUND WRITER STATS # 38 | UserParameter=pgsql.bgwriter.checkpoints_timed[*],psql -qAtX $1 -c "select checkpoints_timed from pg_stat_bgwriter" 39 | UserParameter=pgsql.bgwriter.checkpoints_req[*],psql -qAtX $1 -c "select checkpoints_req from pg_stat_bgwriter" 40 | UserParameter=pgsql.bgwriter.checkpoint_write_time[*],psql -qAtX $1 -c "select checkpoint_write_time from pg_stat_bgwriter" 41 | UserParameter=pgsql.bgwriter.checkpoint_sync_time[*],psql -qAtX $1 -c "select checkpoint_sync_time from pg_stat_bgwriter" 42 | UserParameter=pgsql.bgwriter.buffers_checkpoint[*],psql -qAtX $1 -c "select buffers_checkpoint from pg_stat_bgwriter" 43 | UserParameter=pgsql.bgwriter.buffers_clean[*],psql -qAtX $1 -c "select buffers_clean from pg_stat_bgwriter" 44 | UserParameter=pgsql.bgwriter.maxwritten_clean[*],psql -qAtX $1 -c "select maxwritten_clean from pg_stat_bgwriter" 45 | UserParameter=pgsql.bgwriter.buffers_backend[*],psql -qAtX $1 -c "select buffers_backend from pg_stat_bgwriter" 46 | UserParameter=pgsql.bgwriter.buffers_backend_fsync[*],psql -qAtX $1 -c "select buffers_backend_fsync from pg_stat_bgwriter" 47 | UserParameter=pgsql.bgwriter.buffers_alloc[*],psql -qAtX $1 -c "select buffers_alloc from pg_stat_bgwriter" 48 | 49 | # CONNECTIONS # 50 | UserParameter=pgsql.connections.active[*],psql -qAtX $1 -c "select count(*) from pg_stat_activity where state = 'active'" 51 | UserParameter=pgsql.connections.idle[*],psql -qAtX $1 -c "select count(*) from pg_stat_activity where state = 'idle'" 52 | UserParameter=pgsql.connections.idle_in_transaction[*],psql -qAtX $1 -c "select count(*) from pg_stat_activity where state = 'idle in transaction'" 53 | UserParameter=pgsql.connections.total[*],psql -qAtX $1 -c "select count(*) from pg_stat_activity" 54 | UserParameter=pgsql.connections.total_pct[*],psql -qAtX $1 -c "select count(*)*100/(select current_setting('max_connections')::int) from pg_stat_activity" 55 | UserParameter=pgsql.connections.waiting[*],psql -qAtX $1 -c "select count(*) from pg_stat_activity WHERE backend_type = 'client backend' AND state != 'idle' AND wait_event IS NOT NULL;" 56 | UserParameter=pgsql.connections.prepared[*],psql -qAtX $1 -c "select count(*) from pg_prepared_xacts" 57 | 58 | # TRANSACTIONS # 59 | UserParameter=pgsql.transactions.idle[*],psql -qAtX $1 -c "select coalesce(extract(epoch from max(age(now(), query_start))), 0) from pg_stat_activity where state='idle in transaction'" 60 | UserParameter=pgsql.transactions.active[*],psql -qAtX $1 -c "select coalesce(extract(epoch from max(age(now(), query_start))), 0) from pg_stat_activity where state <> 'idle in transaction' and state <> 'idle'" 61 | UserParameter=pgsql.transactions.waiting[*],psql -qAtX $1 -c "select coalesce(extract(epoch from max(age(now(), query_start))), 0) from pg_stat_activity WHERE backend_type = 'client backend' AND state != 'idle' AND wait_event IS NOT NULL" 62 | UserParameter=pgsql.transactions.prepared[*],psql -qAtX $1 -c "select coalesce(extract(epoch from max(age(now(), prepared))), 0) from pg_prepared_xacts" 63 | UserParameter=pgsql.pgstatstatements.avg_query_time[*],psql -qAtX $1 -c "select round((sum(total_time) / sum(calls))::numeric,2) from pg_stat_statements" 64 | 65 | # SUMMARY DATABASE STATS # 66 | UserParameter=pgsql.dbstat.sum.numbackends[*],psql -qAtX $1 -c "select sum(numbackends) from pg_stat_database" 67 | UserParameter=pgsql.dbstat.sum.xact_commit[*],psql -qAtX $1 -c "select sum(xact_commit) from pg_stat_database" 68 | UserParameter=pgsql.dbstat.sum.xact_rollback[*],psql -qAtX $1 -c "select sum(xact_rollback) from pg_stat_database" 69 | UserParameter=pgsql.dbstat.sum.blks_read[*],psql -qAtX $1 -c "select sum(blks_read) from pg_stat_database" 70 | UserParameter=pgsql.dbstat.sum.blks_hit[*],psql -qAtX $1 -c "select sum(blks_hit) from pg_stat_database" 71 | UserParameter=pgsql.dbstat.sum.tup_returned[*],psql -qAtX $1 -c "select sum(tup_returned) from pg_stat_database" 72 | UserParameter=pgsql.dbstat.sum.tup_fetched[*],psql -qAtX $1 -c "select sum(tup_fetched) from pg_stat_database" 73 | UserParameter=pgsql.dbstat.sum.tup_inserted[*],psql -qAtX $1 -c "select sum(tup_inserted) from pg_stat_database" 74 | UserParameter=pgsql.dbstat.sum.tup_updated[*],psql -qAtX $1 -c "select sum(tup_updated) from pg_stat_database" 75 | UserParameter=pgsql.dbstat.sum.tup_deleted[*],psql -qAtX $1 -c "select sum(tup_deleted) from pg_stat_database" 76 | UserParameter=pgsql.dbstat.sum.conflicts[*],psql -qAtX $1 -c "select sum(conflicts) from pg_stat_database" 77 | UserParameter=pgsql.dbstat.sum.temp_files[*],psql -qAtX $1 -c "select sum(temp_files) from pg_stat_database" 78 | UserParameter=pgsql.dbstat.sum.temp_bytes[*],psql -qAtX $1 -c "select sum(temp_bytes) from pg_stat_database" 79 | UserParameter=pgsql.dbstat.sum.deadlocks[*],psql -qAtX $1 -c "select sum(deadlocks) from pg_stat_database" 80 | 81 | # SPECIFIED DATABASE STATS - TODO: CREATE LLD # 82 | UserParameter=pgsql.dbstat.numbackends[*],psql -qAtX $1 -c "select numbackends from pg_stat_database where datname = '$2'" 83 | UserParameter=pgsql.dbstat.xact_commit[*],psql -qAtX $1 -c "select xact_commit from pg_stat_database where datname = '$2'" 84 | UserParameter=pgsql.dbstat.xact_rollback[*],psql -qAtX $1 -c "select xact_rollback from pg_stat_database where datname = '$2'" 85 | UserParameter=pgsql.dbstat.blks_read[*],psql -qAtX $1 -c "select blks_read from pg_stat_database where datname = '$2'" 86 | UserParameter=pgsql.dbstat.blks_hit[*],psql -qAtX $1 -c "select blks_hit from pg_stat_database where datname = '$2'" 87 | UserParameter=pgsql.dbstat.tup_returned[*],psql -qAtX $1 -c "select tup_returned from pg_stat_database where datname = '$2'" 88 | UserParameter=pgsql.dbstat.tup_fetched[*],psql -qAtX $1 -c "select tup_fetched from pg_stat_database where datname = '$2'" 89 | UserParameter=pgsql.dbstat.tup_inserted[*],psql -qAtX $1 -c "select tup_inserted from pg_stat_database where datname = '$2'" 90 | UserParameter=pgsql.dbstat.tup_updated[*],psql -qAtX $1 -c "select tup_updated from pg_stat_database where datname = '$2'" 91 | UserParameter=pgsql.dbstat.tup_deleted[*],psql -qAtX $1 -c "select tup_deleted from pg_stat_database where datname = '$2'" 92 | UserParameter=pgsql.dbstat.conflicts[*],psql -qAtX $1 -c "select conflicts from pg_stat_database where datname = '$2'" 93 | UserParameter=pgsql.dbstat.temp_files[*],psql -qAtX $1 -c "select temp_files from pg_stat_database where datname = '$2'" 94 | UserParameter=pgsql.dbstat.temp_bytes[*],psql -qAtX $1 -c "select temp_bytes from pg_stat_database where datname = '$2'" 95 | UserParameter=pgsql.dbstat.deadlocks[*],psql -qAtX $1 -c "select deadlocks from pg_stat_database where datname = '$2'" 96 | 97 | # DATABASE/TABLE/INDEXES SIZE - TODO: CREATE LLD # 98 | UserParameter=pgsql.table.size[*],psql -qAtX $1 -d $2 -c "select pg_relation_size('$3')" 99 | UserParameter=pgsql.index.size[*],psql -qAtX $1 -d $2 -c "select pg_total_relation_size('$3') - pg_relation_size('$3')" 100 | 101 | # TABLE STATS # 102 | UserParameter=pgsql.table.stat.heap_blks_read[*],psql -qAtX $1 -d $2 -c "select coalesce(heap_blks_read,0) from pg_statio_user_tables where (schemaname || '.' || relname) = '$3'" 103 | UserParameter=pgsql.table.stat.heap_blks_hit[*],psql -qAtX $1 -d $2 -c "select coalesce(heap_blks_hit,0) from pg_statio_user_tables where (schemaname || '.' || relname) = '$3'" 104 | UserParameter=pgsql.table.stat.idx_blks_read[*],psql -qAtX $1 -d $2 -c "select coalesce(idx_blks_read,0) from pg_statio_user_tables where (schemaname || '.' || relname) = '$3'" 105 | UserParameter=pgsql.table.stat.idx_blks_hit[*],psql -qAtX $1 -d $2 -c "select coalesce(idx_blks_hit,0) from pg_statio_user_tables where (schemaname || '.' || relname) = '$3'" 106 | UserParameter=pgsql.table.stat.toast_blks_read[*],psql -qAtX $1 -d $2 -c "select coalesce(toast_blks_read,0) from pg_statio_user_tables where (schemaname || '.' || relname) = '$3'" 107 | UserParameter=pgsql.table.stat.toast_blks_hit[*],psql -qAtX $1 -d $2 -c "select coalesce(toast_blks_hit,0) from pg_statio_user_tables where (schemaname || '.' || relname) = '$3'" 108 | UserParameter=pgsql.table.stat.tidx_blks_read[*],psql -qAtX $1 -d $2 -c "select coalesce(tidx_blks_read,0) from pg_statio_user_tables where (schemaname || '.' || relname) = '$3'" 109 | UserParameter=pgsql.table.stat.tidx_blks_hit[*],psql -qAtX $1 -d $2 -c "select coalesce(tidx_blks_hit,0) from pg_statio_user_tables where (schemaname || '.' || relname) = '$3'" 110 | UserParameter=pgsql.table.stat.seq_scan[*],psql -qAtX $1 -d $2 -c "select coalesce(seq_scan,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 111 | UserParameter=pgsql.table.stat.seq_tup_read[*],psql -qAtX $1 -d $2 -c "select coalesce(seq_tup_read,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 112 | UserParameter=pgsql.table.stat.idx_scan[*],psql -qAtX $1 -d $2 -c "select coalesce(idx_scan,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 113 | UserParameter=pgsql.table.stat.idx_tup_fetch[*],psql -qAtX $1 -d $2 -c "select coalesce(idx_tup_fetch,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 114 | UserParameter=pgsql.table.stat.n_tup_ins[*],psql -qAtX $1 -d $2 -c "select coalesce(n_tup_ins,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 115 | UserParameter=pgsql.table.stat.n_tup_del[*],psql -qAtX $1 -d $2 -c "select coalesce(n_tup_del,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 116 | UserParameter=pgsql.table.stat.n_tup_upd[*],psql -qAtX $1 -d $2 -c "select coalesce(n_tup_upd,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 117 | UserParameter=pgsql.table.stat.n_tup_hot_upd[*],psql -qAtX $1 -d $2 -c "select coalesce(n_tup_hot_upd,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 118 | UserParameter=pgsql.table.stat.n_live_tup[*],psql -qAtX $1 -d $2 -c "select coalesce(n_live_tup,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 119 | UserParameter=pgsql.table.stat.n_dead_tup[*],psql -qAtX $1 -d $2 -c "select coalesce(n_dead_tup,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 120 | UserParameter=pgsql.table.stat.vacuum_count[*],psql -qAtX $1 -d $2 -c "select coalesce(vacuum_count,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 121 | UserParameter=pgsql.table.stat.autovacuum_count[*],psql -qAtX $1 -d $2 -c "select coalesce(autovacuum_count,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 122 | UserParameter=pgsql.table.stat.analyze_count[*],psql -qAtX $1 -d $2 -c "select coalesce(analyze_count,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 123 | UserParameter=pgsql.table.stat.autoanalyze_count[*],psql -qAtX $1 -d $2 -c "select coalesce(autoanalyze_count,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 124 | 125 | # Streaming Discovery 126 | UserParameter=pgsql.streaming.discovery[*],/bin/echo -n '{"data":['; for replica in $(psql -qAtX $1 -c "select client_addr from pg_stat_replication"); do /bin/echo -n "{\"{#HOTSTANDBY}\": \"$replica\"},"; done |sed -e 's:,$::'; /bin/echo -n ']}' 127 | 128 | # STREAMING REPLICATION # 129 | UserParameter=pgsql.packet_loss[*],ping -W 2 -q -n -c 10 $1 | grep "packet loss" | cut -d " " -f 6 | cut -d "%" -f1 130 | UserParameter=pgsql.streaming.count[*],psql -qAtX $1 -c "select count(*) from pg_stat_replication" 131 | UserParameter=pgsql.streaming.state[*],psql -qAtX $1 -c "select pg_is_in_recovery()" 132 | UserParameter=pgsql.streaming.lag.bytes[*],psql -qAtX $1 -c "select greatest(0,pg_wal_lsn_diff(pg_current_wal_lsn(), replay_lsn)) from pg_stat_replication where client_addr = '$2'" 133 | UserParameter=pgsql.streaming.lag.seconds[*],psql -qAtX -h 127.0.0.1 $1 -c "SELECT EXTRACT(EPOCH FROM replay_lag)::INTEGER FROM pg_stat_replication where client_addr = '$2';" 134 | 135 | # Table Discovery 136 | UserParameter=pgsql.table.discovery[*],/bin/echo -n '{"data":['; for db in $(psql -qAtX $1 -c "select datname from pg_database where not datistemplate and datallowconn and datname!='postgres'"); do for table in $(psql -qAtX -F. $1 -d $db -c "select n.nspname,c.relname from pg_catalog.pg_class c left join pg_catalog.pg_namespace n on n.oid = c.relnamespace where c.relkind in ('r','s','') and n.nspname not in ('^pg_toast','information_schema','pg_catalog')"); do /bin/echo -n "{\"{#DBNAME}\": \"$db\", \"{#TABLENAME}\": \"$table\"},"; done; done | sed -e 's:\},$:\}:'; /bin/echo -n ']}' 137 | 138 | # Bloat: Top 10 Tables 139 | UserParameter=pgsql.table.bloat.discovery[*],/bin/echo -n '{"data":['; for table in $(psql -qAtX -F. $1 -d $2 -c "SELECT nspname || '.' || relname FROM pg_class c LEFT JOIN pg_namespace n ON n.oid = c.relnamespace LEFT JOIN LATERAL pgstattuple_approx(nspname || '.' || relname ) b ON true WHERE relkind IN ( 'r' ) AND ( approx_free_space >= $3 AND approx_free_percent >= $4 ) AND NOT pg_is_in_recovery();" ); do /bin/echo -n "{\"{#DBNAME}\": \"$2\", \"{#TABLENAME}\": \"$table\"},"; done | sed -e 's:\},$:\}:'; /bin/echo -n ']}' 140 | UserParameter=pgsql.table.bloat.values[*],psql -qAtX $1 -d $2 -c "SELECT * FROM pgstattuple_approx('$3');" | awk -F\| '{printf("{\"{#TABLENAME}\":\"$3\", \"APPROX_FREE_PERCENT\":\"%.2f\", \"APPROX_DEAD_TUPLE_PERCENT\":\"%.2f\", \"TABLE_LEN\":\"%d\", \"APPROX_FREE_SPACE\":\"%d\", \"SCANNED_PERCENT\":\"%.2f\"}",$$10, $$8, $$1, $$9, $$2)}' 141 | -------------------------------------------------------------------------------- /PostgreSQL/9.6/userparameter_postgresql.conf: -------------------------------------------------------------------------------- 1 | # On Postgres terminal, create the "pg_buffercache" extension: 2 | # postgres=# CREATE EXTENSION pg_buffercache; 3 | # CREATE EXTENSION 4 | # Note: You should create the extension for you own database. Example: 5 | # postgres=# \c zabbix 6 | # You are now connected to database "zabbix" as user "postgres". 7 | # zabbix=# create extension pg_buffercache; 8 | # CREATE EXTENSION 9 | # zabbix=# 10 | 11 | # EXTERNAL EXTENSIONS # 12 | UserParameter=pgsql.buffercache.clear[*],psql -qAtX $1 -c "select count(*) from pg_buffercache where not isdirty" 13 | UserParameter=pgsql.buffercache.dirty[*],psql -qAtX $1 -c "select count(*) from pg_buffercache where isdirty" 14 | UserParameter=pgsql.buffercache.used[*],psql -qAtX $1 -c "select count(*) from pg_buffercache where reldatabase is not null" 15 | UserParameter=pgsql.buffercache.total[*],psql -qAtX $1 -c "select count(*) from pg_buffercache" 16 | 17 | # Database Discovery 18 | UserParameter=pgsql.db.discovery[*],/bin/echo -n '{"data":['; for db in $(psql -qAtX $1 -c "select datname from pg_database where not datistemplate and datallowconn and datname!='postgres'"); do /bin/echo -n "{\"{#DBNAME}\": \"$db\"},"; done |sed -e 's:,$::'; /bin/echo -n ']}' 19 | 20 | # Database Statistics 21 | UserParameter=pgsql.db.size[*],psql -qAtX $1 -c "select pg_database_size('$2')" 22 | UserParameter=pgsql.db.autovac_freeze[*],psql -qAtX $1 -c "SELECT txns, ROUND(100*(txns/freez::float)) AS perc FROM (SELECT foo.freez::int, age(datfrozenxid) AS txns FROM pg_database d JOIN (SELECT setting AS freez FROM pg_settings WHERE name = 'autovacuum_freeze_max_age') AS foo ON (true) WHERE d.datallowconn AND datname = '$2') AS foo2;" | awk -F\| '{printf("{\"{#DBNAME}\":\"$2\", \"TXNS\":\"%d\", \"TXNS_PERCENT\":\"%d\"}", $$1, $$2)}' 23 | 24 | # GENERAL INFORMATION # 25 | UserParameter=pgsql.ping[*],/bin/echo -e "\\\timing \n select 1" | psql -qAtX $1 | tail -n 1 |cut -d' ' -f2 26 | UserParameter=pgsql.uptime[*],psql -qAtX $1 -c "select date_part('epoch', now() - pg_postmaster_start_time())::int" 27 | UserParameter=pgsql.cache.hit[*],psql -qAtX $1 -c "select round(sum(blks_hit)*100/sum(blks_hit+blks_read), 2) from pg_stat_database" 28 | UserParameter=pgsql.version[*],psql -qAtX $1 -c "SELECT version() AS pg_version" 29 | 30 | # OTHER INFORMATION # 31 | UserParameter=pgsql.table.tuples[*],psql -qAtX $1 -d $2 -c "select count(*) from $3" 32 | UserParameter=pgsql.setting[*],psql -qAtX $1 -c "select current_setting('$2')" 33 | UserParameter=pgsql.trigger[*],psql -qAtX $1 -c "select count(*) from pg_trigger where tgenabled='O' and tgname='$2'" 34 | UserParameter=pgsql.wal.write[*],psql -qAtX $1 -c "select pg_xlog_location_diff(pg_current_xlog_location(),'0/00000000')" 35 | UserParameter=pgsql.wal.count[*],psql -qAtX $1 -c "select count(*) from pg_ls_dir('pg_xlog')" 36 | 37 | # BACKGROUND WRITER STATS # 38 | UserParameter=pgsql.bgwriter.checkpoints_timed[*],psql -qAtX $1 -c "select checkpoints_timed from pg_stat_bgwriter" 39 | UserParameter=pgsql.bgwriter.checkpoints_req[*],psql -qAtX $1 -c "select checkpoints_req from pg_stat_bgwriter" 40 | UserParameter=pgsql.bgwriter.checkpoint_write_time[*],psql -qAtX $1 -c "select checkpoint_write_time from pg_stat_bgwriter" 41 | UserParameter=pgsql.bgwriter.checkpoint_sync_time[*],psql -qAtX $1 -c "select checkpoint_sync_time from pg_stat_bgwriter" 42 | UserParameter=pgsql.bgwriter.buffers_checkpoint[*],psql -qAtX $1 -c "select buffers_checkpoint from pg_stat_bgwriter" 43 | UserParameter=pgsql.bgwriter.buffers_clean[*],psql -qAtX $1 -c "select buffers_clean from pg_stat_bgwriter" 44 | UserParameter=pgsql.bgwriter.maxwritten_clean[*],psql -qAtX $1 -c "select maxwritten_clean from pg_stat_bgwriter" 45 | UserParameter=pgsql.bgwriter.buffers_backend[*],psql -qAtX $1 -c "select buffers_backend from pg_stat_bgwriter" 46 | UserParameter=pgsql.bgwriter.buffers_backend_fsync[*],psql -qAtX $1 -c "select buffers_backend_fsync from pg_stat_bgwriter" 47 | UserParameter=pgsql.bgwriter.buffers_alloc[*],psql -qAtX $1 -c "select buffers_alloc from pg_stat_bgwriter" 48 | 49 | # CONNECTIONS # 50 | UserParameter=pgsql.connections.active[*],psql -qAtX $1 -c "select count(*) from pg_stat_activity where state = 'active'" 51 | UserParameter=pgsql.connections.idle[*],psql -qAtX $1 -c "select count(*) from pg_stat_activity where state = 'idle'" 52 | UserParameter=pgsql.connections.idle_in_transaction[*],psql -qAtX $1 -c "select count(*) from pg_stat_activity where state = 'idle in transaction'" 53 | UserParameter=pgsql.connections.total[*],psql -qAtX $1 -c "select count(*) from pg_stat_activity" 54 | UserParameter=pgsql.connections.total_pct[*],psql -qAtX $1 -c "select count(*)*100/(select current_setting('max_connections')::int) from pg_stat_activity" 55 | UserParameter=pgsql.connections.waiting[*],psql -qAtX $1 -c "select count(*) from pg_stat_activity WHERE state != 'idle' AND wait_event IS NOT NULL;" 56 | UserParameter=pgsql.connections.prepared[*],psql -qAtX $1 -c "select count(*) from pg_prepared_xacts" 57 | 58 | # TRANSACTIONS # 59 | UserParameter=pgsql.transactions.idle[*],psql -qAtX $1 -c "select coalesce(extract(epoch from max(age(now(), query_start))), 0) from pg_stat_activity where state='idle in transaction'" 60 | UserParameter=pgsql.transactions.active[*],psql -qAtX $1 -c "select coalesce(extract(epoch from max(age(now(), query_start))), 0) from pg_stat_activity where state <> 'idle in transaction' and state <> 'idle'" 61 | UserParameter=pgsql.transactions.waiting[*],psql -qAtX $1 -c "select coalesce(extract(epoch from max(age(now(), query_start))), 0) from pg_stat_activity WHERE state != 'idle' AND wait_event IS NOT NULL" 62 | UserParameter=pgsql.transactions.prepared[*],psql -qAtX $1 -c "select coalesce(extract(epoch from max(age(now(), prepared))), 0) from pg_prepared_xacts" 63 | UserParameter=pgsql.pgstatstatements.avg_query_time[*],psql -qAtX $1 -c "select round((sum(total_time) / sum(calls))::numeric,2) from pg_stat_statements" 64 | 65 | # SUMMARY DATABASE STATS # 66 | UserParameter=pgsql.dbstat.sum.numbackends[*],psql -qAtX $1 -c "select sum(numbackends) from pg_stat_database" 67 | UserParameter=pgsql.dbstat.sum.xact_commit[*],psql -qAtX $1 -c "select sum(xact_commit) from pg_stat_database" 68 | UserParameter=pgsql.dbstat.sum.xact_rollback[*],psql -qAtX $1 -c "select sum(xact_rollback) from pg_stat_database" 69 | UserParameter=pgsql.dbstat.sum.blks_read[*],psql -qAtX $1 -c "select sum(blks_read) from pg_stat_database" 70 | UserParameter=pgsql.dbstat.sum.blks_hit[*],psql -qAtX $1 -c "select sum(blks_hit) from pg_stat_database" 71 | UserParameter=pgsql.dbstat.sum.tup_returned[*],psql -qAtX $1 -c "select sum(tup_returned) from pg_stat_database" 72 | UserParameter=pgsql.dbstat.sum.tup_fetched[*],psql -qAtX $1 -c "select sum(tup_fetched) from pg_stat_database" 73 | UserParameter=pgsql.dbstat.sum.tup_inserted[*],psql -qAtX $1 -c "select sum(tup_inserted) from pg_stat_database" 74 | UserParameter=pgsql.dbstat.sum.tup_updated[*],psql -qAtX $1 -c "select sum(tup_updated) from pg_stat_database" 75 | UserParameter=pgsql.dbstat.sum.tup_deleted[*],psql -qAtX $1 -c "select sum(tup_deleted) from pg_stat_database" 76 | UserParameter=pgsql.dbstat.sum.conflicts[*],psql -qAtX $1 -c "select sum(conflicts) from pg_stat_database" 77 | UserParameter=pgsql.dbstat.sum.temp_files[*],psql -qAtX $1 -c "select sum(temp_files) from pg_stat_database" 78 | UserParameter=pgsql.dbstat.sum.temp_bytes[*],psql -qAtX $1 -c "select sum(temp_bytes) from pg_stat_database" 79 | UserParameter=pgsql.dbstat.sum.deadlocks[*],psql -qAtX $1 -c "select sum(deadlocks) from pg_stat_database" 80 | 81 | # SPECIFIED DATABASE STATS - TODO: CREATE LLD # 82 | UserParameter=pgsql.dbstat.numbackends[*],psql -qAtX $1 -c "select numbackends from pg_stat_database where datname = '$2'" 83 | UserParameter=pgsql.dbstat.xact_commit[*],psql -qAtX $1 -c "select xact_commit from pg_stat_database where datname = '$2'" 84 | UserParameter=pgsql.dbstat.xact_rollback[*],psql -qAtX $1 -c "select xact_rollback from pg_stat_database where datname = '$2'" 85 | UserParameter=pgsql.dbstat.blks_read[*],psql -qAtX $1 -c "select blks_read from pg_stat_database where datname = '$2'" 86 | UserParameter=pgsql.dbstat.blks_hit[*],psql -qAtX $1 -c "select blks_hit from pg_stat_database where datname = '$2'" 87 | UserParameter=pgsql.dbstat.tup_returned[*],psql -qAtX $1 -c "select tup_returned from pg_stat_database where datname = '$2'" 88 | UserParameter=pgsql.dbstat.tup_fetched[*],psql -qAtX $1 -c "select tup_fetched from pg_stat_database where datname = '$2'" 89 | UserParameter=pgsql.dbstat.tup_inserted[*],psql -qAtX $1 -c "select tup_inserted from pg_stat_database where datname = '$2'" 90 | UserParameter=pgsql.dbstat.tup_updated[*],psql -qAtX $1 -c "select tup_updated from pg_stat_database where datname = '$2'" 91 | UserParameter=pgsql.dbstat.tup_deleted[*],psql -qAtX $1 -c "select tup_deleted from pg_stat_database where datname = '$2'" 92 | UserParameter=pgsql.dbstat.conflicts[*],psql -qAtX $1 -c "select conflicts from pg_stat_database where datname = '$2'" 93 | UserParameter=pgsql.dbstat.temp_files[*],psql -qAtX $1 -c "select temp_files from pg_stat_database where datname = '$2'" 94 | UserParameter=pgsql.dbstat.temp_bytes[*],psql -qAtX $1 -c "select temp_bytes from pg_stat_database where datname = '$2'" 95 | UserParameter=pgsql.dbstat.deadlocks[*],psql -qAtX $1 -c "select deadlocks from pg_stat_database where datname = '$2'" 96 | 97 | # DATABASE/TABLE/INDEXES SIZE - TODO: CREATE LLD # 98 | UserParameter=pgsql.table.size[*],psql -qAtX $1 -d $2 -c "select pg_relation_size('$3')" 99 | UserParameter=pgsql.index.size[*],psql -qAtX $1 -d $2 -c "select pg_total_relation_size('$3') - pg_relation_size('$3')" 100 | 101 | # TABLE STATS # 102 | UserParameter=pgsql.table.stat.heap_blks_read[*],psql -qAtX $1 -d $2 -c "select coalesce(heap_blks_read,0) from pg_statio_user_tables where (schemaname || '.' || relname) = '$3'" 103 | UserParameter=pgsql.table.stat.heap_blks_hit[*],psql -qAtX $1 -d $2 -c "select coalesce(heap_blks_hit,0) from pg_statio_user_tables where (schemaname || '.' || relname) = '$3'" 104 | UserParameter=pgsql.table.stat.idx_blks_read[*],psql -qAtX $1 -d $2 -c "select coalesce(idx_blks_read,0) from pg_statio_user_tables where (schemaname || '.' || relname) = '$3'" 105 | UserParameter=pgsql.table.stat.idx_blks_hit[*],psql -qAtX $1 -d $2 -c "select coalesce(idx_blks_hit,0) from pg_statio_user_tables where (schemaname || '.' || relname) = '$3'" 106 | UserParameter=pgsql.table.stat.toast_blks_read[*],psql -qAtX $1 -d $2 -c "select coalesce(toast_blks_read,0) from pg_statio_user_tables where (schemaname || '.' || relname) = '$3'" 107 | UserParameter=pgsql.table.stat.toast_blks_hit[*],psql -qAtX $1 -d $2 -c "select coalesce(toast_blks_hit,0) from pg_statio_user_tables where (schemaname || '.' || relname) = '$3'" 108 | UserParameter=pgsql.table.stat.tidx_blks_read[*],psql -qAtX $1 -d $2 -c "select coalesce(tidx_blks_read,0) from pg_statio_user_tables where (schemaname || '.' || relname) = '$3'" 109 | UserParameter=pgsql.table.stat.tidx_blks_hit[*],psql -qAtX $1 -d $2 -c "select coalesce(tidx_blks_hit,0) from pg_statio_user_tables where (schemaname || '.' || relname) = '$3'" 110 | UserParameter=pgsql.table.stat.seq_scan[*],psql -qAtX $1 -d $2 -c "select coalesce(seq_scan,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 111 | UserParameter=pgsql.table.stat.seq_tup_read[*],psql -qAtX $1 -d $2 -c "select coalesce(seq_tup_read,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 112 | UserParameter=pgsql.table.stat.idx_scan[*],psql -qAtX $1 -d $2 -c "select coalesce(idx_scan,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 113 | UserParameter=pgsql.table.stat.idx_tup_fetch[*],psql -qAtX $1 -d $2 -c "select coalesce(idx_tup_fetch,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 114 | UserParameter=pgsql.table.stat.n_tup_ins[*],psql -qAtX $1 -d $2 -c "select coalesce(n_tup_ins,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 115 | UserParameter=pgsql.table.stat.n_tup_del[*],psql -qAtX $1 -d $2 -c "select coalesce(n_tup_del,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 116 | UserParameter=pgsql.table.stat.n_tup_upd[*],psql -qAtX $1 -d $2 -c "select coalesce(n_tup_upd,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 117 | UserParameter=pgsql.table.stat.n_tup_hot_upd[*],psql -qAtX $1 -d $2 -c "select coalesce(n_tup_hot_upd,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 118 | UserParameter=pgsql.table.stat.n_live_tup[*],psql -qAtX $1 -d $2 -c "select coalesce(n_live_tup,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 119 | UserParameter=pgsql.table.stat.n_dead_tup[*],psql -qAtX $1 -d $2 -c "select coalesce(n_dead_tup,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 120 | UserParameter=pgsql.table.stat.vacuum_count[*],psql -qAtX $1 -d $2 -c "select coalesce(vacuum_count,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 121 | UserParameter=pgsql.table.stat.autovacuum_count[*],psql -qAtX $1 -d $2 -c "select coalesce(autovacuum_count,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 122 | UserParameter=pgsql.table.stat.analyze_count[*],psql -qAtX $1 -d $2 -c "select coalesce(analyze_count,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 123 | UserParameter=pgsql.table.stat.autoanalyze_count[*],psql -qAtX $1 -d $2 -c "select coalesce(autoanalyze_count,0) from pg_stat_user_tables where (schemaname || '.' || relname) = '$3'" 124 | 125 | # Streaming Discovery 126 | UserParameter=pgsql.streaming.discovery[*],/bin/echo -n '{"data":['; for replica in $(psql -qAtX $1 -c "select client_addr from pg_stat_replication"); do /bin/echo -n "{\"{#HOTSTANDBY}\": \"$replica\"},"; done |sed -e 's:,$::'; /bin/echo -n ']}' 127 | 128 | # STREAMING REPLICATION # 129 | UserParameter=pgsql.packet_loss[*],ping -W 2 -q -n -c 10 $1 | grep "packet loss" | cut -d " " -f 6 | cut -d "%" -f1 130 | UserParameter=pgsql.streaming.count[*],psql -qAtX $1 -c "select count(*) from pg_stat_replication" 131 | UserParameter=pgsql.streaming.state[*],psql -qAtX $1 -c "select pg_is_in_recovery()" 132 | UserParameter=pgsql.streaming.lag.bytes[*],psql -qAtX $1 -c "select greatest(0,pg_xlog_location_diff(pg_current_xlog_location(), replay_location)) from pg_stat_replication where client_addr = '$2'" 133 | UserParameter=pgsql.streaming.lag.seconds[*],psql -qAtX -h $2 $1 -c "SELECT CASE WHEN pg_last_xlog_receive_location() = pg_last_xlog_replay_location() THEN 0 ELSE EXTRACT (EPOCH FROM now() - pg_last_xact_replay_timestamp())::INTEGER END AS replication_lag;" 134 | 135 | # Table Discovery 136 | UserParameter=pgsql.table.discovery[*],/bin/echo -n '{"data":['; for db in $(psql -qAtX $1 -c "select datname from pg_database where not datistemplate and datallowconn and datname!='postgres'"); do for table in $(psql -qAtX -F. $1 -d $db -c "select n.nspname,c.relname from pg_catalog.pg_class c left join pg_catalog.pg_namespace n on n.oid = c.relnamespace where c.relkind in ('r','s','') and n.nspname not in ('^pg_toast','information_schema','pg_catalog')"); do /bin/echo -n "{\"{#DBNAME}\": \"$db\", \"{#TABLENAME}\": \"$table\"},"; done; done | sed -e 's:\},$:\}:'; /bin/echo -n ']}' 137 | 138 | # Bloat: Top 10 Tables 139 | UserParameter=pgsql.table.bloat.discovery[*],/bin/echo -n '{"data":['; for table in $(psql -qAtX -F. $1 -d $2 -c "SELECT nspname || '.' || relname FROM pg_class c LEFT JOIN pg_namespace n ON n.oid = c.relnamespace LEFT JOIN LATERAL pgstattuple_approx(nspname || '.' || relname ) b ON true WHERE relkind IN ( 'r' ) AND ( approx_free_space >= $3 AND approx_free_percent >= $4 ) AND NOT pg_is_in_recovery();" ); do /bin/echo -n "{\"{#DBNAME}\": \"$2\", \"{#TABLENAME}\": \"$table\"},"; done | sed -e 's:\},$:\}:'; /bin/echo -n ']}' 140 | UserParameter=pgsql.table.bloat.values[*],psql -qAtX $1 -d $2 -c "SELECT * FROM pgstattuple_approx('$3');" | awk -F\| '{printf("{\"{#TABLENAME}\":\"$3\", \"APPROX_FREE_PERCENT\":\"%.2f\", \"APPROX_DEAD_TUPLE_PERCENT\":\"%.2f\", \"TABLE_LEN\":\"%d\", \"APPROX_FREE_SPACE\":\"%d\", \"SCANNED_PERCENT\":\"%.2f\"}",$$10, $$8, $$1, $$9, $$2)}' 141 | -------------------------------------------------------------------------------- /PostgreSQL/README.md: -------------------------------------------------------------------------------- 1 | # PostgreSQL Template 2 | 3 | When building this template, attempts are being made to allow it 4 | to be run as a 'regular user', but there may be some features that 5 | it makes use of that will not work in certain environments. 6 | 7 | Optimally, the following steps can be performed to get a fully working 8 | monitor in place: 9 | 10 | 1. createuser --superuser zabbix 11 | 2. createdb --owner=zabbix zabbix 12 | 13 | The following PostgreSQL Extensions are used to generate statistics: 14 | 15 | - pgstattuple 16 | - Used by Table Bloat monitoring 17 | - pg_buffercache 18 | - Buffer Statistics 19 | 20 | For most monitoring, it is recommended that the zabbix-agent is on the same 21 | server as the database, but in the case of something like RDS, you would need 22 | to setup a seperate instance that connects into the database server 'remotely'. 23 | 24 | In either case, you will need to setup a .pgpass file under the zabbix user on 25 | the machine running zabbix-agentd, to allow for passwordless access to the 26 | database 27 | 28 | # Monitoring 29 | 30 | In order to reduce the impact on the server, our discovery rules are written, by 31 | default, in such a way to only return what we are generally interested in. And, 32 | due to limitations we have yet to figure out a way around with Zabbix, you can 33 | only monitor one database on a server ... once we can figure out how to get around 34 | that, we will obviously update the template accordingly. 35 | 36 | As such, at present, there is one MACRO that needs to be set per server being monitored, 37 | and that is {$ACTIVE_DB}, which is the database whose tables / indexes / etc you are 38 | specifically monitoring fow what is listed below. If you do not set that value, the 39 | tests below will not work. 40 | 41 | ## Bloat Monitoring ( see: [Autovacuum Tuning Basics](https://blog.2ndquadrant.com/autovacuum-tuning-basics/) 42 | 43 | The thresholds for Bloat Monitoring are set within the Template Macros, and can be 44 | adjusted for each instance accordingly. There are 4 settings: 45 | 46 | - ${BLOAT_CRITICAL_BYTES} 47 | - ${BLOAT_CRITICAL_PERCENT} 48 | - ${BLOAT_WARN_BYTES} 49 | - ${BLOAT_WARN_PERCENT} 50 | 51 | The Discovery rule for this is based on the WARN levels: 52 | 53 | if FreeSpace > ${BLOAT_WARN_BYTES} AND PercentFree > ${BLOAT_WARN_PERCENT} 54 | 55 | ## Autovacuum Freeze Age 56 | 57 | The thresholds for Autovacuum Freeze Age Monitoring are set within the Template 58 | Macros, and can be adjusted for each instance accordingly. There are 4 settings: 59 | 60 | - ${AUTOVAC_FREEZE_AGE_CRITICAL_PERCENT} 61 | - ${AUTOVAC_FREEZE_AGE_CRITICAL_PERCENT} 62 | 63 | This monitor is at the database level. 64 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # zabbix_templates 2 | Various templates for Zabbix 3 | -------------------------------------------------------------------------------- /pgBarman/README.md: -------------------------------------------------------------------------------- 1 | # zabbix_templates 2 | Various templates for Zabbix 3 | -------------------------------------------------------------------------------- /pgBouncer/README.md: -------------------------------------------------------------------------------- 1 | # zabbix_templates 2 | Various templates for Zabbix 3 | --------------------------------------------------------------------------------