diff --git a/public.c77_dbh_get_vacuum_health.sql b/public.c77_dbh_get_vacuum_health.sql index 772c97a..a163c08 100644 --- a/public.c77_dbh_get_vacuum_health.sql +++ b/public.c77_dbh_get_vacuum_health.sql @@ -1,6 +1,13 @@ CREATE OR REPLACE FUNCTION public.c77_dbh_get_vacuum_health() RETURNS JSON AS $$ +DECLARE + v_has_pgstattuple boolean; BEGIN + -- Check if pgstattuple is installed + SELECT EXISTS ( + SELECT 1 FROM pg_extension WHERE extname = 'pgstattuple' + ) INTO v_has_pgstattuple; + RETURN ( SELECT json_agg( json_build_object( @@ -32,7 +39,8 @@ BEGIN 'dead_tuples', dead_tuples, 'live_tuples', live_tuples, 'table_size', table_size::text || ' bytes', - 'bloat_estimate', bloat_estimate::text || '%' + 'bloat_estimate', bloat_estimate::text || '%' || + (CASE WHEN v_has_pgstattuple THEN ' (precise)' ELSE ' (estimated)' END) ) ) FROM public.c77_dbh_vacuum_stats diff --git a/public.c77_dbh_update_vacuum_stats.sql b/public.c77_dbh_update_vacuum_stats.sql index a238332..fb5c1e1 100644 --- a/public.c77_dbh_update_vacuum_stats.sql +++ b/public.c77_dbh_update_vacuum_stats.sql @@ -1,6 +1,13 @@ CREATE OR REPLACE FUNCTION public.c77_dbh_update_vacuum_stats() RETURNS void AS $$ +DECLARE + v_has_pgstattuple boolean; BEGIN + -- Check if pgstattuple is installed + SELECT EXISTS ( + SELECT 1 FROM pg_extension WHERE extname = 'pgstattuple' + ) INTO v_has_pgstattuple; + -- Insert or update vacuum stats for all user tables INSERT INTO public.c77_dbh_vacuum_stats ( table_name, last_vacuum, last_autovacuum, vacuum_count, @@ -29,12 +36,26 @@ BEGIN 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(); + -- Update bloat estimate + IF v_has_pgstattuple THEN + -- Use pgstattuple for precise bloat if available + UPDATE public.c77_dbh_vacuum_stats v + SET bloat_estimate = ROUND(CAST(COALESCE(t.free_percent + t.dead_tuple_percent, 0) AS numeric), 2) + FROM ( + SELECT (pgstattuple(c.oid)).* + FROM pg_class c + JOIN pg_namespace n ON n.oid = c.relnamespace + WHERE (n.nspname || '.' || c.relname) = v.table_name + ) t + WHERE v.last_updated = now(); + ELSE + -- Fallback to heuristic bloat estimate + 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 IF; END; $$ LANGUAGE plpgsql; \ No newline at end of file