diff --git a/Changes b/Changes new file mode 100644 index 0000000..88eca10 --- /dev/null +++ b/Changes @@ -0,0 +1,14 @@ +PGTelemetry Change Log + +2017-09-30 1.0 First full stable release + * Fixed wal telemetry on slaves + * Added lock detail metrics + +2017-08-23 0.2 First release on pgxn + * Support for PostgreSQL 10 added + * Support for wal telemetry on slaves + +2017-08-08 0.1 First semi-public release + * Basic metrics + * Some Zabbix alert scripts + * A sample Prometheus postgres_exporter config diff --git a/extension/pgtelemetry--0.1--1.0.sql b/extension/pgtelemetry--0.1--1.0.sql new file mode 100644 index 0000000..0711e9b --- /dev/null +++ b/extension/pgtelemetry--0.1--1.0.sql @@ -0,0 +1,103 @@ + +-- cheating but needed to make plans safe on replicas. +create function is_replica() returns bool language sql IMMUTABLE +AS $$ + select pg_is_in_recovery(); +$$; + + +-- 9.6-compatibility for PostgreSQL 10 and above +do $d$ begin +if version() not like 'PostgreSQL 9.%' then + CREATE FUNCTION pg_current_xlog_location() RETURNS pg_lsn language sql as $$ + select pg_current_wal_lsn(); + $$; + CREATE FUNCTION pg_last_xlog_replay_location() returns pg_lsn language sql as $$ + select pg_last_wal_replay_lsn(); + $$; +end if; +end;$d$ language plpgsql; + +create or replace function wal_telemetry() returns table ( + current_epoch numeric, last_epoch numeric, secs_elapsed numeric, + current_lsn pg_lsn, last_lsn pg_lsn, bytes_elapsed numeric, + bytes_per_sec numeric +) language sql as $$ +WITH insert_record AS ( + insert into pg_telemetry_wal_log + select extract('epoch' from now()), now(), + pg_current_xlog_location() as wal_location + WHERE NOT is_replica() + returning * + ), current_record AS ( + select * from insert_record where not is_replica() + UNION + SELECT * from pg_telemetry_wal_log + WHERE is_replica() + order by run_time desc limit 1 + ) + select c.run_time as current_epoch, l.run_time as last_epoch, + c.run_time - l.run_time as secs_elapsed, + c.lsn as current_lsn, l.lsn as last_lsn, + c.lsn - l.lsn as bytes_elapsed, + (c.lsn - l.lsn)::numeric / (c.run_time - l.run_time) as bytes_per_sec + FROM current_record c, + lateral (select * from pg_telemetry_wal_log where run_time < c.run_time + order by run_time desc limit 1) l; +$$ set search_path from current; + +select wal_telemetry(); + +comment on function wal_telemetry() is $$ +The wal_telemetry() function checks the current wal location and compares +with the last entry in the pg_telemetry_wal_log. It then provides for you +both current and last data, and the differences between them. These include +bytes elapsed and seconds elapsed, and bytes per sec. + +The function is designed so that you can export delta information to a monitoring +solution such as munin or prometheus without the latter having to know anything +about lsn representation or losing information in the process. + +On a replica this does not write to the table and measures deltas from the last +this was written on the master. +$$; + + +create function wal_telemetry_create_or_select_record() +returns pg_telemetry_wal_log language plpgsql as +$$ +declare log_entry pg_telemetry_wal_log; +begin + if pg_is_in_recovery() then + select * into log_entry from pg_telemetry_wal_log order by run_time desc limit 1; + else + insert into pg_telemetry_wal_log + select extract('epoch' from now()), now(), + pg_current_xlog_location() as wal_location + returning * into log_entry; + end if; + return log_entry; +end; +$$; + +create or replace function wal_telemetry() returns table ( + current_epoch numeric, last_epoch numeric, secs_elapsed numeric, + current_lsn pg_lsn, last_lsn pg_lsn, bytes_elapsed numeric, + bytes_per_sec numeric +) language sql as $$ + select c.run_time as current_epoch, l.run_time as last_epoch, + c.run_time - l.run_time as secs_elapsed, + c.lsn as current_lsn, l.lsn as last_lsn, + c.lsn - l.lsn as bytes_elapsed, + (c.lsn - l.lsn)::numeric / (c.run_time - l.run_time) as bytes_per_sec + FROM wal_telemetry_create_or_select_record() c, + lateral (select * from pg_telemetry_wal_log where run_time < c.run_time + order by run_time desc limit 1) l; +$$ set search_path from current; + +select wal_telemetry(); + +CREATE VIEW waiting_queries_reason_details AS +select wait_event_type, wait_event, count(*) from pg_stat_activity + WHERE wait_event is not null + GROUP BY wait_event_type, wait_event; diff --git a/extension/pgtelemetry--0.2--1.0.sql b/extension/pgtelemetry--0.2--1.0.sql index 96d7eb1..e9076fb 100644 --- a/extension/pgtelemetry--0.2--1.0.sql +++ b/extension/pgtelemetry--0.2--1.0.sql @@ -5,24 +5,22 @@ $$ declare log_entry pg_telemetry_wal_log; begin if pg_is_in_recovery() then - select * into log_entry from pg_telemetry_wal_log order by current_epoch desc limit 1; + select * into log_entry from pg_telemetry_wal_log order by run_time desc limit 1; else insert into pg_telemetry_wal_log select extract('epoch' from now()), now(), - pg_current_xlog_location() end as wal_location - WHERE NOT is_replica() + pg_current_xlog_location() as wal_location returning * into log_entry; end if; return log_entry; end; $$; -create function wal_telemetry() returns table ( +create or replace function wal_telemetry() returns table ( current_epoch numeric, last_epoch numeric, secs_elapsed numeric, current_lsn pg_lsn, last_lsn pg_lsn, bytes_elapsed numeric, bytes_per_sec numeric ) language sql as $$ -WITH insert_record AS select c.run_time as current_epoch, l.run_time as last_epoch, c.run_time - l.run_time as secs_elapsed, c.lsn as current_lsn, l.lsn as last_lsn, @@ -38,4 +36,4 @@ select wal_telemetry(); CREATE VIEW waiting_queries_reason_details AS select wait_event_type, wait_event, count(*) from pg_stat_activity WHERE wait_event is not null - GROUP BY wait_event_type, wait_event;` + GROUP BY wait_event_type, wait_event; diff --git a/extension/pgtelemetry--1.0.sql b/extension/pgtelemetry--1.0.sql index 68da8a1..7f4fa64 100644 --- a/extension/pgtelemetry--1.0.sql +++ b/extension/pgtelemetry--1.0.sql @@ -11,7 +11,7 @@ if version() not like 'PostgreSQL 9.%' then CREATE FUNCTION pg_current_xlog_location() RETURNS pg_lsn language sql as $$ select pg_current_wal_lsn(); $$; - CREATE FUNCTION pg_last_xlog_replay_location returns pg_lsn language sql as $$ + CREATE FUNCTION pg_last_xlog_replay_location() returns pg_lsn language sql as $$ select pg_last_wal_replay_lsn(); $$; end if; @@ -151,7 +151,7 @@ select case when wait_event is null then state else 'waiting' end as state, CREATE VIEW waiting_queries_reason_details AS select wait_event_type, wait_event, count(*) from pg_stat_activity WHERE wait_event is not null - GROUP BY wait_event_type, wait_event;` + GROUP BY wait_event_type, wait_event; comment on view connections_by_state is @@ -337,12 +337,11 @@ $$ declare log_entry pg_telemetry_wal_log; begin if pg_is_in_recovery() then - select * into log_entry from pg_telemetry_wal_log order by current_epoch desc limit 1; + select * into log_entry from pg_telemetry_wal_log order by run_time desc limit 1; else insert into pg_telemetry_wal_log select extract('epoch' from now()), now(), - pg_current_xlog_location() end as wal_location - WHERE NOT is_replica() + pg_current_xlog_location() as wal_location returning * into log_entry; end if; return log_entry; @@ -354,7 +353,6 @@ create function wal_telemetry() returns table ( current_lsn pg_lsn, last_lsn pg_lsn, bytes_elapsed numeric, bytes_per_sec numeric ) language sql as $$ -WITH insert_record AS select c.run_time as current_epoch, l.run_time as last_epoch, c.run_time - l.run_time as secs_elapsed, c.lsn as current_lsn, l.lsn as last_lsn,