added custom file tasks

This commit is contained in:
muppeth 2023-05-12 21:58:11 +02:00
parent 013f6a2ae5
commit 30754c0ea7
22 changed files with 366 additions and 0 deletions

View File

@ -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

View File

@ -0,0 +1,2 @@
SELECT round(sum(blks_hit)*100/sum(blks_hit+blks_read), 2)
FROM pg_stat_database

View File

@ -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);

View File

@ -0,0 +1,2 @@
SELECT count(*)
FROM pg_prepared_xacts

View File

@ -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');

View File

@ -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');

View File

@ -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

View File

@ -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

View File

@ -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

View File

@ -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;

View File

@ -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

View File

@ -0,0 +1,2 @@
\timing
SELECT 1;

View File

@ -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

View File

@ -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

View File

@ -0,0 +1 @@
SELECT pg_is_in_recovery()::int

View File

@ -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');

View File

@ -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

View File

@ -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');

View File

@ -0,0 +1 @@
SELECT date_part('epoch', now() - pg_postmaster_start_time())::int

View File

@ -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');

10
tasks/custom_agent.yml Normal file
View File

@ -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'

View File

@ -14,6 +14,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'