From ead608817b4d4c47993cc7241e45285fe6723587 Mon Sep 17 00:00:00 2001 From: Sergey Dudoladov Date: Thu, 19 Oct 2023 17:42:42 +0200 Subject: [PATCH 1/3] add function to monitor sequences --- postgres-appliance/scripts/metric_helpers.sql | 35 +++++++++++++++++++ 1 file changed, 35 insertions(+) diff --git a/postgres-appliance/scripts/metric_helpers.sql b/postgres-appliance/scripts/metric_helpers.sql index 89abd09c4..9df9512bd 100644 --- a/postgres-appliance/scripts/metric_helpers.sql +++ b/postgres-appliance/scripts/metric_helpers.sql @@ -193,6 +193,41 @@ $$ LANGUAGE sql IMMUTABLE SECURITY DEFINER STRICT; CREATE OR REPLACE VIEW pg_stat_statements AS SELECT * FROM pg_stat_statements(true); +CREATE OR REPLACE FUNCTION get_nearly_exhausted_sequences( + IN threshold float, + OUT schemaname name, + OUT sequencename name, + OUT max_value int8, + OUT increment_by int8, + OUT last_value int8, + OUT percent_used numeric + ) RETURNS SETOF record AS +$_$ +WITH t AS ( + SELECT + schemaname, + sequencename, + max_value, + increment_by, + last_value, + abs(last_value - start_value / increment_by)::numeric as used_sequence, + (max_value - min_value) / abs(increment_by)::numeric as sequence_capacity + FROM pg_sequences + WHERE last_value IS NOT NULL +) SELECT + schemaname, + sequencename, + max_value, + increment_by, + last_value, + round(used_sequence / sequence_capacity * 100, 2) as percent_used + FROM t + WHERE used_sequence / sequence_capacity > threshold +$_$ +LANGUAGE sql SECURITY DEFINER STRICT SET search_path to 'pg_catalog'; + +CREATE OR REPLACE VIEW nearly_exhausted_sequences AS SELECT * FROM get_nearly_exhausted_sequences(0.8); + REVOKE ALL ON ALL TABLES IN SCHEMA metric_helpers FROM public; GRANT SELECT ON ALL TABLES IN SCHEMA metric_helpers TO admin, robot_zmon; From 6c43272c2f29e159e9a28e45e5213829ba3557c2 Mon Sep 17 00:00:00 2001 From: Sergey Dudoladov Date: Fri, 3 Nov 2023 10:23:02 +0100 Subject: [PATCH 2/3] add a new query that covers many more cases --- postgres-appliance/scripts/metric_helpers.sql | 34 +++++++------------ 1 file changed, 12 insertions(+), 22 deletions(-) diff --git a/postgres-appliance/scripts/metric_helpers.sql b/postgres-appliance/scripts/metric_helpers.sql index 9df9512bd..a15e458fe 100644 --- a/postgres-appliance/scripts/metric_helpers.sql +++ b/postgres-appliance/scripts/metric_helpers.sql @@ -197,32 +197,22 @@ CREATE OR REPLACE FUNCTION get_nearly_exhausted_sequences( IN threshold float, OUT schemaname name, OUT sequencename name, - OUT max_value int8, - OUT increment_by int8, - OUT last_value int8, - OUT percent_used numeric + OUT seq_percent_used numeric ) RETURNS SETOF record AS $_$ -WITH t AS ( - SELECT - schemaname, - sequencename, - max_value, - increment_by, - last_value, - abs(last_value - start_value / increment_by)::numeric as used_sequence, - (max_value - min_value) / abs(increment_by)::numeric as sequence_capacity - FROM pg_sequences - WHERE last_value IS NOT NULL -) SELECT +SELECT * +FROM ( + SELECT schemaname, sequencename, - max_value, - increment_by, - last_value, - round(used_sequence / sequence_capacity * 100, 2) as percent_used - FROM t - WHERE used_sequence / sequence_capacity > threshold + round( + (abs(last_value::numeric - start_value) + 1) / + (CASE WHEN increment_by > 0 THEN (max_value::numeric - start_value) ELSE (start_value::numeric - min_value) END + 1) * 100, + 2) as seq_percent_used + FROM pg_sequences + WHERE NOT CYCLE AND last_value IS NOT NULL + ) AS s +WHERE seq_percent_used >= threshold; $_$ LANGUAGE sql SECURITY DEFINER STRICT SET search_path to 'pg_catalog'; From c82430a32ca6da87783df265192a50c6a481c7c4 Mon Sep 17 00:00:00 2001 From: Sergey Dudoladov Date: Tue, 9 Jan 2024 09:20:59 +0100 Subject: [PATCH 3/3] update query based on review --- postgres-appliance/scripts/metric_helpers.sql | 17 +++++++++++------ 1 file changed, 11 insertions(+), 6 deletions(-) diff --git a/postgres-appliance/scripts/metric_helpers.sql b/postgres-appliance/scripts/metric_helpers.sql index a15e458fe..5aa939993 100644 --- a/postgres-appliance/scripts/metric_helpers.sql +++ b/postgres-appliance/scripts/metric_helpers.sql @@ -202,16 +202,21 @@ CREATE OR REPLACE FUNCTION get_nearly_exhausted_sequences( $_$ SELECT * FROM ( - SELECT + SELECT schemaname, sequencename, - round( - (abs(last_value::numeric - start_value) + 1) / - (CASE WHEN increment_by > 0 THEN (max_value::numeric - start_value) ELSE (start_value::numeric - min_value) END + 1) * 100, - 2) as seq_percent_used + round(abs( + ceil((abs(last_value::numeric - start_value) + 1) / increment_by) / + floor((CASE WHEN increment_by > 0 + THEN (max_value::numeric - start_value) + ELSE (start_value::numeric - min_value) + END + 1) / increment_by + ) * 100 + ), + 2) AS seq_percent_used FROM pg_sequences WHERE NOT CYCLE AND last_value IS NOT NULL - ) AS s +) AS s WHERE seq_percent_used >= threshold; $_$ LANGUAGE sql SECURITY DEFINER STRICT SET search_path to 'pg_catalog';