-- Profiles and Auth Triggers for Mylder Platform -- Migration: 20251214_profiles_and_auth.sql -- Enable UUID extension (if not already enabled) CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; -- ============================================ -- PROFILES TABLE -- ============================================ CREATE TABLE IF NOT EXISTS profiles ( id UUID PRIMARY KEY REFERENCES auth.users(id) ON DELETE CASCADE, email TEXT NOT NULL, full_name TEXT, avatar_url TEXT, role TEXT DEFAULT 'user' CHECK (role IN ('user', 'admin')), created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW() ); -- Index for email lookups CREATE INDEX IF NOT EXISTS idx_profiles_email ON profiles(email); -- Enable RLS ALTER TABLE profiles ENABLE ROW LEVEL SECURITY; -- RLS Policies for profiles CREATE POLICY "Users can view their own profile" ON profiles FOR SELECT USING (auth.uid() = id); CREATE POLICY "Users can update their own profile" ON profiles FOR UPDATE USING (auth.uid() = id); -- Service role can manage all profiles (for admin operations) CREATE POLICY "Service role can manage all profiles" ON profiles FOR ALL USING ( auth.jwt() ->> 'role' = 'service_role' ); -- ============================================ -- TEAMS TABLE -- ============================================ CREATE TABLE IF NOT EXISTS teams ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), name TEXT NOT NULL, owner_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, stripe_customer_id TEXT, plan TEXT DEFAULT 'free' CHECK (plan IN ('free', 'pro', 'enterprise')), created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW() ); CREATE INDEX IF NOT EXISTS idx_teams_owner_id ON teams(owner_id); ALTER TABLE teams ENABLE ROW LEVEL SECURITY; CREATE POLICY "Team owners can manage their teams" ON teams FOR ALL USING (auth.uid() = owner_id); -- ============================================ -- TEAM MEMBERS TABLE -- ============================================ CREATE TABLE IF NOT EXISTS team_members ( team_id UUID NOT NULL REFERENCES teams(id) ON DELETE CASCADE, user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, role TEXT DEFAULT 'member' CHECK (role IN ('owner', 'admin', 'member')), created_at TIMESTAMPTZ DEFAULT NOW(), PRIMARY KEY (team_id, user_id) ); CREATE INDEX IF NOT EXISTS idx_team_members_user_id ON team_members(user_id); ALTER TABLE team_members ENABLE ROW LEVEL SECURITY; CREATE POLICY "Team members can view their memberships" ON team_members FOR SELECT USING (auth.uid() = user_id); CREATE POLICY "Team owners can manage memberships" ON team_members FOR ALL USING ( EXISTS (SELECT 1 FROM teams WHERE teams.id = team_members.team_id AND teams.owner_id = auth.uid()) ); -- ============================================ -- SUBSCRIPTIONS TABLE -- ============================================ CREATE TABLE IF NOT EXISTS subscriptions ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, stripe_customer_id TEXT, stripe_subscription_id TEXT, plan TEXT DEFAULT 'free' CHECK (plan IN ('free', 'pro', 'team')), status TEXT DEFAULT 'active' CHECK (status IN ('active', 'canceled', 'past_due', 'incomplete')), current_period_start TIMESTAMPTZ, current_period_end TIMESTAMPTZ, cancel_at_period_end BOOLEAN DEFAULT FALSE, created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW() ); CREATE INDEX IF NOT EXISTS idx_subscriptions_user_id ON subscriptions(user_id); CREATE INDEX IF NOT EXISTS idx_subscriptions_stripe_customer_id ON subscriptions(stripe_customer_id); ALTER TABLE subscriptions ENABLE ROW LEVEL SECURITY; CREATE POLICY "Users can view their own subscriptions" ON subscriptions FOR SELECT USING (auth.uid() = user_id); -- ============================================ -- MESSAGES TABLE (for chat history) -- ============================================ CREATE TABLE IF NOT EXISTS messages ( 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 auth.users(id) ON DELETE CASCADE, role TEXT NOT NULL CHECK (role IN ('user', 'assistant', 'system')), content TEXT NOT NULL, metadata JSONB DEFAULT '{}', created_at TIMESTAMPTZ DEFAULT NOW() ); CREATE INDEX IF NOT EXISTS idx_messages_project_id ON messages(project_id); CREATE INDEX IF NOT EXISTS idx_messages_user_id ON messages(user_id); CREATE INDEX IF NOT EXISTS idx_messages_created_at ON messages(created_at DESC); ALTER TABLE messages ENABLE ROW LEVEL SECURITY; CREATE POLICY "Users can manage messages in their projects" ON messages FOR ALL USING ( EXISTS (SELECT 1 FROM projects WHERE projects.id = messages.project_id AND projects.user_id = auth.uid()) ); -- ============================================ -- AGENT RUNS TABLE -- ============================================ CREATE TABLE IF NOT EXISTS agent_runs ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), message_id UUID NOT NULL REFERENCES messages(id) ON DELETE CASCADE, project_id UUID NOT NULL REFERENCES projects(id) ON DELETE CASCADE, command TEXT NOT NULL, status TEXT DEFAULT 'pending' CHECK (status IN ('pending', 'running', 'completed', 'failed', 'cancelled')), result JSONB, started_at TIMESTAMPTZ, completed_at TIMESTAMPTZ, created_at TIMESTAMPTZ DEFAULT NOW() ); CREATE INDEX IF NOT EXISTS idx_agent_runs_project_id ON agent_runs(project_id); CREATE INDEX IF NOT EXISTS idx_agent_runs_status ON agent_runs(status); ALTER TABLE agent_runs ENABLE ROW LEVEL SECURITY; CREATE POLICY "Users can view agent runs in their projects" ON agent_runs FOR ALL USING ( EXISTS (SELECT 1 FROM projects WHERE projects.id = agent_runs.project_id AND projects.user_id = auth.uid()) ); -- ============================================ -- ISSUES TABLE -- ============================================ CREATE TABLE IF NOT EXISTS issues ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), project_id UUID NOT NULL REFERENCES projects(id) ON DELETE CASCADE, gitea_id INTEGER, title TEXT NOT NULL, body TEXT, state TEXT DEFAULT 'open' CHECK (state IN ('open', 'closed')), labels TEXT[] DEFAULT '{}', assignee TEXT, milestone TEXT, created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW() ); CREATE INDEX IF NOT EXISTS idx_issues_project_id ON issues(project_id); CREATE INDEX IF NOT EXISTS idx_issues_state ON issues(state); ALTER TABLE issues ENABLE ROW LEVEL SECURITY; CREATE POLICY "Users can manage issues in their projects" ON issues FOR ALL USING ( EXISTS (SELECT 1 FROM projects WHERE projects.id = issues.project_id AND projects.user_id = auth.uid()) ); -- ============================================ -- TRIGGER: Auto-create profile on user signup -- ============================================ CREATE OR REPLACE FUNCTION handle_new_user() RETURNS TRIGGER AS $$ BEGIN INSERT INTO public.profiles (id, email, full_name, avatar_url, role) VALUES ( NEW.id, NEW.email, COALESCE(NEW.raw_user_meta_data->>'full_name', NEW.raw_user_meta_data->>'name', split_part(NEW.email, '@', 1)), COALESCE(NEW.raw_user_meta_data->>'avatar_url', NEW.raw_user_meta_data->>'picture'), 'user' ); -- Also create a default free subscription INSERT INTO public.subscriptions (user_id, plan, status) VALUES (NEW.id, 'free', 'active'); -- Create a default personal team INSERT INTO public.teams (name, owner_id, plan) VALUES ( COALESCE(NEW.raw_user_meta_data->>'full_name', split_part(NEW.email, '@', 1)) || '''s Team', NEW.id, 'free' ); -- Add user as owner of their team INSERT INTO public.team_members (team_id, user_id, role) SELECT id, NEW.id, 'owner' FROM public.teams WHERE owner_id = NEW.id LIMIT 1; RETURN NEW; END; $$ LANGUAGE plpgsql SECURITY DEFINER; -- Create the trigger on auth.users DROP TRIGGER IF EXISTS on_auth_user_created ON auth.users; CREATE TRIGGER on_auth_user_created AFTER INSERT ON auth.users FOR EACH ROW EXECUTE FUNCTION handle_new_user(); -- ============================================ -- TRIGGER: Update updated_at timestamp -- ============================================ CREATE OR REPLACE FUNCTION update_updated_at() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$ LANGUAGE plpgsql; -- Add updated_at triggers DROP TRIGGER IF EXISTS profiles_updated_at ON profiles; CREATE TRIGGER profiles_updated_at BEFORE UPDATE ON profiles FOR EACH ROW EXECUTE FUNCTION update_updated_at(); DROP TRIGGER IF EXISTS teams_updated_at ON teams; CREATE TRIGGER teams_updated_at BEFORE UPDATE ON teams FOR EACH ROW EXECUTE FUNCTION update_updated_at(); DROP TRIGGER IF EXISTS subscriptions_updated_at ON subscriptions; CREATE TRIGGER subscriptions_updated_at BEFORE UPDATE ON subscriptions FOR EACH ROW EXECUTE FUNCTION update_updated_at(); DROP TRIGGER IF EXISTS issues_updated_at ON issues; CREATE TRIGGER issues_updated_at BEFORE UPDATE ON issues FOR EACH ROW EXECUTE FUNCTION update_updated_at(); -- ============================================ -- COMMENTS -- ============================================ COMMENT ON TABLE profiles IS 'User profiles linked to auth.users'; COMMENT ON FUNCTION handle_new_user() IS 'Auto-creates profile, subscription, and personal team on user signup'; COMMENT ON TABLE teams IS 'Teams for multi-user collaboration'; COMMENT ON TABLE team_members IS 'Team membership with roles'; COMMENT ON TABLE subscriptions IS 'User subscription status for billing'; COMMENT ON TABLE messages IS 'Chat messages in project context'; COMMENT ON TABLE agent_runs IS 'AI agent execution history'; COMMENT ON TABLE issues IS 'Project issues synced with Gitea';