CREATE OR REPLACE FUNCTION public.c77_dbh_get_vacuum_health() RETURNS JSON AS $$ DECLARE v_median_bloat numeric; v_bloat_stddev numeric; v_has_pgstattuple boolean; BEGIN SELECT EXISTS ( SELECT 1 FROM pg_extension WHERE extname = 'pgstattuple' ) INTO v_has_pgstattuple; -- Calculate median and stddev including TOAST-adjusted bloat WITH toast_bloat AS ( SELECT (n.nspname || '.' || c.relname) AS table_name, CASE WHEN v_has_pgstattuple THEN COALESCE((pgstattuple(c.oid)).free_percent + (pgstattuple(c.oid)).dead_tuple_percent, 0) ELSE CASE WHEN s.n_live_tup + s.n_dead_tup = 0 THEN 0 ELSE (s.n_dead_tup::numeric / (s.n_live_tup + s.n_dead_tup)) * 100 END END AS bloat_estimate 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') ) SELECT percentile_cont(0.5) WITHIN GROUP (ORDER BY bloat_estimate), stddev(bloat_estimate) INTO v_median_bloat, v_bloat_stddev FROM toast_bloat; RETURN ( SELECT json_agg( json_build_object( 'metric', 'Table Vacuum Health', 'table_name', v.table_name, 'status', CASE WHEN (v.bloat_estimate + COALESCE(t.toast_bloat, 0)) > v_median_bloat + 2 * v_bloat_stddev THEN 'Red' WHEN (v.bloat_estimate + COALESCE(t.toast_bloat, 0)) > v_median_bloat + v_bloat_stddev THEN 'Yellow' ELSE 'Green' END, 'severity', CASE WHEN (v.bloat_estimate + COALESCE(t.toast_bloat, 0)) > v_median_bloat + 2 * v_bloat_stddev THEN 5 WHEN (v.bloat_estimate + COALESCE(t.toast_bloat, 0)) > v_median_bloat + v_bloat_stddev THEN 3 ELSE 1 END, 'insight', CASE WHEN (v.bloat_estimate + COALESCE(t.toast_bloat, 0)) > v_median_bloat + 2 * v_bloat_stddev THEN 'Table bloat is critically high' || (CASE WHEN t.toast_bloat > v.bloat_estimate THEN '; TOAST overhead is significant.' ELSE '.' END) WHEN (v.bloat_estimate + COALESCE(t.toast_bloat, 0)) > v_median_bloat + v_bloat_stddev THEN 'Table bloat is above average' || (CASE WHEN t.toast_bloat > v.bloat_estimate THEN '; TOAST overhead notable.' ELSE '.' END) ELSE 'Table bloat is within normal range.' END, 'action', CASE WHEN (v.bloat_estimate + COALESCE(t.toast_bloat, 0)) > v_median_bloat + 2 * v_bloat_stddev THEN 'Run VACUUM FULL or CLUSTER' || (CASE WHEN t.toast_bloat > v.bloat_estimate THEN '; review large fields for TOAST impact.' ELSE '.' END) WHEN (v.bloat_estimate + COALESCE(t.toast_bloat, 0)) > v_median_bloat + v_bloat_stddev THEN 'Run VACUUM and ANALYZE' || (CASE WHEN t.toast_bloat > v.bloat_estimate THEN '; check TOAST usage.' ELSE '.' END) ELSE 'No immediate action required.' END, 'last_vacuum', v.last_vacuum::text, 'last_autovacuum', v.last_autovacuum::text, 'vacuum_count', v.vacuum_count, 'dead_tuples', v.dead_tuples, 'live_tuples', v.live_tuples, 'table_size', pg_size_pretty(v.table_size), 'bloat_estimate', v.bloat_estimate::text || '%' || (CASE WHEN v_has_pgstattuple THEN ' (precise)' ELSE ' (estimated)' END), 'details', json_build_object( 'median_bloat', round(v_median_bloat)::text || '%', 'bloat_stddev', round(v_bloat_stddev)::text || '%', 'toast_bloat', round(COALESCE(t.toast_bloat, 0))::text || '%', 'explanation', 'Includes TOAST bloat in total health assessment.' ) ) ) FROM public.c77_dbh_vacuum_stats v LEFT JOIN ( SELECT (n.nspname || '.' || c.relname) AS table_name, CASE WHEN v_has_pgstattuple THEN COALESCE((pgstattuple(tst.oid)).free_percent + (pgstattuple(tst.oid)).dead_tuple_percent, 0) ELSE 0 END AS toast_bloat FROM pg_class c JOIN pg_namespace n ON n.oid = c.relnamespace LEFT JOIN pg_class tst ON tst.oid = c.reltoastrelid WHERE n.nspname NOT IN ('pg_catalog', 'information_schema') AND c.reltoastrelid != 0 ) t ON v.table_name = t.table_name ); END; $$ LANGUAGE plpgsql;