fix: resolve infinite recursion in RLS policies
Use SECURITY DEFINER helper functions to break circular dependencies between projects and project_collaborators table policies. Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
This commit is contained in:
parent
bcbad57aa9
commit
841eefb186
|
|
@ -0,0 +1,174 @@
|
||||||
|
-- Migration: Fix infinite recursion in RLS policies
|
||||||
|
-- Problem: Self-referencing policies and circular dependencies between
|
||||||
|
-- projects <-> project_collaborators cause infinite recursion.
|
||||||
|
-- Solution: Use SECURITY DEFINER functions to bypass RLS for permission checks.
|
||||||
|
|
||||||
|
-- =============================================================================
|
||||||
|
-- HELPER FUNCTIONS (SECURITY DEFINER bypasses RLS)
|
||||||
|
-- =============================================================================
|
||||||
|
|
||||||
|
-- Check if the current user is an admin
|
||||||
|
CREATE OR REPLACE FUNCTION is_admin()
|
||||||
|
RETURNS boolean
|
||||||
|
LANGUAGE sql
|
||||||
|
SECURITY DEFINER
|
||||||
|
STABLE
|
||||||
|
AS $$
|
||||||
|
SELECT EXISTS (
|
||||||
|
SELECT 1 FROM profiles
|
||||||
|
WHERE id = auth.uid()
|
||||||
|
AND is_admin = true
|
||||||
|
);
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- Check if the current user is the owner of a project
|
||||||
|
CREATE OR REPLACE FUNCTION is_project_owner(p_project_id uuid)
|
||||||
|
RETURNS boolean
|
||||||
|
LANGUAGE sql
|
||||||
|
SECURITY DEFINER
|
||||||
|
STABLE
|
||||||
|
AS $$
|
||||||
|
SELECT EXISTS (
|
||||||
|
SELECT 1 FROM projects
|
||||||
|
WHERE id = p_project_id
|
||||||
|
AND user_id = auth.uid()
|
||||||
|
);
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- Check if the current user is a collaborator on a project (any role)
|
||||||
|
CREATE OR REPLACE FUNCTION is_project_collaborator(p_project_id uuid)
|
||||||
|
RETURNS boolean
|
||||||
|
LANGUAGE sql
|
||||||
|
SECURITY DEFINER
|
||||||
|
STABLE
|
||||||
|
AS $$
|
||||||
|
SELECT EXISTS (
|
||||||
|
SELECT 1 FROM project_collaborators
|
||||||
|
WHERE project_id = p_project_id
|
||||||
|
AND user_id = auth.uid()
|
||||||
|
);
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- Check if the current user is an editor or owner collaborator on a project
|
||||||
|
CREATE OR REPLACE FUNCTION is_project_editor(p_project_id uuid)
|
||||||
|
RETURNS boolean
|
||||||
|
LANGUAGE sql
|
||||||
|
SECURITY DEFINER
|
||||||
|
STABLE
|
||||||
|
AS $$
|
||||||
|
SELECT EXISTS (
|
||||||
|
SELECT 1 FROM project_collaborators
|
||||||
|
WHERE project_id = p_project_id
|
||||||
|
AND user_id = auth.uid()
|
||||||
|
AND role IN ('owner', 'editor')
|
||||||
|
);
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- =============================================================================
|
||||||
|
-- FIX PROFILES POLICIES
|
||||||
|
-- =============================================================================
|
||||||
|
|
||||||
|
-- Drop the problematic admin policy (self-references profiles table)
|
||||||
|
DROP POLICY IF EXISTS "Admins can view all profiles" ON profiles;
|
||||||
|
|
||||||
|
-- Recreate using the helper function
|
||||||
|
CREATE POLICY "Admins can view all profiles"
|
||||||
|
ON profiles
|
||||||
|
FOR SELECT
|
||||||
|
USING (is_admin());
|
||||||
|
|
||||||
|
-- =============================================================================
|
||||||
|
-- FIX PROJECT_COLLABORATORS POLICIES
|
||||||
|
-- =============================================================================
|
||||||
|
|
||||||
|
-- Drop the problematic SELECT policy (self-references project_collaborators)
|
||||||
|
DROP POLICY IF EXISTS "Users can view collaborators for their projects" ON project_collaborators;
|
||||||
|
|
||||||
|
-- Recreate without self-reference: user is either the collaborator row's user,
|
||||||
|
-- the project owner, or already a collaborator on that project
|
||||||
|
CREATE POLICY "Users can view collaborators for their projects"
|
||||||
|
ON project_collaborators
|
||||||
|
FOR SELECT
|
||||||
|
USING (
|
||||||
|
auth.uid() = user_id
|
||||||
|
OR is_project_owner(project_id)
|
||||||
|
OR is_project_collaborator(project_id)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- Drop and recreate INSERT/UPDATE/DELETE policies to use helper functions
|
||||||
|
DROP POLICY IF EXISTS "Owners can add collaborators" ON project_collaborators;
|
||||||
|
CREATE POLICY "Owners can add collaborators"
|
||||||
|
ON project_collaborators
|
||||||
|
FOR INSERT
|
||||||
|
WITH CHECK (is_project_owner(project_id));
|
||||||
|
|
||||||
|
DROP POLICY IF EXISTS "Owners can update collaborators" ON project_collaborators;
|
||||||
|
CREATE POLICY "Owners can update collaborators"
|
||||||
|
ON project_collaborators
|
||||||
|
FOR UPDATE
|
||||||
|
USING (is_project_owner(project_id))
|
||||||
|
WITH CHECK (is_project_owner(project_id));
|
||||||
|
|
||||||
|
DROP POLICY IF EXISTS "Owners can remove collaborators" ON project_collaborators;
|
||||||
|
CREATE POLICY "Owners can remove collaborators"
|
||||||
|
ON project_collaborators
|
||||||
|
FOR DELETE
|
||||||
|
USING (is_project_owner(project_id));
|
||||||
|
|
||||||
|
-- =============================================================================
|
||||||
|
-- FIX COLLABORATION_SESSIONS POLICIES
|
||||||
|
-- =============================================================================
|
||||||
|
|
||||||
|
-- Drop the SELECT policy that cross-references both projects and project_collaborators
|
||||||
|
DROP POLICY IF EXISTS "Collaborators can view sessions" ON collaboration_sessions;
|
||||||
|
|
||||||
|
CREATE POLICY "Collaborators can view sessions"
|
||||||
|
ON collaboration_sessions
|
||||||
|
FOR SELECT
|
||||||
|
USING (
|
||||||
|
is_project_owner(project_id)
|
||||||
|
OR is_project_collaborator(project_id)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- =============================================================================
|
||||||
|
-- FIX AUDIT_TRAIL POLICIES
|
||||||
|
-- =============================================================================
|
||||||
|
|
||||||
|
DROP POLICY IF EXISTS "Collaborators can view audit trail" ON audit_trail;
|
||||||
|
CREATE POLICY "Collaborators can view audit trail"
|
||||||
|
ON audit_trail
|
||||||
|
FOR SELECT
|
||||||
|
USING (
|
||||||
|
is_project_owner(project_id)
|
||||||
|
OR is_project_collaborator(project_id)
|
||||||
|
);
|
||||||
|
|
||||||
|
DROP POLICY IF EXISTS "Collaborators can write audit entries" ON audit_trail;
|
||||||
|
CREATE POLICY "Collaborators can write audit entries"
|
||||||
|
ON audit_trail
|
||||||
|
FOR INSERT
|
||||||
|
WITH CHECK (
|
||||||
|
auth.uid() = user_id
|
||||||
|
AND (
|
||||||
|
is_project_owner(project_id)
|
||||||
|
OR is_project_editor(project_id)
|
||||||
|
)
|
||||||
|
);
|
||||||
|
|
||||||
|
-- =============================================================================
|
||||||
|
-- FIX PROJECTS POLICIES (collaborator access)
|
||||||
|
-- =============================================================================
|
||||||
|
|
||||||
|
-- Drop the policies that query project_collaborators (creating circular deps)
|
||||||
|
DROP POLICY IF EXISTS "Collaborators can view shared projects" ON projects;
|
||||||
|
CREATE POLICY "Collaborators can view shared projects"
|
||||||
|
ON projects
|
||||||
|
FOR SELECT
|
||||||
|
USING (is_project_collaborator(id));
|
||||||
|
|
||||||
|
DROP POLICY IF EXISTS "Collaborators can update shared projects" ON projects;
|
||||||
|
CREATE POLICY "Collaborators can update shared projects"
|
||||||
|
ON projects
|
||||||
|
FOR UPDATE
|
||||||
|
USING (is_project_editor(id))
|
||||||
|
WITH CHECK (is_project_editor(id));
|
||||||
Loading…
Reference in New Issue