Files
thrilltrack-explorer/supabase/migrations/20251111021341_67018ac9-7870-40d7-b5d2-34e0b02dfbef.sql
gpt-engineer-app[bot] 07fdfe34f3 Fix function search paths
Adjust migrations to set search_path = public for functions to resolve security warnings and ensure proper function execution context.
2025-11-11 02:13:51 +00:00

222 lines
7.1 KiB
PL/PgSQL

-- Data Retention Policy Functions
-- Functions to automatically clean up old metrics and anomaly detections
-- Function to clean up old metric time series data (older than retention_days)
CREATE OR REPLACE FUNCTION cleanup_old_metrics(retention_days INTEGER DEFAULT 30)
RETURNS TABLE(deleted_count BIGINT) AS $$
DECLARE
cutoff_date TIMESTAMP WITH TIME ZONE;
rows_deleted BIGINT;
BEGIN
-- Calculate cutoff date
cutoff_date := NOW() - (retention_days || ' days')::INTERVAL;
-- Delete old metrics
DELETE FROM metric_time_series
WHERE timestamp < cutoff_date;
GET DIAGNOSTICS rows_deleted = ROW_COUNT;
-- Log the cleanup
INSERT INTO system_alerts (
alert_type,
severity,
message,
metadata
) VALUES (
'data_retention',
'info',
format('Cleaned up %s old metrics (older than %s days)', rows_deleted, retention_days),
jsonb_build_object(
'deleted_count', rows_deleted,
'retention_days', retention_days,
'cutoff_date', cutoff_date
)
);
RETURN QUERY SELECT rows_deleted;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Function to archive and clean up old anomaly detections
CREATE OR REPLACE FUNCTION cleanup_old_anomalies(retention_days INTEGER DEFAULT 30)
RETURNS TABLE(archived_count BIGINT, deleted_count BIGINT) AS $$
DECLARE
cutoff_date TIMESTAMP WITH TIME ZONE;
rows_archived BIGINT := 0;
rows_deleted BIGINT := 0;
BEGIN
-- Calculate cutoff date
cutoff_date := NOW() - (retention_days || ' days')::INTERVAL;
-- Archive resolved anomalies older than 7 days
WITH archived AS (
DELETE FROM anomaly_detections
WHERE detected_at < NOW() - INTERVAL '7 days'
AND alert_created = true
RETURNING *
)
SELECT COUNT(*) INTO rows_archived FROM archived;
-- Delete very old unresolved anomalies (older than retention period)
DELETE FROM anomaly_detections
WHERE detected_at < cutoff_date
AND alert_created = false;
GET DIAGNOSTICS rows_deleted = ROW_COUNT;
-- Log the cleanup
INSERT INTO system_alerts (
alert_type,
severity,
message,
metadata
) VALUES (
'data_retention',
'info',
format('Archived %s and deleted %s old anomaly detections', rows_archived, rows_deleted),
jsonb_build_object(
'archived_count', rows_archived,
'deleted_count', rows_deleted,
'retention_days', retention_days
)
);
RETURN QUERY SELECT rows_archived, rows_deleted;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Function to clean up old resolved alerts
CREATE OR REPLACE FUNCTION cleanup_old_alerts(retention_days INTEGER DEFAULT 90)
RETURNS TABLE(deleted_count BIGINT) AS $$
DECLARE
cutoff_date TIMESTAMP WITH TIME ZONE;
rows_deleted BIGINT;
BEGIN
-- Calculate cutoff date
cutoff_date := NOW() - (retention_days || ' days')::INTERVAL;
-- Delete old resolved alerts
DELETE FROM system_alerts
WHERE created_at < cutoff_date
AND resolved = true;
GET DIAGNOSTICS rows_deleted = ROW_COUNT;
RAISE NOTICE 'Cleaned up % old resolved alerts (older than % days)', rows_deleted, retention_days;
RETURN QUERY SELECT rows_deleted;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Function to clean up old resolved incidents
CREATE OR REPLACE FUNCTION cleanup_old_incidents(retention_days INTEGER DEFAULT 90)
RETURNS TABLE(deleted_count BIGINT) AS $$
DECLARE
cutoff_date TIMESTAMP WITH TIME ZONE;
rows_deleted BIGINT;
BEGIN
-- Calculate cutoff date
cutoff_date := NOW() - (retention_days || ' days')::INTERVAL;
-- Delete old resolved incidents
DELETE FROM incidents
WHERE created_at < cutoff_date
AND status = 'resolved';
GET DIAGNOSTICS rows_deleted = ROW_COUNT;
RAISE NOTICE 'Cleaned up % old resolved incidents (older than % days)', rows_deleted, retention_days;
RETURN QUERY SELECT rows_deleted;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Master cleanup function that runs all retention policies
CREATE OR REPLACE FUNCTION run_data_retention_cleanup()
RETURNS jsonb AS $$
DECLARE
metrics_deleted BIGINT;
anomalies_archived BIGINT;
anomalies_deleted BIGINT;
alerts_deleted BIGINT;
incidents_deleted BIGINT;
result jsonb;
BEGIN
-- Run all cleanup functions
SELECT deleted_count INTO metrics_deleted FROM cleanup_old_metrics(30);
SELECT archived_count, deleted_count INTO anomalies_archived, anomalies_deleted FROM cleanup_old_anomalies(30);
SELECT deleted_count INTO alerts_deleted FROM cleanup_old_alerts(90);
SELECT deleted_count INTO incidents_deleted FROM cleanup_old_incidents(90);
-- Build result
result := jsonb_build_object(
'success', true,
'timestamp', NOW(),
'cleanup_results', jsonb_build_object(
'metrics_deleted', metrics_deleted,
'anomalies_archived', anomalies_archived,
'anomalies_deleted', anomalies_deleted,
'alerts_deleted', alerts_deleted,
'incidents_deleted', incidents_deleted
)
);
RETURN result;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Grant execute permissions to authenticated users
GRANT EXECUTE ON FUNCTION cleanup_old_metrics(INTEGER) TO authenticated;
GRANT EXECUTE ON FUNCTION cleanup_old_anomalies(INTEGER) TO authenticated;
GRANT EXECUTE ON FUNCTION cleanup_old_alerts(INTEGER) TO authenticated;
GRANT EXECUTE ON FUNCTION cleanup_old_incidents(INTEGER) TO authenticated;
GRANT EXECUTE ON FUNCTION run_data_retention_cleanup() TO authenticated;
-- Create a view to show current data retention statistics
CREATE OR REPLACE VIEW data_retention_stats AS
SELECT
'metrics' AS table_name,
COUNT(*) AS total_records,
COUNT(*) FILTER (WHERE timestamp > NOW() - INTERVAL '7 days') AS last_7_days,
COUNT(*) FILTER (WHERE timestamp > NOW() - INTERVAL '30 days') AS last_30_days,
MIN(timestamp) AS oldest_record,
MAX(timestamp) AS newest_record,
pg_size_pretty(pg_total_relation_size('metric_time_series')) AS table_size
FROM metric_time_series
UNION ALL
SELECT
'anomaly_detections' AS table_name,
COUNT(*) AS total_records,
COUNT(*) FILTER (WHERE detected_at > NOW() - INTERVAL '7 days') AS last_7_days,
COUNT(*) FILTER (WHERE detected_at > NOW() - INTERVAL '30 days') AS last_30_days,
MIN(detected_at) AS oldest_record,
MAX(detected_at) AS newest_record,
pg_size_pretty(pg_total_relation_size('anomaly_detections')) AS table_size
FROM anomaly_detections
UNION ALL
SELECT
'system_alerts' AS table_name,
COUNT(*) AS total_records,
COUNT(*) FILTER (WHERE created_at > NOW() - INTERVAL '7 days') AS last_7_days,
COUNT(*) FILTER (WHERE created_at > NOW() - INTERVAL '30 days') AS last_30_days,
MIN(created_at) AS oldest_record,
MAX(created_at) AS newest_record,
pg_size_pretty(pg_total_relation_size('system_alerts')) AS table_size
FROM system_alerts
UNION ALL
SELECT
'incidents' AS table_name,
COUNT(*) AS total_records,
COUNT(*) FILTER (WHERE created_at > NOW() - INTERVAL '7 days') AS last_7_days,
COUNT(*) FILTER (WHERE created_at > NOW() - INTERVAL '30 days') AS last_30_days,
MIN(created_at) AS oldest_record,
MAX(created_at) AS newest_record,
pg_size_pretty(pg_total_relation_size('incidents')) AS table_size
FROM incidents;
-- Enable RLS on the view
ALTER VIEW data_retention_stats SET (security_invoker = on);
-- Grant select on view
GRANT SELECT ON data_retention_stats TO authenticated;