CREATE TABLE IF NOT EXISTS public.c77_dbh_index_stats ( index_name text COLLATE pg_catalog."default" PRIMARY KEY, -- Fully qualified index name table_name text, -- Associated table index_size bigint DEFAULT 0, -- Size in bytes scan_count bigint DEFAULT 0, -- Number of scans bloat_estimate numeric DEFAULT 0, -- Estimated bloat percentage last_updated timestamp without time zone DEFAULT now() -- Last stats update ); CREATE OR REPLACE FUNCTION public.c77_dbh_update_index_stats() RETURNS void AS $$ DECLARE v_has_pgstattuple boolean; BEGIN SELECT EXISTS ( SELECT 1 FROM pg_extension WHERE extname = 'pgstattuple' ) INTO v_has_pgstattuple; INSERT INTO public.c77_dbh_index_stats ( index_name, table_name, index_size, scan_count, bloat_estimate, last_updated ) SELECT (n.nspname || '.' || i.relname) AS index_name, (n.nspname || '.' || t.relname) AS table_name, pg_relation_size(i.oid) AS index_size, COALESCE(s.idx_scan, 0) AS scan_count, CASE WHEN v_has_pgstattuple THEN ROUND(CAST(COALESCE((pgstattuple(i.oid)).free_percent + (pgstattuple(i.oid)).dead_tuple_percent, 0) AS numeric), 2) ELSE 0 -- Placeholder; could estimate based on size vs. usage END AS bloat_estimate, now() AS last_updated FROM pg_index ix JOIN pg_class i ON i.oid = ix.indexrelid JOIN pg_class t ON t.oid = ix.indrelid JOIN pg_namespace n ON n.oid = i.relnamespace LEFT JOIN pg_stat_all_indexes s ON s.indexrelid = i.oid WHERE n.nspname NOT IN ('pg_catalog', 'information_schema') ON CONFLICT (index_name) DO UPDATE SET table_name = EXCLUDED.table_name, index_size = EXCLUDED.index_size, scan_count = EXCLUDED.scan_count, bloat_estimate = EXCLUDED.bloat_estimate, last_updated = EXCLUDED.last_updated; END; $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION public.c77_dbh_get_index_health() RETURNS JSON AS $$ DECLARE v_median_bloat numeric; v_median_usage numeric; BEGIN SELECT percentile_cont(0.5) WITHIN GROUP (ORDER BY bloat_estimate), percentile_cont(0.5) WITHIN GROUP (ORDER BY scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0)) INTO v_median_bloat, v_median_usage FROM public.c77_dbh_index_stats WHERE index_name NOT LIKE 'pg_toast.%'; RETURN ( SELECT json_agg( json_build_object( 'metric', 'Index Health', 'index_name', index_name, 'table_name', table_name, 'status', CASE WHEN bloat_estimate > v_median_bloat * 2 OR scan_count = 0 THEN 'Red' WHEN bloat_estimate > v_median_bloat * 1.2 OR (scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0)) < v_median_usage * 0.5 THEN 'Yellow' ELSE 'Green' END, 'severity', CASE WHEN bloat_estimate > v_median_bloat * 2 OR scan_count = 0 THEN 5 WHEN bloat_estimate > v_median_bloat * 1.2 OR (scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0)) < v_median_usage * 0.5 THEN 3 ELSE 1 END, 'insight', CASE WHEN scan_count = 0 THEN 'Index is unused; consider dropping.' WHEN bloat_estimate > v_median_bloat * 2 THEN 'Index bloat is critically high.' WHEN (scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0)) < v_median_usage * 0.5 THEN 'Index usage is low relative to size.' ELSE 'Index is healthy and well-utilized.' END, 'action', CASE WHEN scan_count = 0 THEN 'Drop the index if not needed.' WHEN bloat_estimate > v_median_bloat * 2 THEN 'Run REINDEX; check autovacuum.' WHEN (scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0)) < v_median_usage * 0.5 THEN 'Review query patterns or consider reindexing.' ELSE 'No action needed.' END, 'index_size', pg_size_pretty(index_size), 'scan_count', scan_count, 'bloat_estimate', bloat_estimate::text || '%', 'details', json_build_object( 'usage_rate', round((scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0))::numeric, 2)::text || ' scans/MB', 'median_bloat', round(v_median_bloat)::text || '%', 'median_usage', round(v_median_usage, 2)::text || ' scans/MB' ) ) ) FROM public.c77_dbh_index_stats WHERE index_name NOT LIKE 'pg_toast.%' ); END; $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION public.c77_dbh_get_toast_health() RETURNS JSON AS $$ DECLARE v_median_bloat numeric; v_median_usage numeric; v_has_pgstattuple boolean; BEGIN SELECT EXISTS ( SELECT 1 FROM pg_extension WHERE extname = 'pgstattuple' ) INTO v_has_pgstattuple; SELECT percentile_cont(0.5) WITHIN GROUP (ORDER BY bloat_estimate), percentile_cont(0.5) WITHIN GROUP (ORDER BY scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0)) INTO v_median_bloat, v_median_usage FROM public.c77_dbh_index_stats WHERE index_name LIKE 'pg_toast.%'; RETURN ( SELECT json_agg( json_build_object( 'metric', 'TOAST Index Health', 'index_name', index_name, 'parent_table', table_name, 'status', CASE WHEN bloat_estimate > v_median_bloat * 2 OR scan_count = 0 THEN 'Red' WHEN bloat_estimate > v_median_bloat * 1.2 OR (scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0)) < v_median_usage * 0.5 THEN 'Yellow' ELSE 'Green' END, 'severity', CASE WHEN bloat_estimate > v_median_bloat * 2 OR scan_count = 0 THEN 5 WHEN bloat_estimate > v_median_bloat * 1.2 OR (scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0)) < v_median_usage * 0.5 THEN 3 ELSE 1 END, 'insight', CASE WHEN scan_count = 0 THEN 'TOAST index is unused; parent table may not need toasted columns indexed.' WHEN bloat_estimate > v_median_bloat * 2 THEN 'TOAST index bloat is critically high.' WHEN (scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0)) < v_median_usage * 0.5 THEN 'TOAST index usage is low relative to size.' ELSE 'TOAST index is healthy and well-utilized.' END, 'action', CASE WHEN scan_count = 0 THEN 'Review parent table queries; consider dropping TOAST index.' WHEN bloat_estimate > v_median_bloat * 2 THEN 'Run REINDEX on TOAST table; optimize large fields in parent.' WHEN (scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0)) < v_median_usage * 0.5 THEN 'Check parent table usage patterns.' ELSE 'No action needed.' END, 'index_size', pg_size_pretty(index_size), 'scan_count', scan_count, 'bloat_estimate', bloat_estimate::text || '%' || (CASE WHEN v_has_pgstattuple THEN ' (precise)' ELSE ' (estimated)' END), 'details', json_build_object( 'usage_rate', round((scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0))::numeric, 2)::text || ' scans/MB', 'median_bloat', round(v_median_bloat)::text || '%', 'median_usage', round(v_median_usage, 2)::text || ' scans/MB', 'parent_columns', ( SELECT string_agg(attname, ', ') FROM pg_attribute a JOIN pg_class c ON c.oid = (SELECT oid FROM pg_class WHERE relname = split_part(table_name, '.', 2) AND relnamespace = (SELECT oid FROM pg_namespace WHERE nspname = split_part(table_name, '.', 1))) WHERE a.attrelid = c.oid AND a.attlen = -1 -- Variable-length columns likely toasted ) ) ) ) FROM public.c77_dbh_index_stats WHERE index_name LIKE 'pg_toast.%' ); END; $$ LANGUAGE plpgsql;