From 19b1de99355b5dfe5321c8a1bdb994709ba383fd Mon Sep 17 00:00:00 2001 From: Tom Rogers Date: Mon, 24 Mar 2025 13:07:19 -0500 Subject: [PATCH] Add vacuum health monitoring with c77_dbh_vacuum_stats and c77_dbh_get_vacuum_health --- c77_dbh_vacuum_stats_table.sql | 15 ++++++++++ public.c77_dbh_get_vacuum_health.sql | 41 ++++++++++++++++++++++++++ public.c77_dbh_update_vacuum_stats.sql | 40 +++++++++++++++++++++++++ 3 files changed, 96 insertions(+) create mode 100644 c77_dbh_vacuum_stats_table.sql create mode 100644 public.c77_dbh_get_vacuum_health.sql create mode 100644 public.c77_dbh_update_vacuum_stats.sql diff --git a/c77_dbh_vacuum_stats_table.sql b/c77_dbh_vacuum_stats_table.sql new file mode 100644 index 0000000..8e8e5cd --- /dev/null +++ b/c77_dbh_vacuum_stats_table.sql @@ -0,0 +1,15 @@ +CREATE TABLE IF NOT EXISTS public.c77_dbh_vacuum_stats ( + table_name text COLLATE pg_catalog."default" PRIMARY KEY, -- Fully qualified table name (schema.table) + last_vacuum timestamp without time zone, -- Last manual vacuum + last_autovacuum timestamp without time zone, -- Last autovacuum + vacuum_count bigint DEFAULT 0, -- Number of vacuums + dead_tuples bigint DEFAULT 0, -- Estimated dead tuples + live_tuples bigint DEFAULT 0, -- Estimated live tuples + table_size bigint DEFAULT 0, -- Table size in bytes + bloat_estimate numeric DEFAULT 0, -- Estimated bloat percentage + last_updated timestamp without time zone DEFAULT now() -- Last stats update +); + +REVOKE ALL ON TABLE public.c77_dbh_vacuum_stats FROM PUBLIC; +GRANT SELECT ON TABLE public.c77_dbh_vacuum_stats TO PUBLIC; +GRANT ALL ON TABLE public.c77_dbh_vacuum_stats TO homestead; -- Adjust role as needed \ No newline at end of file diff --git a/public.c77_dbh_get_vacuum_health.sql b/public.c77_dbh_get_vacuum_health.sql new file mode 100644 index 0000000..772c97a --- /dev/null +++ b/public.c77_dbh_get_vacuum_health.sql @@ -0,0 +1,41 @@ +CREATE OR REPLACE FUNCTION public.c77_dbh_get_vacuum_health() + RETURNS JSON AS $$ +BEGIN + RETURN ( + SELECT json_agg( + json_build_object( + 'metric', 'Table Vacuum Health', + 'table_name', table_name, + 'status', CASE + WHEN bloat_estimate > 50 THEN 'Red' + WHEN bloat_estimate > 20 THEN 'Yellow' + ELSE 'Green' + END, + 'severity', CASE + WHEN bloat_estimate > 50 THEN 5 + WHEN bloat_estimate > 20 THEN 3 + ELSE 1 + END, + 'insight', CASE + WHEN bloat_estimate > 50 THEN 'Table has critical bloat; vacuum and analyze urgently.' + WHEN bloat_estimate > 20 THEN 'Table has moderate bloat; consider vacuuming.' + ELSE 'Table is in good health.' + END, + 'action', CASE + WHEN bloat_estimate > 50 THEN 'Run VACUUM FULL or CLUSTER; check autovacuum settings.' + WHEN bloat_estimate > 20 THEN 'Run VACUUM and ANALYZE; monitor autovacuum.' + ELSE 'No action needed.' + END, + 'last_vacuum', last_vacuum::text, + 'last_autovacuum', last_autovacuum::text, + 'vacuum_count', vacuum_count, + 'dead_tuples', dead_tuples, + 'live_tuples', live_tuples, + 'table_size', table_size::text || ' bytes', + 'bloat_estimate', bloat_estimate::text || '%' + ) + ) + FROM public.c77_dbh_vacuum_stats + ); +END; +$$ LANGUAGE plpgsql; \ No newline at end of file diff --git a/public.c77_dbh_update_vacuum_stats.sql b/public.c77_dbh_update_vacuum_stats.sql new file mode 100644 index 0000000..a238332 --- /dev/null +++ b/public.c77_dbh_update_vacuum_stats.sql @@ -0,0 +1,40 @@ +CREATE OR REPLACE FUNCTION public.c77_dbh_update_vacuum_stats() + RETURNS void AS $$ +BEGIN + -- Insert or update vacuum stats for all user tables + INSERT INTO public.c77_dbh_vacuum_stats ( + table_name, last_vacuum, last_autovacuum, vacuum_count, + dead_tuples, live_tuples, table_size, last_updated + ) + SELECT + (n.nspname || '.' || c.relname) AS table_name, + s.last_vacuum, + s.last_autovacuum, + COALESCE(s.vacuum_count, 0) + COALESCE(s.autovacuum_count, 0) AS vacuum_count, + s.n_dead_tup AS dead_tuples, + s.n_live_tup AS live_tuples, + pg_relation_size(c.oid) AS table_size, + now() AS last_updated + FROM pg_stat_all_tables s + JOIN pg_class c ON c.oid = s.relid + JOIN pg_namespace n ON n.oid = c.relnamespace + WHERE n.nspname NOT IN ('pg_catalog', 'information_schema') + ON CONFLICT (table_name) DO UPDATE + SET + last_vacuum = EXCLUDED.last_vacuum, + last_autovacuum = EXCLUDED.last_autovacuum, + vacuum_count = EXCLUDED.vacuum_count, + dead_tuples = EXCLUDED.dead_tuples, + live_tuples = EXCLUDED.live_tuples, + table_size = EXCLUDED.table_size, + last_updated = EXCLUDED.last_updated; + + -- Estimate bloat (simple heuristic for now; requires pgstattuple for precision) + UPDATE public.c77_dbh_vacuum_stats + SET bloat_estimate = CASE + WHEN live_tuples + dead_tuples = 0 THEN 0 + ELSE ROUND((dead_tuples::numeric / (live_tuples + dead_tuples)) * 100, 2) + END + WHERE last_updated = now(); +END; +$$ LANGUAGE plpgsql; \ No newline at end of file