-- Phase 1: Enhanced Error Tracking Schema -- Add columns for enhanced error context to request_metadata table -- Add new columns for error tracking ALTER TABLE request_metadata ADD COLUMN IF NOT EXISTS error_stack text, ADD COLUMN IF NOT EXISTS breadcrumbs jsonb DEFAULT '[]'::jsonb, ADD COLUMN IF NOT EXISTS environment_context jsonb DEFAULT '{}'::jsonb; -- Add comments to document new columns COMMENT ON COLUMN request_metadata.error_stack IS 'Stack trace of the error (first 5000 chars)'; COMMENT ON COLUMN request_metadata.breadcrumbs IS 'User action trail before error occurred (last 10 actions)'; COMMENT ON COLUMN request_metadata.environment_context IS 'Browser/device context when error occurred'; -- Index for error grouping and analysis CREATE INDEX IF NOT EXISTS idx_request_metadata_error_grouping ON request_metadata(error_type, endpoint, created_at DESC) WHERE error_type IS NOT NULL; -- Index for recent errors query (dashboard) CREATE INDEX IF NOT EXISTS idx_request_metadata_recent_errors ON request_metadata(created_at DESC) WHERE error_type IS NOT NULL; -- Update log_request_metadata RPC function to accept new fields CREATE OR REPLACE FUNCTION log_request_metadata( p_request_id uuid, p_user_id uuid DEFAULT NULL, p_endpoint text DEFAULT NULL, p_method text DEFAULT NULL, p_status_code integer DEFAULT NULL, p_duration_ms integer DEFAULT NULL, p_error_type text DEFAULT NULL, p_error_message text DEFAULT NULL, p_user_agent text DEFAULT NULL, p_client_version text DEFAULT NULL, p_parent_request_id uuid DEFAULT NULL, p_trace_id uuid DEFAULT NULL, p_error_stack text DEFAULT NULL, p_breadcrumbs jsonb DEFAULT '[]'::jsonb, p_environment_context jsonb DEFAULT '{}'::jsonb ) RETURNS void LANGUAGE plpgsql SECURITY DEFINER SET search_path = public AS $$ BEGIN INSERT INTO request_metadata ( request_id, user_id, endpoint, method, status_code, duration_ms, error_type, error_message, user_agent, client_version, parent_request_id, trace_id, error_stack, breadcrumbs, environment_context ) VALUES ( p_request_id, p_user_id, p_endpoint, p_method, p_status_code, p_duration_ms, p_error_type, p_error_message, p_user_agent, p_client_version, p_parent_request_id, p_trace_id, p_error_stack, p_breadcrumbs, p_environment_context ); END; $$; -- Create error_summary view for aggregation CREATE OR REPLACE VIEW error_summary AS SELECT error_type, endpoint, COUNT(*) as occurrence_count, COUNT(DISTINCT user_id) as affected_users, MAX(created_at) as last_occurred, MIN(created_at) as first_occurred, ROUND(AVG(duration_ms)::numeric, 2) as avg_duration_ms, (ARRAY_AGG(request_id ORDER BY created_at DESC) FILTER (WHERE created_at > now() - interval '1 day') )[1:5] as recent_request_ids FROM request_metadata WHERE error_type IS NOT NULL AND created_at > now() - interval '30 days' GROUP BY error_type, endpoint ORDER BY occurrence_count DESC; COMMENT ON VIEW error_summary IS 'Aggregated error statistics for monitoring dashboard'; -- Grant access to authenticated users GRANT SELECT ON error_summary TO authenticated;