333 lines
11 KiB
PL/PgSQL
333 lines
11 KiB
PL/PgSQL
-- Mylder Platform Database Schema
|
|
-- Run this in Supabase Studio SQL Editor after deployment
|
|
|
|
-- Enable required extensions
|
|
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
|
|
|
|
-- ============================================
|
|
-- PROFILES (extends auth.users)
|
|
-- ============================================
|
|
CREATE TABLE IF NOT EXISTS public.profiles (
|
|
id UUID REFERENCES auth.users(id) ON DELETE CASCADE PRIMARY KEY,
|
|
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()
|
|
);
|
|
|
|
-- Auto-create profile on user signup
|
|
CREATE OR REPLACE FUNCTION public.handle_new_user()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
INSERT INTO public.profiles (id, email, full_name, avatar_url)
|
|
VALUES (
|
|
NEW.id,
|
|
NEW.email,
|
|
NEW.raw_user_meta_data->>'full_name',
|
|
NEW.raw_user_meta_data->>'avatar_url'
|
|
);
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
|
|
|
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 public.handle_new_user();
|
|
|
|
-- ============================================
|
|
-- TEAMS
|
|
-- ============================================
|
|
CREATE TABLE IF NOT EXISTS public.teams (
|
|
id UUID DEFAULT uuid_generate_v4() PRIMARY KEY,
|
|
name TEXT NOT NULL,
|
|
owner_id UUID REFERENCES public.profiles(id) ON DELETE CASCADE NOT NULL,
|
|
stripe_customer_id TEXT,
|
|
plan TEXT DEFAULT 'free' CHECK (plan IN ('free', 'pro', 'enterprise')),
|
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
|
updated_at TIMESTAMPTZ DEFAULT NOW()
|
|
);
|
|
|
|
-- ============================================
|
|
-- TEAM MEMBERS
|
|
-- ============================================
|
|
CREATE TABLE IF NOT EXISTS public.team_members (
|
|
team_id UUID REFERENCES public.teams(id) ON DELETE CASCADE,
|
|
user_id UUID REFERENCES public.profiles(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)
|
|
);
|
|
|
|
-- Auto-add owner as team member
|
|
CREATE OR REPLACE FUNCTION public.handle_new_team()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
INSERT INTO public.team_members (team_id, user_id, role)
|
|
VALUES (NEW.id, NEW.owner_id, 'owner');
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
|
|
|
DROP TRIGGER IF EXISTS on_team_created ON public.teams;
|
|
CREATE TRIGGER on_team_created
|
|
AFTER INSERT ON public.teams
|
|
FOR EACH ROW EXECUTE FUNCTION public.handle_new_team();
|
|
|
|
-- ============================================
|
|
-- PROJECTS
|
|
-- ============================================
|
|
CREATE TABLE IF NOT EXISTS public.projects (
|
|
id UUID DEFAULT uuid_generate_v4() PRIMARY KEY,
|
|
team_id UUID REFERENCES public.teams(id) ON DELETE CASCADE NOT NULL,
|
|
name TEXT NOT NULL,
|
|
slug TEXT NOT NULL,
|
|
description TEXT,
|
|
gitea_repo TEXT,
|
|
tech_stack TEXT[] DEFAULT '{}',
|
|
platform TEXT,
|
|
status TEXT DEFAULT 'active' CHECK (status IN ('active', 'archived', 'paused')),
|
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
|
updated_at TIMESTAMPTZ DEFAULT NOW(),
|
|
UNIQUE(team_id, slug)
|
|
);
|
|
|
|
-- ============================================
|
|
-- MESSAGES
|
|
-- ============================================
|
|
CREATE TABLE IF NOT EXISTS public.messages (
|
|
id UUID DEFAULT uuid_generate_v4() PRIMARY KEY,
|
|
project_id UUID REFERENCES public.projects(id) ON DELETE CASCADE NOT NULL,
|
|
user_id UUID REFERENCES public.profiles(id) ON DELETE SET NULL,
|
|
role TEXT NOT NULL CHECK (role IN ('user', 'assistant', 'system')),
|
|
content TEXT NOT NULL,
|
|
metadata JSONB,
|
|
created_at TIMESTAMPTZ DEFAULT NOW()
|
|
);
|
|
|
|
-- ============================================
|
|
-- AGENT RUNS
|
|
-- ============================================
|
|
CREATE TABLE IF NOT EXISTS public.agent_runs (
|
|
id UUID DEFAULT uuid_generate_v4() PRIMARY KEY,
|
|
message_id UUID REFERENCES public.messages(id) ON DELETE CASCADE NOT NULL,
|
|
project_id UUID REFERENCES public.projects(id) ON DELETE CASCADE NOT NULL,
|
|
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()
|
|
);
|
|
|
|
-- ============================================
|
|
-- ISSUES (synced from Gitea)
|
|
-- ============================================
|
|
CREATE TABLE IF NOT EXISTS public.issues (
|
|
id UUID DEFAULT uuid_generate_v4() PRIMARY KEY,
|
|
project_id UUID REFERENCES public.projects(id) ON DELETE CASCADE NOT NULL,
|
|
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(),
|
|
UNIQUE(project_id, gitea_id)
|
|
);
|
|
|
|
-- ============================================
|
|
-- UPDATED_AT TRIGGER
|
|
-- ============================================
|
|
CREATE OR REPLACE FUNCTION public.update_updated_at()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
NEW.updated_at = NOW();
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- Apply to all tables with updated_at
|
|
DROP TRIGGER IF EXISTS update_profiles_updated_at ON public.profiles;
|
|
CREATE TRIGGER update_profiles_updated_at
|
|
BEFORE UPDATE ON public.profiles
|
|
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at();
|
|
|
|
DROP TRIGGER IF EXISTS update_teams_updated_at ON public.teams;
|
|
CREATE TRIGGER update_teams_updated_at
|
|
BEFORE UPDATE ON public.teams
|
|
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at();
|
|
|
|
DROP TRIGGER IF EXISTS update_projects_updated_at ON public.projects;
|
|
CREATE TRIGGER update_projects_updated_at
|
|
BEFORE UPDATE ON public.projects
|
|
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at();
|
|
|
|
DROP TRIGGER IF EXISTS update_issues_updated_at ON public.issues;
|
|
CREATE TRIGGER update_issues_updated_at
|
|
BEFORE UPDATE ON public.issues
|
|
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at();
|
|
|
|
-- ============================================
|
|
-- ROW LEVEL SECURITY (RLS)
|
|
-- ============================================
|
|
|
|
-- Enable RLS on all tables
|
|
ALTER TABLE public.profiles ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE public.teams ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE public.team_members ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE public.projects ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE public.messages ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE public.agent_runs ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE public.issues ENABLE ROW LEVEL SECURITY;
|
|
|
|
-- PROFILES
|
|
CREATE POLICY "Users can view own profile" ON public.profiles
|
|
FOR SELECT USING (auth.uid() = id);
|
|
|
|
CREATE POLICY "Users can update own profile" ON public.profiles
|
|
FOR UPDATE USING (auth.uid() = id);
|
|
|
|
-- TEAMS
|
|
CREATE POLICY "Team members can view their teams" ON public.teams
|
|
FOR SELECT USING (
|
|
EXISTS (
|
|
SELECT 1 FROM public.team_members
|
|
WHERE team_members.team_id = teams.id
|
|
AND team_members.user_id = auth.uid()
|
|
)
|
|
);
|
|
|
|
CREATE POLICY "Users can create teams" ON public.teams
|
|
FOR INSERT WITH CHECK (auth.uid() = owner_id);
|
|
|
|
CREATE POLICY "Team owners can update teams" ON public.teams
|
|
FOR UPDATE USING (auth.uid() = owner_id);
|
|
|
|
CREATE POLICY "Team owners can delete teams" ON public.teams
|
|
FOR DELETE USING (auth.uid() = owner_id);
|
|
|
|
-- TEAM MEMBERS
|
|
CREATE POLICY "Team members can view team membership" ON public.team_members
|
|
FOR SELECT USING (
|
|
EXISTS (
|
|
SELECT 1 FROM public.team_members tm
|
|
WHERE tm.team_id = team_members.team_id
|
|
AND tm.user_id = auth.uid()
|
|
)
|
|
);
|
|
|
|
-- PROJECTS
|
|
CREATE POLICY "Team members can view projects" ON public.projects
|
|
FOR SELECT USING (
|
|
EXISTS (
|
|
SELECT 1 FROM public.team_members
|
|
WHERE team_members.team_id = projects.team_id
|
|
AND team_members.user_id = auth.uid()
|
|
)
|
|
);
|
|
|
|
CREATE POLICY "Team members can create projects" ON public.projects
|
|
FOR INSERT WITH CHECK (
|
|
EXISTS (
|
|
SELECT 1 FROM public.team_members
|
|
WHERE team_members.team_id = projects.team_id
|
|
AND team_members.user_id = auth.uid()
|
|
)
|
|
);
|
|
|
|
CREATE POLICY "Team members can update projects" ON public.projects
|
|
FOR UPDATE USING (
|
|
EXISTS (
|
|
SELECT 1 FROM public.team_members
|
|
WHERE team_members.team_id = projects.team_id
|
|
AND team_members.user_id = auth.uid()
|
|
)
|
|
);
|
|
|
|
-- MESSAGES
|
|
CREATE POLICY "Team members can view messages" ON public.messages
|
|
FOR SELECT USING (
|
|
EXISTS (
|
|
SELECT 1 FROM public.projects p
|
|
JOIN public.team_members tm ON tm.team_id = p.team_id
|
|
WHERE p.id = messages.project_id
|
|
AND tm.user_id = auth.uid()
|
|
)
|
|
);
|
|
|
|
CREATE POLICY "Team members can create messages" ON public.messages
|
|
FOR INSERT WITH CHECK (
|
|
EXISTS (
|
|
SELECT 1 FROM public.projects p
|
|
JOIN public.team_members tm ON tm.team_id = p.team_id
|
|
WHERE p.id = messages.project_id
|
|
AND tm.user_id = auth.uid()
|
|
)
|
|
);
|
|
|
|
-- AGENT RUNS
|
|
CREATE POLICY "Team members can view agent runs" ON public.agent_runs
|
|
FOR SELECT USING (
|
|
EXISTS (
|
|
SELECT 1 FROM public.projects p
|
|
JOIN public.team_members tm ON tm.team_id = p.team_id
|
|
WHERE p.id = agent_runs.project_id
|
|
AND tm.user_id = auth.uid()
|
|
)
|
|
);
|
|
|
|
-- ISSUES
|
|
CREATE POLICY "Team members can view issues" ON public.issues
|
|
FOR SELECT USING (
|
|
EXISTS (
|
|
SELECT 1 FROM public.projects p
|
|
JOIN public.team_members tm ON tm.team_id = p.team_id
|
|
WHERE p.id = issues.project_id
|
|
AND tm.user_id = auth.uid()
|
|
)
|
|
);
|
|
|
|
CREATE POLICY "Team members can manage issues" ON public.issues
|
|
FOR ALL USING (
|
|
EXISTS (
|
|
SELECT 1 FROM public.projects p
|
|
JOIN public.team_members tm ON tm.team_id = p.team_id
|
|
WHERE p.id = issues.project_id
|
|
AND tm.user_id = auth.uid()
|
|
)
|
|
);
|
|
|
|
-- ============================================
|
|
-- REALTIME SUBSCRIPTIONS
|
|
-- ============================================
|
|
|
|
-- Enable realtime for specific tables
|
|
ALTER PUBLICATION supabase_realtime ADD TABLE public.messages;
|
|
ALTER PUBLICATION supabase_realtime ADD TABLE public.agent_runs;
|
|
ALTER PUBLICATION supabase_realtime ADD TABLE public.issues;
|
|
|
|
-- ============================================
|
|
-- INDEXES
|
|
-- ============================================
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_team_members_user ON public.team_members(user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_projects_team ON public.projects(team_id);
|
|
CREATE INDEX IF NOT EXISTS idx_messages_project ON public.messages(project_id);
|
|
CREATE INDEX IF NOT EXISTS idx_messages_created ON public.messages(created_at DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_agent_runs_project ON public.agent_runs(project_id);
|
|
CREATE INDEX IF NOT EXISTS idx_issues_project ON public.issues(project_id);
|
|
|
|
-- ============================================
|
|
-- GRANTS
|
|
-- ============================================
|
|
|
|
GRANT USAGE ON SCHEMA public TO anon, authenticated;
|
|
GRANT ALL ON ALL TABLES IN SCHEMA public TO anon, authenticated;
|
|
GRANT ALL ON ALL SEQUENCES IN SCHEMA public TO anon, authenticated;
|
|
GRANT ALL ON ALL FUNCTIONS IN SCHEMA public TO anon, authenticated;
|