Add multi-tenancy with Teams feature

This commit is contained in:
Mondo Diaz
2026-01-28 12:50:58 -06:00
parent a5796f5437
commit 576791d19e
33 changed files with 5493 additions and 115 deletions

62
migrations/009_teams.sql Normal file
View File

@@ -0,0 +1,62 @@
-- Migration 009: Teams and Multi-Tenancy
-- Adds support for team-based multi-tenancy
-- Part of Multi-Tenancy with Teams feature
-- Create teams table
CREATE TABLE IF NOT EXISTS teams (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
name VARCHAR(255) NOT NULL,
slug VARCHAR(255) NOT NULL UNIQUE,
description TEXT,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
created_by VARCHAR(255) NOT NULL,
settings JSONB DEFAULT '{}'::jsonb,
-- Slug must be lowercase alphanumeric with hyphens
CONSTRAINT check_team_slug_format CHECK (slug ~ '^[a-z0-9][a-z0-9-]*[a-z0-9]$' OR slug ~ '^[a-z0-9]$')
);
-- Create team_memberships table
CREATE TABLE IF NOT EXISTS team_memberships (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
team_id UUID NOT NULL REFERENCES teams(id) ON DELETE CASCADE,
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
role VARCHAR(20) NOT NULL DEFAULT 'member',
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
invited_by VARCHAR(255),
-- Each user can only be a member of a team once
CONSTRAINT unique_team_membership UNIQUE (team_id, user_id),
-- Role must be one of: owner, admin, member
CONSTRAINT check_team_role CHECK (role IN ('owner', 'admin', 'member'))
);
-- Add team_id column to projects table (nullable for migration compatibility)
ALTER TABLE projects ADD COLUMN IF NOT EXISTS team_id UUID REFERENCES teams(id) ON DELETE SET NULL;
-- Indexes for teams table
CREATE INDEX IF NOT EXISTS idx_teams_slug ON teams(slug);
CREATE INDEX IF NOT EXISTS idx_teams_created_by ON teams(created_by);
CREATE INDEX IF NOT EXISTS idx_teams_created_at ON teams(created_at);
-- Indexes for team_memberships table
CREATE INDEX IF NOT EXISTS idx_team_memberships_team_id ON team_memberships(team_id);
CREATE INDEX IF NOT EXISTS idx_team_memberships_user_id ON team_memberships(user_id);
CREATE INDEX IF NOT EXISTS idx_team_memberships_role ON team_memberships(role);
CREATE INDEX IF NOT EXISTS idx_team_memberships_team_role ON team_memberships(team_id, role);
-- Index for projects team_id
CREATE INDEX IF NOT EXISTS idx_projects_team_id ON projects(team_id);
-- Comments
COMMENT ON TABLE teams IS 'Teams serve as organizational containers for projects';
COMMENT ON COLUMN teams.slug IS 'URL-friendly unique identifier (lowercase alphanumeric with hyphens)';
COMMENT ON COLUMN teams.settings IS 'JSON object for team-specific settings';
COMMENT ON TABLE team_memberships IS 'Maps users to teams with their roles';
COMMENT ON COLUMN team_memberships.role IS 'User role in the team: owner, admin, or member';
COMMENT ON COLUMN team_memberships.invited_by IS 'Username of the user who invited this member';
COMMENT ON COLUMN projects.team_id IS 'Optional team that owns this project';

View File

@@ -0,0 +1,99 @@
-- Migration 009b: Migrate Existing Projects to Personal Teams
-- Creates personal teams for existing users and assigns their projects to those teams.
-- This migration is idempotent and can be run multiple times safely.
-- Create personal teams for users who own projects but don't have a personal team yet
INSERT INTO teams (name, slug, description, created_by, settings)
SELECT DISTINCT
u.username || '''s Team' AS name,
LOWER(u.username) || '-personal' AS slug,
'Personal team for ' || u.username AS description,
u.username AS created_by,
'{"personal": true}'::jsonb AS settings
FROM users u
JOIN projects p ON p.created_by = u.username
WHERE NOT EXISTS (
SELECT 1 FROM teams t
WHERE t.slug = LOWER(u.username) || '-personal'
)
AND p.team_id IS NULL
ON CONFLICT (slug) DO NOTHING;
-- Add users as owners of their personal teams
INSERT INTO team_memberships (team_id, user_id, role, invited_by)
SELECT
t.id AS team_id,
u.id AS user_id,
'owner' AS role,
u.username AS invited_by
FROM teams t
JOIN users u ON t.created_by = u.username
WHERE t.slug LIKE '%-personal'
AND NOT EXISTS (
SELECT 1 FROM team_memberships tm
WHERE tm.team_id = t.id
AND tm.user_id = u.id
)
ON CONFLICT DO NOTHING;
-- Assign projects without a team to their creator's personal team
UPDATE projects p
SET team_id = t.id
FROM teams t
WHERE t.slug = LOWER(p.created_by) || '-personal'
AND p.team_id IS NULL;
-- Handle orphaned projects (created_by doesn't match any user)
-- Create a special orphaned projects team if there are any
DO $$
DECLARE
orphan_count INTEGER;
orphan_team_id UUID;
BEGIN
-- Count orphaned projects
SELECT COUNT(*) INTO orphan_count
FROM projects p
WHERE p.team_id IS NULL
AND NOT EXISTS (
SELECT 1 FROM users u WHERE u.username = p.created_by
);
IF orphan_count > 0 THEN
-- Create or get the orphaned projects team
INSERT INTO teams (name, slug, description, created_by, settings)
VALUES (
'Orphaned Projects',
'orphaned-projects',
'Projects whose original creators no longer exist',
'system',
'{"system": true}'::jsonb
)
ON CONFLICT (slug) DO UPDATE SET name = teams.name
RETURNING id INTO orphan_team_id;
-- Assign orphaned projects to this team
UPDATE projects
SET team_id = orphan_team_id
WHERE team_id IS NULL
AND NOT EXISTS (
SELECT 1 FROM users u WHERE u.username = projects.created_by
);
RAISE NOTICE 'Migrated % orphaned project(s) to orphaned-projects team', orphan_count;
END IF;
END $$;
-- Log migration results
DO $$
DECLARE
teams_created INTEGER;
memberships_created INTEGER;
projects_migrated INTEGER;
BEGIN
SELECT COUNT(*) INTO teams_created FROM teams WHERE slug LIKE '%-personal';
SELECT COUNT(*) INTO memberships_created FROM team_memberships;
SELECT COUNT(*) INTO projects_migrated FROM projects WHERE team_id IS NOT NULL;
RAISE NOTICE 'Migration complete: % personal teams, % memberships, % projects with teams',
teams_created, memberships_created, projects_migrated;
END $$;