-- 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';