-- Phase 2: Create update_profile RPC function with validation and audit logging CREATE OR REPLACE FUNCTION public.update_profile( p_username text, p_display_name text DEFAULT NULL, p_bio text DEFAULT NULL, p_preferred_pronouns text DEFAULT NULL, p_show_pronouns boolean DEFAULT false, p_preferred_language text DEFAULT 'en', p_personal_location text DEFAULT NULL, p_avatar_url text DEFAULT NULL, p_avatar_image_id text DEFAULT NULL ) RETURNS jsonb LANGUAGE plpgsql SECURITY DEFINER SET search_path = public AS $$ DECLARE v_user_id uuid; v_old_profile record; v_changes jsonb := '[]'::jsonb; v_change jsonb; BEGIN -- Get authenticated user ID v_user_id := auth.uid(); IF v_user_id IS NULL THEN RAISE EXCEPTION 'Not authenticated'; END IF; -- Get current profile for comparison SELECT * INTO v_old_profile FROM public.profiles WHERE user_id = v_user_id; IF v_old_profile IS NULL THEN RAISE EXCEPTION 'Profile not found'; END IF; -- Check if account is deactivated IF v_old_profile.deactivated THEN RAISE EXCEPTION 'Cannot update deactivated account'; END IF; -- Validate username length and format (3-20 chars, alphanumeric, underscore, hyphen) IF p_username IS NOT NULL THEN IF LENGTH(p_username) < 3 OR LENGTH(p_username) > 20 THEN RAISE EXCEPTION 'Username must be between 3 and 20 characters'; END IF; IF p_username !~ '^[a-z0-9_-]+$' THEN RAISE EXCEPTION 'Username can only contain lowercase letters, numbers, underscores, and hyphens'; END IF; -- Check for consecutive special characters IF p_username ~ '__' OR p_username ~ '--' OR p_username ~ '_-' OR p_username ~ '-_' THEN RAISE EXCEPTION 'Username cannot contain consecutive special characters'; END IF; END IF; -- Validate display_name length (max 50 chars) IF p_display_name IS NOT NULL AND LENGTH(p_display_name) > 50 THEN RAISE EXCEPTION 'Display name must be 50 characters or less'; END IF; -- Validate bio length (max 500 chars) IF p_bio IS NOT NULL AND LENGTH(p_bio) > 500 THEN RAISE EXCEPTION 'Bio must be 500 characters or less'; END IF; -- Validate personal_location (max 100 chars, no special chars like <>) IF p_personal_location IS NOT NULL THEN IF LENGTH(p_personal_location) > 100 THEN RAISE EXCEPTION 'Personal location must be 100 characters or less'; END IF; IF p_personal_location ~ '[<>]' THEN RAISE EXCEPTION 'Personal location contains invalid characters'; END IF; END IF; -- Track changes for audit log IF v_old_profile.username IS DISTINCT FROM p_username THEN v_changes := v_changes || jsonb_build_array( jsonb_build_object('field', 'username', 'old', v_old_profile.username, 'new', p_username) ); END IF; IF v_old_profile.display_name IS DISTINCT FROM p_display_name THEN v_changes := v_changes || jsonb_build_array( jsonb_build_object('field', 'display_name', 'old', v_old_profile.display_name, 'new', p_display_name) ); END IF; IF v_old_profile.bio IS DISTINCT FROM p_bio THEN v_changes := v_changes || jsonb_build_array( jsonb_build_object('field', 'bio', 'old', v_old_profile.bio, 'new', p_bio) ); END IF; -- Update profile (updated_at is handled by trigger) UPDATE public.profiles SET username = COALESCE(p_username, username), display_name = p_display_name, bio = p_bio, preferred_pronouns = p_preferred_pronouns, show_pronouns = p_show_pronouns, preferred_language = COALESCE(p_preferred_language, preferred_language), personal_location = p_personal_location, avatar_url = COALESCE(p_avatar_url, avatar_url), avatar_image_id = COALESCE(p_avatar_image_id, avatar_image_id) WHERE user_id = v_user_id; -- Log significant changes IF jsonb_array_length(v_changes) > 0 THEN INSERT INTO public.admin_audit_log (admin_user_id, target_user_id, action, details) VALUES (v_user_id, v_user_id, 'profile_updated', jsonb_build_object('changes', v_changes)); END IF; RETURN jsonb_build_object( 'success', true, 'username_changed', v_old_profile.username IS DISTINCT FROM p_username, 'changes_count', jsonb_array_length(v_changes) ); END; $$; GRANT EXECUTE ON FUNCTION public.update_profile TO authenticated;