diff --git a/src/integrations/supabase/types.ts b/src/integrations/supabase/types.ts index 6f153fb1..cff8ca73 100644 --- a/src/integrations/supabase/types.ts +++ b/src/integrations/supabase/types.ts @@ -1997,6 +1997,30 @@ export type Database = { } Relationships: [] } + orphaned_images: { + Row: { + cloudflare_id: string + created_at: string + id: string + image_url: string + marked_for_deletion_at: string | null + } + Insert: { + cloudflare_id: string + created_at?: string + id?: string + image_url: string + marked_for_deletion_at?: string | null + } + Update: { + cloudflare_id?: string + created_at?: string + id?: string + image_url?: string + marked_for_deletion_at?: string | null + } + Relationships: [] + } orphaned_images_log: { Row: { cleaned_up: boolean | null @@ -5304,6 +5328,36 @@ export type Database = { }, ] } + system_alerts: { + Row: { + alert_type: string + created_at: string + id: string + message: string + metadata: Json | null + resolved_at: string | null + severity: string + } + Insert: { + alert_type: string + created_at?: string + id?: string + message: string + metadata?: Json | null + resolved_at?: string | null + severity: string + } + Update: { + alert_type?: string + created_at?: string + id?: string + message?: string + metadata?: Json | null + resolved_at?: string | null + severity?: string + } + Relationships: [] + } test_data_registry: { Row: { created_at: string @@ -5935,6 +5989,15 @@ export type Database = { } Relationships: [] } + system_health: { + Row: { + alerts_last_24h: number | null + checked_at: string | null + critical_alerts_count: number | null + orphaned_images_count: number | null + } + Relationships: [] + } } Functions: { anonymize_user_submissions: { @@ -6041,6 +6104,15 @@ export type Database = { } Returns: string } + create_system_alert: { + Args: { + p_alert_type: string + p_message: string + p_metadata?: Json + p_severity: string + } + Returns: string + } delete_entity_from_submission: { Args: { p_deleted_by: string @@ -6195,7 +6267,7 @@ export type Database = { is_auth0_user: { Args: never; Returns: boolean } is_moderator: { Args: { _user_id: string }; Returns: boolean } is_superuser: { Args: { _user_id: string }; Returns: boolean } - is_user_banned: { Args: { _user_id: string }; Returns: boolean } + is_user_banned: { Args: { p_user_id: string }; Returns: boolean } log_admin_action: { Args: { _action: string @@ -6239,6 +6311,7 @@ export type Database = { } Returns: undefined } + mark_orphaned_images: { Args: never; Returns: undefined } migrate_ride_technical_data: { Args: never; Returns: undefined } migrate_user_list_items: { Args: never; Returns: undefined } process_approval_transaction: { @@ -6276,6 +6349,14 @@ export type Database = { } Returns: string } + run_system_maintenance: { + Args: never + Returns: { + details: Json + status: string + task: string + }[] + } set_config_value: { Args: { is_local?: boolean diff --git a/supabase/migrations/20251107005923_5a6738b2-fe71-4152-9d6a-902aa51f1ce0.sql b/supabase/migrations/20251107005923_5a6738b2-fe71-4152-9d6a-902aa51f1ce0.sql new file mode 100644 index 00000000..6d0ef17e --- /dev/null +++ b/supabase/migrations/20251107005923_5a6738b2-fe71-4152-9d6a-902aa51f1ce0.sql @@ -0,0 +1,248 @@ +-- Phase 4: Application Boundary Hardening (Simplified) + +-- ============================================================================ +-- 1. IMAGE UPLOAD ORPHAN CLEANUP +-- ============================================================================ + +-- Track image uploads that haven't been associated with submissions after 24 hours +CREATE TABLE IF NOT EXISTS orphaned_images ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + image_url TEXT NOT NULL, + cloudflare_id TEXT NOT NULL, + created_at TIMESTAMPTZ NOT NULL DEFAULT now(), + marked_for_deletion_at TIMESTAMPTZ +); + +CREATE INDEX IF NOT EXISTS idx_orphaned_images_marked ON orphaned_images(marked_for_deletion_at) WHERE marked_for_deletion_at IS NOT NULL; + +-- Function to mark orphaned images (images uploaded but not in any submission after 24h) +CREATE OR REPLACE FUNCTION mark_orphaned_images() +RETURNS void +LANGUAGE plpgsql +SECURITY DEFINER +SET search_path = public +AS $$ +BEGIN + -- Mark images that haven't been used in submissions within 24 hours + INSERT INTO orphaned_images (image_url, cloudflare_id, marked_for_deletion_at) + SELECT DISTINCT + si.url, + si.cloudflare_id, + now() + FROM submission_images si + WHERE si.created_at < now() - interval '24 hours' + AND NOT EXISTS ( + SELECT 1 FROM content_submissions cs + WHERE cs.id = si.submission_id + ) + AND NOT EXISTS ( + SELECT 1 FROM orphaned_images oi + WHERE oi.cloudflare_id = si.cloudflare_id + ); +END; +$$; + +-- ============================================================================ +-- 2. SLUG VALIDATION TRIGGERS +-- ============================================================================ + +-- Function to validate slug format (lowercase, alphanumeric with hyphens only) +CREATE OR REPLACE FUNCTION validate_slug_format() +RETURNS TRIGGER +LANGUAGE plpgsql +AS $$ +BEGIN + IF NEW.slug IS NOT NULL THEN + -- Check format: lowercase letters, numbers, hyphens only + IF NEW.slug !~ '^[a-z0-9]+(-[a-z0-9]+)*$' THEN + RAISE EXCEPTION 'Invalid slug format: %. Slugs must be lowercase alphanumeric with hyphens only.', NEW.slug; + END IF; + + -- Check length constraints + IF length(NEW.slug) < 2 THEN + RAISE EXCEPTION 'Slug too short: %. Minimum length is 2 characters.', NEW.slug; + END IF; + + IF length(NEW.slug) > 100 THEN + RAISE EXCEPTION 'Slug too long: %. Maximum length is 100 characters.', NEW.slug; + END IF; + + -- Prevent reserved slugs + IF NEW.slug IN ('admin', 'api', 'auth', 'new', 'edit', 'delete', 'create', 'update', 'null', 'undefined') THEN + RAISE EXCEPTION 'Reserved slug: %. This slug cannot be used.', NEW.slug; + END IF; + END IF; + + RETURN NEW; +END; +$$; + +-- Apply slug validation to parks +DROP TRIGGER IF EXISTS validate_parks_slug ON parks; +CREATE TRIGGER validate_parks_slug + BEFORE INSERT OR UPDATE OF slug ON parks + FOR EACH ROW + EXECUTE FUNCTION validate_slug_format(); + +-- Apply slug validation to rides +DROP TRIGGER IF EXISTS validate_rides_slug ON rides; +CREATE TRIGGER validate_rides_slug + BEFORE INSERT OR UPDATE OF slug ON rides + FOR EACH ROW + EXECUTE FUNCTION validate_slug_format(); + +-- Apply slug validation to companies +DROP TRIGGER IF EXISTS validate_companies_slug ON companies; +CREATE TRIGGER validate_companies_slug + BEFORE INSERT OR UPDATE OF slug ON companies + FOR EACH ROW + EXECUTE FUNCTION validate_slug_format(); + +-- ============================================================================ +-- 3. MONITORING & ALERTING INFRASTRUCTURE +-- ============================================================================ + +-- Critical alerts table for monitoring +CREATE TABLE IF NOT EXISTS system_alerts ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + alert_type TEXT NOT NULL CHECK (alert_type IN ( + 'orphaned_images', + 'stale_submissions', + 'circular_dependency', + 'validation_error', + 'ban_attempt', + 'upload_timeout', + 'high_error_rate' + )), + severity TEXT NOT NULL CHECK (severity IN ('low', 'medium', 'high', 'critical')), + message TEXT NOT NULL, + metadata JSONB, + resolved_at TIMESTAMPTZ, + created_at TIMESTAMPTZ NOT NULL DEFAULT now() +); + +CREATE INDEX IF NOT EXISTS idx_system_alerts_unresolved ON system_alerts(created_at DESC) WHERE resolved_at IS NULL; +CREATE INDEX IF NOT EXISTS idx_system_alerts_type ON system_alerts(alert_type, created_at DESC); + +-- Function to create system alert +CREATE OR REPLACE FUNCTION create_system_alert( + p_alert_type TEXT, + p_severity TEXT, + p_message TEXT, + p_metadata JSONB DEFAULT NULL +) +RETURNS UUID +LANGUAGE plpgsql +SECURITY DEFINER +SET search_path = public +AS $$ +DECLARE + v_alert_id UUID; +BEGIN + INSERT INTO system_alerts (alert_type, severity, message, metadata) + VALUES (p_alert_type, p_severity, p_message, p_metadata) + RETURNING id INTO v_alert_id; + + RETURN v_alert_id; +END; +$$; + +-- Enhanced ban attempt logging with alert +CREATE OR REPLACE FUNCTION prevent_banned_user_submissions() +RETURNS TRIGGER +LANGUAGE plpgsql +SECURITY DEFINER +SET search_path = public +AS $$ +DECLARE + v_user_banned BOOLEAN; + v_ban_reason TEXT; +BEGIN + -- Check if user is banned + SELECT is_banned, ban_reason INTO v_user_banned, v_ban_reason + FROM profiles + WHERE id = NEW.submitted_by; + + IF v_user_banned THEN + -- Create alert for banned user attempt + PERFORM create_system_alert( + 'ban_attempt', + 'medium', + format('Banned user %s attempted to submit content', NEW.submitted_by), + jsonb_build_object( + 'user_id', NEW.submitted_by, + 'ban_reason', v_ban_reason, + 'submission_type', NEW.entity_type, + 'attempted_at', now() + ) + ); + + RAISE EXCEPTION 'Submission blocked: User account is banned. Reason: %', v_ban_reason; + END IF; + + RETURN NEW; +END; +$$; + +-- ============================================================================ +-- 4. MAINTENANCE FUNCTION +-- ============================================================================ + +-- Main maintenance function to run periodically +CREATE OR REPLACE FUNCTION run_system_maintenance() +RETURNS TABLE( + task TEXT, + status TEXT, + details JSONB +) +LANGUAGE plpgsql +SECURITY DEFINER +SET search_path = public +AS $$ +DECLARE + v_orphaned_count INTEGER; +BEGIN + -- Mark orphaned images + BEGIN + PERFORM mark_orphaned_images(); + SELECT COUNT(*) INTO v_orphaned_count + FROM orphaned_images + WHERE marked_for_deletion_at IS NOT NULL + AND marked_for_deletion_at > now() - interval '1 hour'; + + RETURN QUERY SELECT + 'mark_orphaned_images'::TEXT, + 'success'::TEXT, + jsonb_build_object('count', v_orphaned_count); + + IF v_orphaned_count > 100 THEN + PERFORM create_system_alert( + 'orphaned_images', + 'medium', + format('High number of orphaned images detected: %s', v_orphaned_count), + jsonb_build_object('count', v_orphaned_count) + ); + END IF; + EXCEPTION WHEN OTHERS THEN + RETURN QUERY SELECT + 'mark_orphaned_images'::TEXT, + 'error'::TEXT, + jsonb_build_object('error', SQLERRM); + END; + + RETURN; +END; +$$; + +-- Grant necessary permissions +GRANT EXECUTE ON FUNCTION mark_orphaned_images() TO authenticated; +GRANT EXECUTE ON FUNCTION run_system_maintenance() TO authenticated; +GRANT EXECUTE ON FUNCTION create_system_alert(TEXT, TEXT, TEXT, JSONB) TO authenticated; + +-- Create view for monitoring dashboard +CREATE OR REPLACE VIEW system_health AS +SELECT + (SELECT COUNT(*) FROM orphaned_images WHERE marked_for_deletion_at IS NOT NULL) as orphaned_images_count, + (SELECT COUNT(*) FROM system_alerts WHERE resolved_at IS NULL AND severity IN ('high', 'critical')) as critical_alerts_count, + (SELECT COUNT(*) FROM system_alerts WHERE resolved_at IS NULL AND created_at > now() - interval '24 hours') as alerts_last_24h, + now() as checked_at; \ No newline at end of file