CREATE OR REPLACE FUNCTION public.c77_dbh_get_mv_health() RETURNS JSON AS $$ DECLARE v_has_pg_stat_statements boolean; -- Check if extension is available v_stats_reset timestamp; -- Time of last stats reset v_base_io_load numeric; -- Fallback I/O load v_base_mem_hit_ratio numeric; -- Fallback memory hit ratio BEGIN -- Check if pg_stat_statements is installed SELECT EXISTS ( SELECT 1 FROM pg_extension WHERE extname = 'pg_stat_statements' ) INTO v_has_pg_stat_statements; -- Get stats_reset, base I/O load, and base memory hit ratio for the current database SELECT d.stats_reset, (d.blks_read + d.blks_hit) / EXTRACT(EPOCH FROM (NOW() - d.stats_reset)), CASE WHEN b.buffers_clean + b.buffers_backend = 0 THEN 1.0 ELSE b.buffers_clean::numeric / (b.buffers_clean + b.buffers_backend) END INTO v_stats_reset, v_base_io_load, v_base_mem_hit_ratio FROM pg_stat_database d CROSS JOIN pg_stat_bgwriter b WHERE d.datname = current_database(); RETURN ( SELECT json_agg( json_build_object( 'metric', 'Materialized View Refresh', 'mv_name', m.mv_name, 'status', CASE WHEN m.refresh_mv_time_last > m.refresh_mv_time_max * 0.9 THEN 'Red' WHEN m.refresh_mv_time_last > (m.refresh_mv_time_total / GREATEST(m.refresh_count, 1)) * 1.2 THEN 'Yellow' ELSE 'Green' END, 'severity', CASE WHEN m.refresh_mv_time_last > m.refresh_mv_time_max * 0.9 THEN 5 WHEN m.refresh_mv_time_last > (m.refresh_mv_time_total / GREATEST(m.refresh_count, 1)) * 1.2 THEN 3 ELSE 1 END, 'insight', CASE WHEN v_io_load > 100 THEN 'Refreshes are slower due to high I/O load.' WHEN v_cpu_time > (CASE WHEN v_has_pg_stat_statements THEN 1000 ELSE 0.5 END) THEN 'Refreshes are slower due to CPU usage.' WHEN v_mem_hit_ratio < 0.9 THEN 'Refreshes are slower due to memory pressure.' ELSE 'Refreshes are performing normally.' END, 'action', CASE WHEN v_io_load > 100 THEN 'Optimize I/O or schedule during off-peak hours.' WHEN v_cpu_time > (CASE WHEN v_has_pg_stat_statements THEN 1000 ELSE 0.5 END) THEN 'Increase CPU capacity or optimize queries.' WHEN v_mem_hit_ratio < 0.9 THEN 'Adjust memory settings (e.g., work_mem, shared_buffers).' ELSE 'No action needed.' END, 'last_refresh_time', m.refresh_mv_time_last::text, 'refresh_count', m.refresh_count, 'io_load', round(v_io_load)::text || ' blocks/sec', 'cpu_time', (CASE WHEN v_has_pg_stat_statements THEN round(v_cpu_time)::text || ' ms/call' ELSE (v_cpu_time * 100)::text || '% waiting' END), 'buffer_hit_ratio', round(v_mem_hit_ratio * 100)::text || '%', 'bottleneck', CASE WHEN v_io_load > 100 THEN 'I/O' WHEN v_cpu_time > (CASE WHEN v_has_pg_stat_statements THEN 1000 ELSE 0.5 END) THEN 'CPU' WHEN v_mem_hit_ratio < 0.9 THEN 'RAM' ELSE 'None' END ) ) FROM public.c77_dbh_mv_stats m CROSS JOIN LATERAL ( -- Calculate bottleneck stats per MV SELECT CASE WHEN v_has_pg_stat_statements THEN COALESCE(SUM(s.shared_blks_read) / EXTRACT(EPOCH FROM (NOW() - v_stats_reset)), 0) ELSE v_base_io_load END AS v_io_load, CASE WHEN v_has_pg_stat_statements THEN COALESCE(SUM(s.total_time) / GREATEST(SUM(s.calls), 1), 0) ELSE CASE WHEN EXISTS ( SELECT 1 FROM pg_stat_activity WHERE query ILIKE '%REFRESH MATERIALIZED VIEW ' || m.mv_name || '%' AND wait_event_type = 'CPU' AND state = 'active' ) THEN 1 ELSE 0 END END AS v_cpu_time, CASE WHEN v_has_pg_stat_statements THEN CASE WHEN SUM(s.shared_blks_hit + s.shared_blks_read) = 0 THEN 1.0 ELSE SUM(s.shared_blks_hit)::numeric / (SUM(s.shared_blks_hit) + SUM(s.shared_blks_read)) END ELSE v_base_mem_hit_ratio END AS v_mem_hit_ratio FROM ( -- Subquery to avoid duplicate logic SELECT 1 AS dummy ) AS dummy LEFT JOIN pg_stat_statements s ON v_has_pg_stat_statements AND s.query ILIKE '%REFRESH MATERIALIZED VIEW ' || m.mv_name || '%' AND s.dbid = (SELECT datid FROM pg_stat_database WHERE datname = current_database()) ) AS stats ); END; $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION public.c77_dbh_get_mv_details(p_mv_name text) RETURNS JSON AS $$ DECLARE v_io_load numeric; -- Blocks read per second v_cpu_time numeric; -- CPU time per call (ms) v_mem_hit_ratio numeric; -- Cache hit ratio v_has_pg_stat_statements boolean; -- Check if extension is available v_stats_reset timestamp; -- Time of last stats reset BEGIN -- Check if pg_stat_statements is installed SELECT EXISTS ( SELECT 1 FROM pg_extension WHERE extname = 'pg_stat_statements' ) INTO v_has_pg_stat_statements; -- Get stats_reset separately for the current database SELECT stats_reset INTO v_stats_reset FROM pg_stat_database WHERE datname = current_database(); -- If pg_stat_statements is available, use it for refined stats IF v_has_pg_stat_statements THEN SELECT COALESCE(SUM(s.shared_blks_read) / EXTRACT(EPOCH FROM (NOW() - v_stats_reset)), 0) AS io_load, COALESCE(SUM(s.total_time) / GREATEST(SUM(s.calls), 1), 0) AS cpu_time, CASE WHEN SUM(s.shared_blks_hit + s.shared_blks_read) = 0 THEN 1.0 ELSE SUM(s.shared_blks_hit)::numeric / (SUM(s.shared_blks_hit) + SUM(s.shared_blks_read)) END AS mem_hit_ratio INTO v_io_load, v_cpu_time, v_mem_hit_ratio FROM pg_stat_statements s JOIN pg_stat_database d ON s.dbid = d.datid WHERE s.query ILIKE '%REFRESH MATERIALIZED VIEW ' || p_mv_name || '%' AND d.datname = current_database(); ELSE -- Fallback to basic stats without pg_stat_statements SELECT (d.blks_read + d.blks_hit) / EXTRACT(EPOCH FROM (NOW() - d.stats_reset)) AS io_load, EXISTS ( SELECT 1 FROM pg_stat_activity WHERE query ILIKE '%REFRESH MATERIALIZED VIEW%' AND wait_event_type = 'CPU' AND state = 'active' )::numeric AS cpu_time, -- 1 if waiting, 0 if not (crude proxy) CASE WHEN b.buffers_clean + b.buffers_backend = 0 THEN 1.0 ELSE b.buffers_clean::numeric / (b.buffers_clean + b.buffers_backend) END AS mem_hit_ratio INTO v_io_load, v_cpu_time, v_mem_hit_ratio FROM pg_stat_database d CROSS JOIN pg_stat_bgwriter b WHERE d.datname = current_database(); END IF; RETURN ( SELECT json_build_object( 'metric', 'Materialized View Refresh', 'mv_name', mv_name, 'status', CASE WHEN refresh_mv_time_last > refresh_mv_time_max * 0.9 THEN 'Red' WHEN refresh_mv_time_last > (refresh_mv_time_total / GREATEST(refresh_count, 1)) * 1.2 THEN 'Yellow' ELSE 'Green' END, 'severity', CASE WHEN refresh_mv_time_last > refresh_mv_time_max * 0.9 THEN 5 WHEN refresh_mv_time_last > (refresh_mv_time_total / GREATEST(refresh_count, 1)) * 1.2 THEN 3 ELSE 1 END, 'insight', CASE WHEN v_io_load > 100 THEN 'Refreshes are slower due to high I/O load.' WHEN v_cpu_time > (CASE WHEN v_has_pg_stat_statements THEN 1000 ELSE 0.5 END) THEN 'Refreshes are slower due to CPU usage.' WHEN v_mem_hit_ratio < 0.9 THEN 'Refreshes are slower due to memory pressure.' ELSE 'Refreshes are performing normally.' END, 'action', CASE WHEN v_io_load > 100 THEN 'Optimize I/O or schedule during off-peak hours.' WHEN v_cpu_time > (CASE WHEN v_has_pg_stat_statements THEN 1000 ELSE 0.5 END) THEN 'Increase CPU capacity or optimize queries.' WHEN v_mem_hit_ratio < 0.9 THEN 'Adjust memory settings (e.g., work_mem, shared_buffers).' ELSE 'No action needed.' END, 'details', json_build_object( 'last_refresh_time', refresh_mv_time_last::text, 'avg_refresh_time', (refresh_mv_time_total / GREATEST(refresh_count, 1))::text, 'min_refresh_time', refresh_mv_time_min::text, 'max_refresh_time', refresh_mv_time_max::text, 'refresh_count', refresh_count, 'io_load', round(v_io_load)::text || ' blocks/sec', 'cpu_time', (CASE WHEN v_has_pg_stat_statements THEN round(v_cpu_time)::text || ' ms/call' ELSE (v_cpu_time * 100)::text || '% waiting' END), 'buffer_hit_ratio', round(v_mem_hit_ratio * 100)::text || '%', 'bottleneck', CASE WHEN v_io_load > 100 THEN 'I/O' WHEN v_cpu_time > (CASE WHEN v_has_pg_stat_statements THEN 1000 ELSE 0.5 END) THEN 'CPU' WHEN v_mem_hit_ratio < 0.9 THEN 'RAM' ELSE 'None' END, 'explanations', json_build_object( 'last_refresh_time', 'Last refresh duration compared to historical min/max.', 'io_load', 'Blocks read per second; high values indicate disk I/O bottleneck.', 'cpu_time', (CASE WHEN v_has_pg_stat_statements THEN 'Average CPU time per refresh; high values suggest CPU bottleneck.' ELSE 'Percentage of time waiting on CPU (crude estimate).' END), 'buffer_hit_ratio', 'Percentage of blocks from cache; <90% suggests memory pressure.' ) ) ) FROM public.c77_dbh_mv_stats WHERE mv_name = p_mv_name ); END; $$ LANGUAGE plpgsql;