c77_dbh/health_functions.sql

98 lines
6.1 KiB
PL/PgSQL

CREATE OR REPLACE FUNCTION public.c77_dbh_get_mv_health()
RETURNS JSON AS $$
BEGIN
RETURN (
SELECT json_agg(
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 refresh_mv_time_last > refresh_mv_time_max * 0.9 THEN 'Refreshes are critically slow compared to historical max.'
WHEN refresh_mv_time_last > (refresh_mv_time_total / GREATEST(refresh_count, 1)) * 1.2 THEN 'Refreshes are slower than average.'
ELSE 'Refreshes are performing normally.'
END,
'action', CASE
WHEN refresh_mv_time_last > refresh_mv_time_max * 0.9 THEN 'Investigate immediately; consider optimizing queries or resources.'
WHEN refresh_mv_time_last > (refresh_mv_time_total / GREATEST(refresh_count, 1)) * 1.2 THEN 'Review refresh schedule or resource usage.'
ELSE 'No action needed.'
END,
'last_refresh_time', refresh_mv_time_last::text,
'refresh_count', refresh_count
)
)
FROM public.c77_dbh_mv_stats
);
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION public.c77_dbh_get_mv_details(p_mv_name text)
RETURNS JSON AS $$
BEGIN
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 io_rate > 50 THEN 'Refreshes are slower due to high I/O load.'
WHEN cpu_usage > 80 THEN 'Refreshes are slower due to high CPU usage.'
WHEN ram_usage > 90 THEN 'Refreshes are slower due to memory constraints.'
ELSE 'Refreshes are performing normally.'
END,
'action', CASE
WHEN io_rate > 50 THEN 'Optimize I/O or schedule during off-peak hours.'
WHEN cpu_usage > 80 THEN 'Increase CPU capacity or optimize queries.'
WHEN ram_usage > 90 THEN 'Adjust memory settings (e.g., work_mem).'
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,
'cpu_usage', cpu_usage::text || '%',
'ram_usage', ram_usage::text || '%',
'io_rate', io_rate::text || ' MB/s',
'bottleneck', CASE
WHEN io_rate > 50 THEN 'I/O'
WHEN cpu_usage > 80 THEN 'CPU'
WHEN ram_usage > 90 THEN 'RAM'
ELSE 'None'
END,
'explanations', json_build_object(
'last_refresh_time', 'Last refresh duration compared to historical min/max.',
'io_rate', 'High I/O rate indicates disk operations are limiting performance.',
'cpu_usage', 'High CPU usage suggests processing power is the bottleneck.',
'ram_usage', 'High memory usage may cause disk spills, slowing refreshes.'
)
)
)
FROM public.c77_dbh_mv_stats
CROSS JOIN LATERAL (
-- Placeholder system stats; replace with real data later
SELECT 40 AS cpu_usage, 60 AS ram_usage, 80 AS io_rate
) AS sys
WHERE mv_name = p_mv_name
);
END;
$$ LANGUAGE plpgsql;