ralph/collaboration-and-character-variables #7

Merged
GHMiranda merged 14 commits from ralph/collaboration-and-character-variables into developing 2026-01-23 18:59:46 +00:00
1 changed files with 214 additions and 0 deletions
Showing only changes of commit 2b4abd1eb7 - Show all commits

View File

@ -0,0 +1,214 @@
-- Migration: Add collaboration sessions and audit trail tables
-- Supports real-time multi-user editing with presence tracking and change history
-- =============================================================================
-- PROJECT COLLABORATORS TABLE
-- =============================================================================
-- Tracks which users have access to a project and their role
CREATE TABLE IF NOT EXISTS project_collaborators (
id uuid PRIMARY KEY DEFAULT uuid_generate_v4(),
project_id uuid NOT NULL REFERENCES projects(id) ON DELETE CASCADE,
user_id uuid NOT NULL REFERENCES profiles(id) ON DELETE CASCADE,
role text NOT NULL CHECK (role IN ('owner', 'editor', 'viewer')),
invited_at timestamptz DEFAULT now(),
accepted_at timestamptz,
UNIQUE (project_id, user_id)
);
-- Enable Row Level Security
ALTER TABLE project_collaborators ENABLE ROW LEVEL SECURITY;
-- RLS: Users can view collaborators for projects they belong to
CREATE POLICY "Users can view collaborators for their projects"
ON project_collaborators
FOR SELECT
USING (
auth.uid() = user_id
OR project_id IN (
SELECT project_id FROM project_collaborators WHERE user_id = auth.uid()
)
OR project_id IN (
SELECT id FROM projects WHERE user_id = auth.uid()
)
);
-- RLS: Project owners can insert collaborators
CREATE POLICY "Owners can add collaborators"
ON project_collaborators
FOR INSERT
WITH CHECK (
project_id IN (
SELECT id FROM projects WHERE user_id = auth.uid()
)
);
-- RLS: Project owners can update collaborator roles
CREATE POLICY "Owners can update collaborators"
ON project_collaborators
FOR UPDATE
USING (
project_id IN (
SELECT id FROM projects WHERE user_id = auth.uid()
)
)
WITH CHECK (
project_id IN (
SELECT id FROM projects WHERE user_id = auth.uid()
)
);
-- RLS: Project owners can remove collaborators
CREATE POLICY "Owners can remove collaborators"
ON project_collaborators
FOR DELETE
USING (
project_id IN (
SELECT id FROM projects WHERE user_id = auth.uid()
)
);
-- =============================================================================
-- COLLABORATION SESSIONS TABLE
-- =============================================================================
-- Tracks active editing sessions for real-time presence
CREATE TABLE IF NOT EXISTS collaboration_sessions (
id uuid PRIMARY KEY DEFAULT uuid_generate_v4(),
project_id uuid NOT NULL REFERENCES projects(id) ON DELETE CASCADE,
user_id uuid NOT NULL REFERENCES profiles(id) ON DELETE CASCADE,
cursor_position jsonb,
selected_node_id text,
connected_at timestamptz DEFAULT now(),
last_heartbeat timestamptz DEFAULT now()
);
-- Enable Row Level Security
ALTER TABLE collaboration_sessions ENABLE ROW LEVEL SECURITY;
-- RLS: Users can view sessions for projects they collaborate on
CREATE POLICY "Collaborators can view sessions"
ON collaboration_sessions
FOR SELECT
USING (
project_id IN (
SELECT id FROM projects WHERE user_id = auth.uid()
)
OR project_id IN (
SELECT project_id FROM project_collaborators WHERE user_id = auth.uid()
)
);
-- RLS: Users can insert their own sessions
CREATE POLICY "Users can create own sessions"
ON collaboration_sessions
FOR INSERT
WITH CHECK (auth.uid() = user_id);
-- RLS: Users can update their own sessions (heartbeat, cursor position)
CREATE POLICY "Users can update own sessions"
ON collaboration_sessions
FOR UPDATE
USING (auth.uid() = user_id)
WITH CHECK (auth.uid() = user_id);
-- RLS: Users can delete their own sessions (disconnect)
CREATE POLICY "Users can delete own sessions"
ON collaboration_sessions
FOR DELETE
USING (auth.uid() = user_id);
-- =============================================================================
-- AUDIT TRAIL TABLE
-- =============================================================================
-- Records all node and edge changes for history and revert functionality
CREATE TABLE IF NOT EXISTS audit_trail (
id uuid PRIMARY KEY DEFAULT uuid_generate_v4(),
project_id uuid NOT NULL REFERENCES projects(id) ON DELETE CASCADE,
user_id uuid NOT NULL REFERENCES profiles(id) ON DELETE CASCADE,
action_type text NOT NULL CHECK (action_type IN ('node_add', 'node_update', 'node_delete', 'edge_add', 'edge_update', 'edge_delete')),
entity_id text NOT NULL,
previous_state jsonb,
new_state jsonb,
created_at timestamptz DEFAULT now()
);
-- Enable Row Level Security
ALTER TABLE audit_trail ENABLE ROW LEVEL SECURITY;
-- RLS: Users can view audit trail for projects they collaborate on
CREATE POLICY "Collaborators can view audit trail"
ON audit_trail
FOR SELECT
USING (
project_id IN (
SELECT id FROM projects WHERE user_id = auth.uid()
)
OR project_id IN (
SELECT project_id FROM project_collaborators WHERE user_id = auth.uid()
)
);
-- RLS: Users can insert audit entries for projects they collaborate on
CREATE POLICY "Collaborators can write audit entries"
ON audit_trail
FOR INSERT
WITH CHECK (
auth.uid() = user_id
AND (
project_id IN (
SELECT id FROM projects WHERE user_id = auth.uid()
)
OR project_id IN (
SELECT project_id FROM project_collaborators
WHERE user_id = auth.uid() AND role IN ('owner', 'editor')
)
)
);
-- =============================================================================
-- INDEXES
-- =============================================================================
-- Index for efficient history queries (paginated by time)
CREATE INDEX IF NOT EXISTS idx_audit_trail_project_created
ON audit_trail(project_id, created_at DESC);
-- Index for session lookups by project
CREATE INDEX IF NOT EXISTS idx_collaboration_sessions_project
ON collaboration_sessions(project_id);
-- Index for collaborator lookups by project
CREATE INDEX IF NOT EXISTS idx_project_collaborators_project
ON project_collaborators(project_id);
-- Index for collaborator lookups by user (for "shared with me" queries)
CREATE INDEX IF NOT EXISTS idx_project_collaborators_user
ON project_collaborators(user_id);
-- =============================================================================
-- UPDATE PROJECTS RLS: Allow collaborators to read/write
-- =============================================================================
-- Collaborators with 'editor' or 'owner' role can view the project
CREATE POLICY "Collaborators can view shared projects"
ON projects
FOR SELECT
USING (
id IN (
SELECT project_id FROM project_collaborators WHERE user_id = auth.uid()
)
);
-- Collaborators with 'editor' or 'owner' role can update the project
CREATE POLICY "Collaborators can update shared projects"
ON projects
FOR UPDATE
USING (
id IN (
SELECT project_id FROM project_collaborators
WHERE user_id = auth.uid() AND role IN ('owner', 'editor')
)
)
WITH CHECK (
id IN (
SELECT project_id FROM project_collaborators
WHERE user_id = auth.uid() AND role IN ('owner', 'editor')
)
);