-- Fix item_edit_history table schema to support proper edit tracking -- This adds missing columns and creates relational table for field changes (NO JSON!) -- Add missing columns to item_edit_history ALTER TABLE public.item_edit_history ADD COLUMN IF NOT EXISTS edit_reason TEXT, ADD COLUMN IF NOT EXISTS changed_fields TEXT[] DEFAULT '{}'; -- Create relational table for field-level changes (adheres to NO JSON policy) CREATE TABLE IF NOT EXISTS public.item_field_changes ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), edit_history_id UUID NOT NULL REFERENCES item_edit_history(id) ON DELETE CASCADE, field_name TEXT NOT NULL, old_value TEXT, new_value TEXT, created_at TIMESTAMPTZ DEFAULT NOW() ); -- Create index for performance CREATE INDEX IF NOT EXISTS idx_field_changes_edit_history ON item_field_changes(edit_history_id); -- Rename editor_id to edited_by for consistency ALTER TABLE public.item_edit_history RENAME COLUMN editor_id TO edited_by; -- Update RLS policies for item_field_changes ALTER TABLE public.item_field_changes ENABLE ROW LEVEL SECURITY; CREATE POLICY "Moderators view item field changes" ON public.item_field_changes FOR SELECT USING (is_moderator(auth.uid())); CREATE POLICY "System inserts item field changes" ON public.item_field_changes FOR INSERT WITH CHECK (is_moderator(auth.uid())); -- Fix superuser_release_all_locks function to use SECURITY DEFINER CREATE OR REPLACE FUNCTION public.superuser_release_all_locks(p_superuser_id uuid) RETURNS integer LANGUAGE plpgsql SECURITY DEFINER SET search_path TO 'public' AS $function$ DECLARE v_is_superuser BOOLEAN; v_released_count INTEGER; v_released_locks JSONB; BEGIN -- Verify caller is actually a superuser SELECT EXISTS ( SELECT 1 FROM user_roles WHERE user_id = p_superuser_id AND role = 'superuser' ) INTO v_is_superuser; IF NOT v_is_superuser THEN RAISE EXCEPTION 'Unauthorized: Only superusers can release all locks'; END IF; -- Capture all locked submissions for audit SELECT jsonb_agg( jsonb_build_object( 'submission_id', id, 'assigned_to', assigned_to, 'locked_until', locked_until, 'submission_type', submission_type ) ) INTO v_released_locks FROM content_submissions WHERE assigned_to IS NOT NULL AND locked_until > NOW(); -- Release all active locks UPDATE content_submissions SET assigned_to = NULL, assigned_at = NULL, locked_until = NULL WHERE assigned_to IS NOT NULL AND locked_until > NOW() AND status IN ('pending', 'partially_approved'); GET DIAGNOSTICS v_released_count = ROW_COUNT; -- Log the bulk release IF v_released_count > 0 THEN PERFORM log_admin_action( p_superuser_id, NULL, 'submission_locks_bulk_released', jsonb_build_object( 'released_count', v_released_count, 'released_locks', v_released_locks, 'bulk_operation', true ) ); END IF; RETURN v_released_count; END; $function$;