From 14d4b870e36a6b28bb74e7599b7c62e180315365 Mon Sep 17 00:00:00 2001 From: muppeth Date: Tue, 9 May 2023 00:13:59 +0200 Subject: [PATCH 1/3] updated role to zabbix 6.4 --- defaults/main.yml | 126 +++++++++++++++++++++++---------------- handlers/main.yml | 5 ++ tasks/install_server.yml | 14 +++-- 3 files changed, 87 insertions(+), 58 deletions(-) diff --git a/defaults/main.yml b/defaults/main.yml index d0da146..bd7bbb5 100644 --- a/defaults/main.yml +++ b/defaults/main.yml @@ -1,10 +1,7 @@ --- -#zabbix_installed: 'false' -zabbix_proxy_installed: 'true' - #main -zabbix_version: '5.0' +zabbix_version: '6.4' zabbix_agent: 'true' zabbix_server: 'true' zabbix_proxy: 'false' @@ -38,6 +35,13 @@ zabbix_server_fping6: '/usr/bin/fping6' zabbix_server_queries_slow: '3000' zabbix_cachesize: '8M' +zabbix_server_apt: + - zabbix-server-mysql + - zabbix-frontend-php + - zabbix-nginx-conf + - zabbix-sql-scripts + - gzip + - python3-pymysql #Zabbix Client zabbix_agent_params: - name: "container" @@ -87,55 +91,73 @@ zabbix_proxy_data_sernder_freq: '1' zabbix_proxy_start_pollers: '5' zabbix_proxy_ipmi_pollers: '0' -#PHP Vars -php_version: '8.0' -php_etc_path: '/etc/php' -install_php: 'true' -pool_listen: '/var/run/php/php{{ php_version }}-fpm.sock' - -php_pkgs: - - php{{ php_version }}-fpm - - php{{ php_version }}-bz2 - - php{{ php_version }}-cgi - - php{{ php_version }}-cli - - php{{ php_version }}-common - - php{{ php_version }}-curl - - php{{ php_version }}-dev - - php{{ php_version }}-enchant - - php{{ php_version }}-gd - - php{{ php_version }}-gmp - - php{{ php_version }}-igbinary - - php{{ php_version }}-interbase - - php{{ php_version }}-intl - - php{{ php_version }}-mbstring # frontend - - php{{ php_version }}-msgpack - - php{{ php_version }}-pspell - - php{{ php_version }}-readline - - php{{ php_version }}-zip - - php{{ php_version }}-gd # frontend - - php{{ php_version }}-bcmath # frontend - - php{{ php_version }}-xml # frontend - - php{{ php_version }}-ldap # frontend - - -#nginx -nginx_default_vhost: 'zabbix' -nginx_default_vhost_ssl: 'zabbix' -#nginx_www_dir: '/var/www/' -nginx_vhosts: - -- name: 'zabbix' - template: 'zabbix' - proto: 'http' - listen: '80' - root: '/usr/share/zabbix' - use_access_log: 'true' - use_error_log: 'true' - nginx_error_log_level: 'warn' - state: 'enable' - letsencrypt: 'false' - # MARIADB CONFIG +mariadb_default_config: + - name: 'client' + config: + - port = {{ mariadb_client_port }} + - socket = /var/run/mysqld/mysqld.sock + - default-character-set = utf8mb4 + - name: 'mysqld_safe' + config: + - safe_socket = /var/run/mysqld/mysqld.sock + - safe_nice = 0 + - name: 'mysqld' + config: + - user = mysql + - pid_file = /var/run/mysqld/mysqld.pid + - socket = /var/run/mysqld/mysqld.sock + - port = 3306 + - basedir = /usr + - datadir = {{ mariadb_datadir }} + - tmpdir = /tmp + - init_connect ='SET collation_connection = utf8mb4_unicode_ci' + - init_connect ='SET NAMES utf8mb4' + - character-set-server = utf8mb4 + - collation-server = utf8mb4_unicode_ci + - skip_external_locking = True + - bind_address = {{ zabbix_server_db_host }} + - key_buffer = 16M + - max_allowed_packet = 16M + - thread_stack = 192K + - thread_cache_size = 64 + - myisam_recover = BACKUP + - max_connections = 1000 + - general_log_file = /var/log/mysql/mysql.log + - general_log = 0 + - slow_query_log = 1 + - slow_query_log_file = /var/log/mysql/mysql-slow.log + - long_query_time = 1 + - log_queries_not_using_indexes = False + - default_storage_engine = InnoDB + - innodb_buffer_pool_size = 4096M + - innodb_buffer_pool_instances = 2 + - innodb_log_file_size = 128M + - innodb_log_buffer_size = 8M + - innodb_thread_concurrency = 64 + - innodb_read_io_threads = 16 + - innodb_write_io_threads = 16 + - innodb_file_per_table = 1 + - innodb_open_files = 400 + - innodb_io_capacity = 600 + - innodb_lock_wait_timeout = 60 + - innodb_flush_method = O_DIRECT + - innodb_doublewrite = 0 + - innodb_use_native_aio = 0 + - innodb_large_prefix = on + - server_id = 1 + - log_bin = /var/log/mysql/mysql-bin.log + - expire_logs_days = 2 + - max_binlog_size = 10M + - binlog_format = row + - binlog_cache_size = 16M + - query_cache_type = 1 + - query_cache_limit = 256K + - query_cache_min_res_unit = 2k + - query_cache_size = 64M + - tmp_table_size = 512M + - max_heap_table_size = 512M + - wait_timeout = 120 mariadb_databases: - name: '{{ zabbix_server_db_name }}' collation: 'utf8_general_ci' # should it be utf8_bin? diff --git a/handlers/main.yml b/handlers/main.yml index 53ecdfa..281871f 100644 --- a/handlers/main.yml +++ b/handlers/main.yml @@ -14,3 +14,8 @@ systemd: name: zabbix-proxy state: restarted + +- name: restart nginx + systemd: + name: nginx + state: reloaded diff --git a/tasks/install_server.yml b/tasks/install_server.yml index 7ead633..894caa6 100644 --- a/tasks/install_server.yml +++ b/tasks/install_server.yml @@ -2,11 +2,7 @@ - name: '[Server] - Install Zabbix from repository' apt: - pkg: - - zabbix-server-mysql - - zabbix-frontend-php - - gzip - - python3-pymysql + pkg: "{{ zabbix_server_apt }}" state: latest update_cache: yes install_recommends: no @@ -37,8 +33,14 @@ login_user: '{{ zabbix_server_db_user }}' name: "{{ zabbix_server_db_name }}" state: import - target: /usr/share/doc/zabbix-server-mysql/create.sql.gz + target: /usr/share/zabbix-sql-scripts/mysql/server.sql.gz when: "'ERROR 1146' in zabbix_installed.stderr" # ERROR 1146 means the table doesn't exist notify: - restart zabbix_server + +- name: "[Server] - Remove default nginx vhost" + file: + path: '/etc/nginx/sites-enabled/default' + state: 'absent' + notify: restart nginx From a25e493f87b63a3fc999a21d383ba1de58139912 Mon Sep 17 00:00:00 2001 From: muppeth Date: Fri, 12 May 2023 01:23:55 +0200 Subject: [PATCH 2/3] added mariadb and postgres user parameters --- .../userparameter_container.conf.j2 | 42 +++++++++++++++++++ 1 file changed, 42 insertions(+) diff --git a/templates/zabbix_agent.d/userparameter_container.conf.j2 b/templates/zabbix_agent.d/userparameter_container.conf.j2 index a452aab..7017db6 100644 --- a/templates/zabbix_agent.d/userparameter_container.conf.j2 +++ b/templates/zabbix_agent.d/userparameter_container.conf.j2 @@ -71,4 +71,46 @@ UserParameter=etherpad[*],cat /tmp/pad_stats | grep $1 | cut -d' ' -f2- # Ethercalc UserParameter=ethercalc[*],cat /tmp/ethercalc_stats | grep $1 | cut -d' ' -f2- {% endif %} +{% if item.name == 'mariadb' %} +# Mariadb +UserParameter=mysql.ping[*], mysqladmin -h"$1" -P"$2" ping +UserParameter=mysql.get_status_variables[*], mysql -h"$1" -P"$2" -sNX -e "show global status" +UserParameter=mysql.version[*], mysqladmin -s -h"$1" -P"$2" version +UserParameter=mysql.db.discovery[*], mysql -h"$1" -P"$2" -sN -e "show databases" +UserParameter=mysql.dbsize[*], mysql -h"$1" -P"$2" -sN -e "SELECT COALESCE(SUM(DATA_LENGTH + INDEX_LENGTH),0) FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_SCHEMA='$3'" +UserParameter=mysql.replication.discovery[*], mysql -h"$1" -P"$2" -sNX -e "show slave status" +UserParameter=mysql.slave_status[*], mysql -h"$1" -P"$2" -sNX -e "show slave status" +{% endif %} +{% if item.name == 'postgres' %} +# Postgres +UserParameter=pgsql.bgwriter[*], psql -qtAX postgresql://"$3":"$4"@"$1":"$2"/"$5" -f "/var/lib/zabbix/postgresql/pgsql.bgwriter.sql" + +UserParameter=pgsql.connections.sum[*], psql -qtAX postgresql://"$3":"$4"@"$1":"$2"/"$5" -f "/var/lib/zabbix/postgresql/pgsql.connections.sum.sql" +UserParameter=pgsql.connections[*], psql -qtAX postgresql://"$3":"$4"@"$1":"$2"/"$5" -f "/var/lib/zabbix/postgresql/pgsql.connections.sql" +UserParameter=pgsql.connections.prepared[*], psql -qtAX postgresql://"$3":"$4"@"$1":"$2"/"$5" -f "/var/lib/zabbix/postgresql/pgsql.connections.prepared.sql" + +UserParameter=pgsql.dbstat.sum[*], psql -qtAX postgresql://"$3":"$4"@"$1":"$2"/"$5" -f "/var/lib/zabbix/postgresql/pgsql.dbstat.sum.sql" +UserParameter=pgsql.dbstat[*], psql -qtAX postgresql://"$3":"$4"@"$1":"$2"/"$5" -f "/var/lib/zabbix/postgresql/pgsql.dbstat.sql" + +UserParameter=pgsql.transactions[*], psql -qtAX postgresql://"$3":"$4"@"$1":"$2"/"$5" -f "/var/lib/zabbix/postgresql/pgsql.transactions.sql" +UserParameter=pgsql.config.hash[*], psql -qtAX postgresql://"$3":"$4"@"$1":"$2"/"$5" -f "/var/lib/zabbix/postgresql/pgsql.config.hash.sql" +UserParameter=pgsql.wal.stat[*], psql -qtAX postgresql://"$3":"$4"@"$1":"$2"/"$5" -f "/var/lib/zabbix/postgresql/pgsql.wal.stat.sql" +UserParameter=pgsql.locks[*], psql -qtAX postgresql://"$3":"$4"@"$1":"$2"/"$5" -f "/var/lib/zabbix/postgresql/pgsql.locks.sql" +UserParameter=pgsql.queries[*], psql -qtAX postgresql://"$3":"$4"@"$1":"$2"/"$5" -v tmax=$6 -f "/var/lib/zabbix/postgresql/pgsql.query.time.sql" +UserParameter=pgsql.uptime[*], psql -qtAX postgresql://"$3":"$4"@"$1":"$2"/"$5" -f "/var/lib/zabbix/postgresql/pgsql.uptime.sql" +UserParameter=pgsql.cache.hit[*], psql -qtAX postgresql://"$3":"$4"@"$1":"$2"/"$5" -f "/var/lib/zabbix/postgresql/pgsql.cache.hit.sql" +UserParameter=pgsql.scans[*], psql -qtAX postgresql://"$3":"$4"@"$1":"$2"/"$5" -f "/var/lib/zabbix/postgresql/pgsql.scans.sql" +UserParameter=pgsql.frozenxid[*], psql -qtAX postgresql://"$3":"$4"@"$1":"$2"/"$5" -f "/var/lib/zabbix/postgresql/pgsql.frozenxid.sql" + +UserParameter=pgsql.discovery.db[*], psql -qtAX postgresql://"$3":"$4"@"$1":"$2"/"$5" -f "/var/lib/zabbix/postgresql/pgsql.discovery.db.sql" +UserParameter=pgsql.db.size[*], psql -qtAX postgresql://"$3":"$4"@"$1":"$2"/"$5" -c "SELECT pg_database_size('$6')" +UserParameter=pgsql.ping[*], pg_isready -h "$1" -p "$2" +UserParameter=pgsql.ping.time[*], LANG=C.UTF-8 psql -qtAX postgresql://"$3":"$4"@"$1":"$2"/"$5" -f "/var/lib/zabbix/postgresql/pgsql.ping.time.sql" +UserParameter=pgsql.version[*], psql -qtAX postgresql://"$3":"$4"@"$1":"$2"/"$5" -c "SELECT version();" + +UserParameter=pgsql.replication.count[*], psql -qtAX postgresql://"$3":"$4"@"$1":"$2"/"$5" -c "SELECT count(*) FROM pg_stat_replication" +UserParameter=pgsql.replication.recovery_role[*], psql -qtAX postgresql://"$3":"$4"@"$1":"$2"/"$5" -f "/var/lib/zabbix/postgresql/pgsql.replication.recovery_role.sql" +UserParameter=pgsql.replication.lag.sec[*], psql -qtAX postgresql://"$3":"$4"@"$1":"$2"/"$5" -f "/var/lib/zabbix/postgresql/pgsql.replication.lag.sql" +UserParameter=pgsql.replication.status[*], psql -qtAX postgresql://"$3":"$4"@"$1":"$2"/"$5" -f "/var/lib/zabbix/postgresql/pgsql.replication.status.sql" +{% endif %} {% endfor %} From b08b54699e725bdcd8a7ed6cef80d2007031d498 Mon Sep 17 00:00:00 2001 From: muppeth Date: Fri, 12 May 2023 21:58:11 +0200 Subject: [PATCH 3/3] added custom file tasks --- files/postgresql/pgsql.bgwriter.sql | 13 ++++++ files/postgresql/pgsql.cache.hit.sql | 2 + files/postgresql/pgsql.config.hash.sql | 18 ++++++++ .../postgresql/pgsql.connections.prepared.sql | 2 + files/postgresql/pgsql.connections.sql | 38 +++++++++++++++ files/postgresql/pgsql.connections.sum.sql | 38 +++++++++++++++ files/postgresql/pgsql.dbstat.sql | 17 +++++++ files/postgresql/pgsql.dbstat.sum.sql | 16 +++++++ files/postgresql/pgsql.discovery.db.sql | 10 ++++ files/postgresql/pgsql.frozenxid.sql | 13 ++++++ files/postgresql/pgsql.locks.sql | 46 +++++++++++++++++++ files/postgresql/pgsql.ping.time.sql | 2 + files/postgresql/pgsql.query.time.sql | 31 +++++++++++++ files/postgresql/pgsql.replication.lag.sql | 18 ++++++++ .../pgsql.replication.recovery_role.sql | 1 + files/postgresql/pgsql.replication.status.sql | 21 +++++++++ files/postgresql/pgsql.scans.sql | 9 ++++ files/postgresql/pgsql.transactions.sql | 30 ++++++++++++ files/postgresql/pgsql.uptime.sql | 1 + files/postgresql/pgsql.wal.stat.sql | 26 +++++++++++ tasks/custom_agent.yml | 10 ++++ tasks/main.yml | 4 ++ 22 files changed, 366 insertions(+) create mode 100644 files/postgresql/pgsql.bgwriter.sql create mode 100644 files/postgresql/pgsql.cache.hit.sql create mode 100644 files/postgresql/pgsql.config.hash.sql create mode 100644 files/postgresql/pgsql.connections.prepared.sql create mode 100644 files/postgresql/pgsql.connections.sql create mode 100644 files/postgresql/pgsql.connections.sum.sql create mode 100644 files/postgresql/pgsql.dbstat.sql create mode 100644 files/postgresql/pgsql.dbstat.sum.sql create mode 100644 files/postgresql/pgsql.discovery.db.sql create mode 100644 files/postgresql/pgsql.frozenxid.sql create mode 100644 files/postgresql/pgsql.locks.sql create mode 100644 files/postgresql/pgsql.ping.time.sql create mode 100644 files/postgresql/pgsql.query.time.sql create mode 100644 files/postgresql/pgsql.replication.lag.sql create mode 100644 files/postgresql/pgsql.replication.recovery_role.sql create mode 100644 files/postgresql/pgsql.replication.status.sql create mode 100644 files/postgresql/pgsql.scans.sql create mode 100644 files/postgresql/pgsql.transactions.sql create mode 100644 files/postgresql/pgsql.uptime.sql create mode 100644 files/postgresql/pgsql.wal.stat.sql create mode 100644 tasks/custom_agent.yml diff --git a/files/postgresql/pgsql.bgwriter.sql b/files/postgresql/pgsql.bgwriter.sql new file mode 100644 index 0000000..d584db9 --- /dev/null +++ b/files/postgresql/pgsql.bgwriter.sql @@ -0,0 +1,13 @@ +SELECT row_to_json(T) +FROM + (SELECT checkpoints_timed, + checkpoints_req, + checkpoint_write_time, + checkpoint_sync_time, + current_setting('block_size')::int*buffers_checkpoint AS buffers_checkpoint, + current_setting('block_size')::int*buffers_clean AS buffers_clean, + maxwritten_clean, + current_setting('block_size')::int*buffers_backend AS buffers_backend, + buffers_backend_fsync, + current_setting('block_size')::int*buffers_alloc AS buffers_alloc + FROM pg_stat_bgwriter) T diff --git a/files/postgresql/pgsql.cache.hit.sql b/files/postgresql/pgsql.cache.hit.sql new file mode 100644 index 0000000..4374dda --- /dev/null +++ b/files/postgresql/pgsql.cache.hit.sql @@ -0,0 +1,2 @@ +SELECT round(sum(blks_hit)*100/sum(blks_hit+blks_read), 2) +FROM pg_stat_database diff --git a/files/postgresql/pgsql.config.hash.sql b/files/postgresql/pgsql.config.hash.sql new file mode 100644 index 0000000..3ebfa07 --- /dev/null +++ b/files/postgresql/pgsql.config.hash.sql @@ -0,0 +1,18 @@ +SELECT md5( + json_build_object( + 'extensions', ( + SELECT array_agg(extname) FROM ( + SELECT extname + FROM pg_extension + ORDER BY extname + ) AS e + ), + 'settings', ( + SELECT json_object(array_agg(name), array_agg(setting)) FROM ( + SELECT name, setting + FROM pg_settings + WHERE name != 'application_name' + ORDER BY name + ) AS s + ) + )::text); diff --git a/files/postgresql/pgsql.connections.prepared.sql b/files/postgresql/pgsql.connections.prepared.sql new file mode 100644 index 0000000..4b6ac9f --- /dev/null +++ b/files/postgresql/pgsql.connections.prepared.sql @@ -0,0 +1,2 @@ +SELECT count(*) +FROM pg_prepared_xacts diff --git a/files/postgresql/pgsql.connections.sql b/files/postgresql/pgsql.connections.sql new file mode 100644 index 0000000..f7be5c6 --- /dev/null +++ b/files/postgresql/pgsql.connections.sql @@ -0,0 +1,38 @@ +DO LANGUAGE plpgsql $$ +DECLARE + ver integer; + res text; + +BEGIN + SELECT current_setting('server_version_num') INTO ver; + + IF (ver >= 90600) THEN + SELECT json_object_agg(datname, row_to_json(T)) INTO res from ( + SELECT + datname, + sum(CASE WHEN state = 'active' THEN 1 ELSE 0 END) AS active, + sum(CASE WHEN state = 'idle' THEN 1 ELSE 0 END) AS idle, + sum(CASE WHEN state = 'idle in transaction' THEN 1 ELSE 0 END) AS idle_in_transaction, + count(*) AS total, + count(*)*100/(SELECT current_setting('max_connections')::int) AS total_pct, + sum(CASE WHEN wait_event IS NOT NULL THEN 1 ELSE 0 END) AS waiting + FROM pg_stat_activity WHERE datid is not NULL GROUP BY datname ) T; + + ELSE + SELECT json_object_agg(datname, row_to_json(T)) INTO res from ( + SELECT + datname, + sum(CASE WHEN state = 'active' THEN 1 ELSE 0 END) AS active, + sum(CASE WHEN state = 'idle' THEN 1 ELSE 0 END) AS idle, + sum(CASE WHEN state = 'idle in transaction' THEN 1 ELSE 0 END) AS idle_in_transaction, + count(*) AS total, + count(*)*100/(SELECT current_setting('max_connections')::int) AS total_pct, + sum(CASE WHEN waiting IS TRUE THEN 1 ELSE 0 END) AS waiting + FROM pg_stat_activity GROUP BY datname ) T; + END IF; + + perform set_config('zbx_tmp.db_conn_json_res', res, false); + +END $$; + +SELECT current_setting('zbx_tmp.db_conn_json_res'); diff --git a/files/postgresql/pgsql.connections.sum.sql b/files/postgresql/pgsql.connections.sum.sql new file mode 100644 index 0000000..bbe2c5e --- /dev/null +++ b/files/postgresql/pgsql.connections.sum.sql @@ -0,0 +1,38 @@ +DO LANGUAGE plpgsql $$ +DECLARE + ver integer; + res text; +BEGIN + SELECT current_setting('server_version_num') INTO ver; + + IF (ver >= 90600) THEN + SELECT row_to_json(T) INTO res from ( + SELECT + sum(CASE WHEN state = 'active' THEN 1 ELSE 0 END) AS active, + sum(CASE WHEN state = 'idle' THEN 1 ELSE 0 END) AS idle, + sum(CASE WHEN state = 'idle in transaction' THEN 1 ELSE 0 END) AS idle_in_transaction, + count(*) AS total, + count(*)*100/(SELECT current_setting('max_connections')::int) AS total_pct, + sum(CASE WHEN wait_event IS NOT NULL AND state != 'idle' THEN 1 ELSE 0 END) AS waiting, + (SELECT count(*) FROM pg_prepared_xacts) AS prepared + FROM pg_stat_activity WHERE datid is not NULL + ) T; + + ELSE + SELECT row_to_json(T) INTO res from ( + SELECT + sum(CASE WHEN state = 'active' THEN 1 ELSE 0 END) AS active, + sum(CASE WHEN state = 'idle' THEN 1 ELSE 0 END) AS idle, + sum(CASE WHEN state = 'idle in transaction' THEN 1 ELSE 0 END) AS idle_in_transaction, + count(*) AS total, + count(*)*100/(SELECT current_setting('max_connections')::int) AS total_pct, + sum(CASE WHEN waiting IS TRUE AND state != 'idle' THEN 1 ELSE 0 END) AS waiting, + (SELECT count(*) FROM pg_prepared_xacts) AS prepared + FROM pg_stat_activity + ) T; + END IF; + + perform set_config('zbx_tmp.conn_json_res', res, false); +END $$; + +select current_setting('zbx_tmp.conn_json_res'); diff --git a/files/postgresql/pgsql.dbstat.sql b/files/postgresql/pgsql.dbstat.sql new file mode 100644 index 0000000..9a6e4c4 --- /dev/null +++ b/files/postgresql/pgsql.dbstat.sql @@ -0,0 +1,17 @@ +SELECT json_object_agg(datname, row_to_json(T)) FROM ( + SELECT datname, + numbackends, + xact_commit, + xact_rollback, + blks_read, + blks_hit, + tup_returned, + tup_fetched, + tup_inserted, + tup_updated, + tup_deleted, + conflicts, + temp_files, + temp_bytes, + deadlocks + FROM pg_stat_database where datname is not null) T diff --git a/files/postgresql/pgsql.dbstat.sum.sql b/files/postgresql/pgsql.dbstat.sum.sql new file mode 100644 index 0000000..964b55f --- /dev/null +++ b/files/postgresql/pgsql.dbstat.sum.sql @@ -0,0 +1,16 @@ +SELECT row_to_json(T) from ( + SELECT sum(numbackends) AS numbackends, + sum(xact_commit) AS xact_commit, + sum(xact_rollback) AS xact_rollback, + sum(blks_read) AS blks_read, + sum(blks_hit) AS blks_hit, + sum(tup_returned) AS tup_returned, + sum(tup_fetched) AS tup_fetched, + sum(tup_inserted) AS tup_inserted, + sum(tup_updated) AS tup_updated, + sum(tup_deleted) AS tup_deleted, + sum(conflicts) AS conflicts, + sum(temp_files) AS temp_files, + sum(temp_bytes) AS temp_bytes, + sum(deadlocks) AS deadlocks + FROM pg_stat_database) T diff --git a/files/postgresql/pgsql.discovery.db.sql b/files/postgresql/pgsql.discovery.db.sql new file mode 100644 index 0000000..b2ca855 --- /dev/null +++ b/files/postgresql/pgsql.discovery.db.sql @@ -0,0 +1,10 @@ +WITH T AS ( + SELECT + datname AS "{#DBNAME}" + FROM pg_database + WHERE + NOT datistemplate + AND datname != 'postgres' +) +SELECT '{"data":'|| regexp_replace(coalesce(json_agg(T), '[]'::json)::text, E'[\\n\\r\\s]+', '', 'g') || '}' +FROM T diff --git a/files/postgresql/pgsql.frozenxid.sql b/files/postgresql/pgsql.frozenxid.sql new file mode 100644 index 0000000..80334d9 --- /dev/null +++ b/files/postgresql/pgsql.frozenxid.sql @@ -0,0 +1,13 @@ +SELECT row_to_json(T) +FROM ( + SELECT + extract(epoch FROM now())::integer AS ts, + ((1 - max(age(d.datfrozenxid))::double precision / + current_setting('autovacuum_freeze_max_age')::bigint) * 100)::numeric(9,6) + AS prc_before_av, + ((1 - abs(max(age(d.datfrozenxid))::double precision / + (1::bigint << (min(t.typlen)*8)))) * 100)::numeric(9,6) + AS prc_before_stop + FROM pg_database d CROSS JOIN pg_type t + WHERE t.typname = 'xid' +) T; diff --git a/files/postgresql/pgsql.locks.sql b/files/postgresql/pgsql.locks.sql new file mode 100644 index 0000000..4588446 --- /dev/null +++ b/files/postgresql/pgsql.locks.sql @@ -0,0 +1,46 @@ +WITH T AS + (SELECT db.datname dbname, + lower(replace(Q.mode, 'Lock', '')) AS MODE, + coalesce(T.qty, 0) val + FROM pg_database db + JOIN ( + VALUES ('AccessShareLock') ,('RowShareLock') ,('RowExclusiveLock') ,('ShareUpdateExclusiveLock') ,('ShareLock') ,('ShareRowExclusiveLock') ,('ExclusiveLock') ,('AccessExclusiveLock')) Q(MODE) ON TRUE NATURAL + LEFT JOIN + (SELECT datname, + MODE, + count(MODE) qty + FROM pg_locks lc + RIGHT JOIN pg_database db ON db.oid = lc.database + GROUP BY 1, 2) T + WHERE NOT db.datistemplate + ORDER BY 1, 2) +SELECT json_object_agg(dbname, row_to_json(T2)) +FROM + (SELECT dbname, + sum(val) AS total, + sum(CASE + WHEN MODE = 'accessexclusive' THEN val + END) AS accessexclusive, + sum(CASE + WHEN MODE = 'accessshare' THEN val + END) AS accessshare, + sum(CASE + WHEN MODE = 'exclusive' THEN val + END) AS EXCLUSIVE, + sum(CASE + WHEN MODE = 'rowexclusive' THEN val + END) AS rowexclusive, + sum(CASE + WHEN MODE = 'rowshare' THEN val + END) AS rowshare, + sum(CASE + WHEN MODE = 'share' THEN val + END) AS SHARE, + sum(CASE + WHEN MODE = 'sharerowexclusive' THEN val + END) AS sharerowexclusive, + sum(CASE + WHEN MODE = 'shareupdateexclusive' THEN val + END) AS shareupdateexclusive + FROM T + GROUP BY dbname) T2 diff --git a/files/postgresql/pgsql.ping.time.sql b/files/postgresql/pgsql.ping.time.sql new file mode 100644 index 0000000..d548661 --- /dev/null +++ b/files/postgresql/pgsql.ping.time.sql @@ -0,0 +1,2 @@ +\timing +SELECT 1; diff --git a/files/postgresql/pgsql.query.time.sql b/files/postgresql/pgsql.query.time.sql new file mode 100644 index 0000000..db2fd01 --- /dev/null +++ b/files/postgresql/pgsql.query.time.sql @@ -0,0 +1,31 @@ +WITH T AS + (SELECT db.datname, + coalesce(T.query_time_max, 0) query_time_max, + coalesce(T.tx_time_max, 0) tx_time_max, + coalesce(T.mro_time_max, 0) mro_time_max, + coalesce(T.query_time_sum, 0) query_time_sum, + coalesce(T.tx_time_sum, 0) tx_time_sum, + coalesce(T.mro_time_sum, 0) mro_time_sum, + coalesce(T.query_slow_count, 0) query_slow_count, + coalesce(T.tx_slow_count, 0) tx_slow_count, + coalesce(T.mro_slow_count, 0) mro_slow_count + FROM pg_database db NATURAL + LEFT JOIN ( + SELECT datname, + extract(epoch FROM now())::integer ts, + coalesce(max(extract('epoch' FROM (clock_timestamp() - query_start))::integer * (state NOT IN ('idle', 'idle in transaction', 'idle in transaction (aborted)') AND query !~* E'^(\\s*(--[^\\n]*\\n|/\\*.*\\*/|\\n))*(autovacuum|VACUUM|ANALYZE|REINDEX|CLUSTER|CREATE|ALTER|TRUNCATE|DROP)')::integer), 0) query_time_max, + coalesce(max(extract('epoch' FROM (clock_timestamp() - query_start))::integer * (state NOT IN ('idle') AND query !~* E'^(\\s*(--[^\\n]*\\n|/\\*.*\\*/|\\n))*(autovacuum|VACUUM|ANALYZE|REINDEX|CLUSTER|CREATE|ALTER|TRUNCATE|DROP)')::integer), 0) tx_time_max, + coalesce(max(extract('epoch' FROM (clock_timestamp() - query_start))::integer * (state NOT IN ('idle') AND query ~* E'^(\\s*(--[^\\n]*\\n|/\\*.*\\*/|\\n))*(autovacuum|VACUUM|ANALYZE|REINDEX|CLUSTER|CREATE|ALTER|TRUNCATE|DROP)')::integer), 0) mro_time_max, + coalesce(sum(extract('epoch' FROM (clock_timestamp() - query_start))::integer * (state NOT IN ('idle', 'idle in transaction', 'idle in transaction (aborted)') AND query !~* E'^(\\s*(--[^\\n]*\\n|/\\*.*\\*/|\\n))*(autovacuum|VACUUM|ANALYZE|REINDEX|CLUSTER|CREATE|ALTER|TRUNCATE|DROP)')::integer), 0) query_time_sum, + coalesce(sum(extract('epoch' FROM (clock_timestamp() - query_start))::integer * (state NOT IN ('idle') AND query !~* E'^(\\s*(--[^\\n]*\\n|/\\*.*\\*/|\\n))*(autovacuum|VACUUM|ANALYZE|REINDEX|CLUSTER|CREATE|ALTER|TRUNCATE|DROP)')::integer), 0) tx_time_sum, + coalesce(sum(extract('epoch' FROM (clock_timestamp() - query_start))::integer * (state NOT IN ('idle') AND query ~* E'^(\\s*(--[^\\n]*\\n|/\\*.*\\*/|\\n))*(autovacuum|VACUUM|ANALYZE|REINDEX|CLUSTER|CREATE|ALTER|TRUNCATE|DROP)')::integer), 0) mro_time_sum, + + coalesce(sum((extract('epoch' FROM (clock_timestamp() - query_start)) > :tmax)::integer * (state NOT IN ('idle', 'idle in transaction', 'idle in transaction (aborted)') AND query !~* E'^(\\s*(--[^\\n]*\\n|/\\*.*\\*/|\\n))*(autovacuum|VACUUM|ANALYZE|REINDEX|CLUSTER|CREATE|ALTER|TRUNCATE|DROP)')::integer), 0) query_slow_count, + coalesce(sum((extract('epoch' FROM (clock_timestamp() - query_start)) > :tmax)::integer * (state NOT IN ('idle') AND query !~* E'^(\\s*(--[^\\n]*\\n|/\\*.*\\*/|\\n))*(autovacuum|VACUUM|ANALYZE|REINDEX|CLUSTER|CREATE|ALTER|TRUNCATE|DROP)')::integer), 0) tx_slow_count, + coalesce(sum((extract('epoch' FROM (clock_timestamp() - query_start)) > :tmax)::integer * (state NOT IN ('idle') AND query ~* E'^(\\s*(--[^\\n]*\\n|/\\*.*\\*/|\\n))*(autovacuum|VACUUM|ANALYZE|REINDEX|CLUSTER|CREATE|ALTER|TRUNCATE|DROP)')::integer), 0) mro_slow_count + FROM pg_stat_activity + WHERE pid <> pg_backend_pid() + GROUP BY 1) T + WHERE NOT db.datistemplate ) +SELECT json_object_agg(datname, row_to_json(T)) +FROM T diff --git a/files/postgresql/pgsql.replication.lag.sql b/files/postgresql/pgsql.replication.lag.sql new file mode 100644 index 0000000..e6046c2 --- /dev/null +++ b/files/postgresql/pgsql.replication.lag.sql @@ -0,0 +1,18 @@ +SELECT + CASE + WHEN NOT pg_is_in_recovery() THEN + 'SELECT 0 AS value' + WHEN current_setting('server_version_num')::integer < 100000 THEN + 'SELECT ' + 'CASE WHEN pg_last_xlog_receive_location() = pg_last_xlog_replay_location() ' + 'THEN 0 ' + 'ELSE COALESCE(EXTRACT(EPOCH FROM now() - pg_last_xact_replay_timestamp())::integer, 0) ' + 'END AS value' + WHEN current_setting('server_version_num')::integer >= 100000 THEN + 'SELECT ' + 'CASE WHEN pg_last_wal_receive_lsn() = pg_last_wal_replay_lsn() ' + 'THEN 0 ' + 'ELSE COALESCE(EXTRACT(EPOCH FROM now() - pg_last_xact_replay_timestamp())::integer, 0) ' + 'END AS value' + END +\gexec diff --git a/files/postgresql/pgsql.replication.recovery_role.sql b/files/postgresql/pgsql.replication.recovery_role.sql new file mode 100644 index 0000000..b2c5dfa --- /dev/null +++ b/files/postgresql/pgsql.replication.recovery_role.sql @@ -0,0 +1 @@ +SELECT pg_is_in_recovery()::int diff --git a/files/postgresql/pgsql.replication.status.sql b/files/postgresql/pgsql.replication.status.sql new file mode 100644 index 0000000..2481562 --- /dev/null +++ b/files/postgresql/pgsql.replication.status.sql @@ -0,0 +1,21 @@ +DO LANGUAGE plpgsql $$ +DECLARE + ver integer; + res text := 2; +BEGIN + SELECT current_setting('server_version_num') INTO ver; + + IF (SELECT pg_is_in_recovery()) THEN + IF (ver >= 90600) THEN + SELECT * INTO res from ( + SELECT COUNT(*) FROM pg_stat_wal_receiver + ) T; + ELSE + res := 'ZBX_NOTSUPPORTED: Requires PostgreSQL version 9.6 or higher'; + END IF; + END IF; + + perform set_config('zbx_tmp.repl_status_res', res, false); +END $$; + +SELECT current_setting('zbx_tmp.repl_status_res'); diff --git a/files/postgresql/pgsql.scans.sql b/files/postgresql/pgsql.scans.sql new file mode 100644 index 0000000..9ff47ac --- /dev/null +++ b/files/postgresql/pgsql.scans.sql @@ -0,0 +1,9 @@ +WITH T AS ( + SELECT + sum(CASE WHEN relkind IN ('r', 't', 'm') THEN pg_stat_get_numscans(oid) END) seq, + sum(CASE WHEN relkind = 'i' THEN pg_stat_get_numscans(oid) END) idx + FROM pg_class + WHERE relkind IN ('r', 't', 'm', 'i') +) +SELECT row_to_json(T) +FROM T diff --git a/files/postgresql/pgsql.transactions.sql b/files/postgresql/pgsql.transactions.sql new file mode 100644 index 0000000..2b23019 --- /dev/null +++ b/files/postgresql/pgsql.transactions.sql @@ -0,0 +1,30 @@ +DO LANGUAGE plpgsql $$ +DECLARE + ver integer; + res text; +BEGIN + SELECT current_setting('server_version_num') INTO ver; + + IF (ver >= 90600) THEN + SELECT row_to_json(T) INTO res from ( + SELECT + coalesce(extract(epoch FROM max(CASE WHEN state = 'idle in transaction' THEN age(now(), query_start) END)), 0) AS idle, + coalesce(extract(epoch FROM max(CASE WHEN state <> 'idle in transaction' AND state <> 'idle' THEN age(now(), query_start) END)), 0) AS active, + coalesce(extract(epoch FROM max(CASE WHEN wait_event IS NOT NULL AND state='active' THEN age(now(), query_start) END)), 0) AS waiting, + (SELECT coalesce(extract(epoch FROM max(age(now(), prepared))), 0) FROM pg_prepared_xacts) AS prepared, + max(age(backend_xmin)) AS xmin_age + FROM pg_stat_activity WHERE backend_type='client backend') T; + ELSE + SELECT row_to_json(T) INTO res from ( + SELECT + coalesce(extract(epoch FROM max(CASE WHEN state = 'idle in transaction' THEN age(now(), query_start) END)), 0) AS idle, + coalesce(extract(epoch FROM max(CASE WHEN state <> 'idle in transaction' AND state <> 'idle' THEN age(now(), query_start) END)), 0) AS active, + coalesce(extract(epoch FROM max(CASE WHEN waiting IS TRUE THEN age(now(), query_start) END)), 0) AS waiting, + (SELECT coalesce(extract(epoch FROM max(age(now(), prepared))), 0) FROM pg_prepared_xacts) AS prepared + FROM pg_stat_activity) T; + END IF; + + perform set_config('zbx_tmp.trans_json_res', res, false); +END $$; + +SELECT current_setting('zbx_tmp.trans_json_res'); diff --git a/files/postgresql/pgsql.uptime.sql b/files/postgresql/pgsql.uptime.sql new file mode 100644 index 0000000..f21d7f2 --- /dev/null +++ b/files/postgresql/pgsql.uptime.sql @@ -0,0 +1 @@ +SELECT date_part('epoch', now() - pg_postmaster_start_time())::int diff --git a/files/postgresql/pgsql.wal.stat.sql b/files/postgresql/pgsql.wal.stat.sql new file mode 100644 index 0000000..2c234ab --- /dev/null +++ b/files/postgresql/pgsql.wal.stat.sql @@ -0,0 +1,26 @@ +DO LANGUAGE plpgsql $$ +DECLARE + ver integer; + res text := '{"write":0,"count":0}'; +BEGIN + SELECT current_setting('server_version_num') INTO ver; + + IF (SELECT NOT pg_is_in_recovery()) THEN + IF (ver >= 100000) THEN + SELECT row_to_json(T) INTO res FROM ( + SELECT pg_wal_lsn_diff(pg_current_wal_lsn(),'0/00000000') AS WRITE, + count(*) FROM pg_ls_waldir() AS COUNT + ) T; + + ELSE + SELECT row_to_json(T) INTO res FROM ( + SELECT pg_xlog_location_diff(pg_current_xlog_location(),'0/00000000') AS WRITE, + count(*) FROM pg_ls_dir('pg_xlog') AS COUNT + ) T; + END IF; + END IF; + + perform set_config('zbx_tmp.wal_json_res', res, false); +END $$; + +select current_setting('zbx_tmp.wal_json_res'); diff --git a/tasks/custom_agent.yml b/tasks/custom_agent.yml new file mode 100644 index 0000000..ab95044 --- /dev/null +++ b/tasks/custom_agent.yml @@ -0,0 +1,10 @@ +--- + +- name: '[POSTGRES] - Copy postgres checks related files' + copy: + src: 'files/postgresql' + dest: '/var/lib/zabbix/' + owner: 'zabbix' + group: 'zabbix' + loop: '{{ zabbix_agent_params }}' + when: zabbix_agent_params is defined and item.name == 'postgres' diff --git a/tasks/main.yml b/tasks/main.yml index 282acfa..99585ad 100644 --- a/tasks/main.yml +++ b/tasks/main.yml @@ -11,6 +11,10 @@ include: install_agent.yml when: zabbix_agent == 'true' +- name: Copy additional custom files for checks + include: custom_agent.yml + when: zabbix_agent == 'true' + - name: install Zabbix Proxy include: install_proxy.yml when: zabbix_proxy == 'true'