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( '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 || '%' || (CASE WHEN v_has_pgstattuple THEN ' (precise)' ELSE ' (estimated)' END) ) ) FROM public.c77_dbh_vacuum_stats ); END; $$ LANGUAGE plpgsql;