-- Supabase Schema for Gantt Board -- Run this in the Supabase SQL Editor -- Enable UUID extension CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; -- ============================================ -- USERS TABLE -- ============================================ CREATE TABLE IF NOT EXISTS users ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), name TEXT NOT NULL, email TEXT NOT NULL UNIQUE, avatar_url TEXT, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- Create index on email for faster lookups CREATE INDEX IF NOT EXISTS idx_users_email ON users(email); -- Enable RLS ALTER TABLE users ENABLE ROW LEVEL SECURITY; -- Policy: Users can read their own data CREATE POLICY "Users can read own data" ON users FOR SELECT USING (auth.uid() = id); -- Policy: Users can update their own data CREATE POLICY "Users can update own data" ON users FOR UPDATE USING (auth.uid() = id); -- ============================================ -- PROFILES TABLE -- ============================================ CREATE TABLE IF NOT EXISTS profiles ( id UUID PRIMARY KEY REFERENCES auth.users(id), name TEXT, avatar_url TEXT, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- ============================================ -- SESSIONS TABLE -- ============================================ CREATE TABLE IF NOT EXISTS sessions ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, token_hash TEXT NOT NULL UNIQUE, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), expires_at TIMESTAMPTZ NOT NULL ); -- Create indexes for faster lookups CREATE INDEX IF NOT EXISTS idx_sessions_token_hash ON sessions(token_hash); CREATE INDEX IF NOT EXISTS idx_sessions_user_id ON sessions(user_id); CREATE INDEX IF NOT EXISTS idx_sessions_expires_at ON sessions(expires_at); -- Enable RLS ALTER TABLE sessions ENABLE ROW LEVEL SECURITY; -- Policy: Users can only see their own sessions CREATE POLICY "Users can manage own sessions" ON sessions FOR ALL USING (auth.uid() = user_id); -- ============================================ -- PASSWORD RESET TOKENS TABLE -- ============================================ CREATE TABLE IF NOT EXISTS password_reset_tokens ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, token_hash TEXT NOT NULL UNIQUE, expires_at TIMESTAMPTZ NOT NULL, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), used BOOLEAN DEFAULT FALSE ); -- Create indexes CREATE INDEX IF NOT EXISTS idx_reset_tokens_hash ON password_reset_tokens(token_hash); CREATE INDEX IF NOT EXISTS idx_reset_tokens_user ON password_reset_tokens(user_id); -- Enable RLS ALTER TABLE password_reset_tokens ENABLE ROW LEVEL SECURITY; -- Policy: Only service role can manage reset tokens CREATE POLICY "Service role manages reset tokens" ON password_reset_tokens FOR ALL USING (false); -- ============================================ -- PROJECTS TABLE -- ============================================ CREATE TABLE IF NOT EXISTS projects ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), name TEXT NOT NULL, description TEXT, color TEXT NOT NULL, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- Enable RLS ALTER TABLE projects ENABLE ROW LEVEL SECURITY; -- Policy: All authenticated users can read projects CREATE POLICY "Authenticated users can read projects" ON projects FOR SELECT USING (auth.role() = 'authenticated'); -- Policy: All authenticated users can create projects CREATE POLICY "Authenticated users can create projects" ON projects FOR INSERT WITH CHECK (auth.role() = 'authenticated'); -- Policy: All authenticated users can update projects CREATE POLICY "Authenticated users can update projects" ON projects FOR UPDATE USING (auth.role() = 'authenticated'); -- Policy: All authenticated users can delete projects CREATE POLICY "Authenticated users can delete projects" ON projects FOR DELETE USING (auth.role() = 'authenticated'); -- ============================================ -- SPRINTS TABLE -- ============================================ CREATE TABLE IF NOT EXISTS sprints ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), name TEXT NOT NULL, goal TEXT, start_date DATE NOT NULL, end_date DATE NOT NULL, status TEXT NOT NULL CHECK (status IN ('planning', 'active', 'completed')), project_id UUID NOT NULL REFERENCES projects(id) ON DELETE CASCADE, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- Create indexes CREATE INDEX IF NOT EXISTS idx_sprints_project_id ON sprints(project_id); CREATE INDEX IF NOT EXISTS idx_sprints_dates ON sprints(start_date, end_date); -- Enable RLS ALTER TABLE sprints ENABLE ROW LEVEL SECURITY; -- Policy: All authenticated users can manage sprints CREATE POLICY "Authenticated users can manage sprints" ON sprints FOR ALL USING (auth.role() = 'authenticated'); -- ============================================ -- TASKS TABLE -- ============================================ CREATE TABLE IF NOT EXISTS tasks ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), title TEXT NOT NULL, description TEXT, type TEXT NOT NULL CHECK (type IN ('idea', 'task', 'bug', 'research', 'plan')), status TEXT NOT NULL CHECK (status IN ('open', 'todo', 'blocked', 'in-progress', 'review', 'validate', 'archived', 'canceled', 'done')), priority TEXT NOT NULL CHECK (priority IN ('low', 'medium', 'high', 'urgent')), project_id UUID NOT NULL REFERENCES projects(id) ON DELETE CASCADE, sprint_id UUID REFERENCES sprints(id) ON DELETE SET NULL, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), created_by_id UUID REFERENCES users(id) ON DELETE SET NULL, updated_by_id UUID REFERENCES users(id) ON DELETE SET NULL, assignee_id UUID REFERENCES users(id) ON DELETE SET NULL, due_date DATE, comments JSONB NOT NULL DEFAULT '[]'::jsonb, tags JSONB NOT NULL DEFAULT '[]'::jsonb, attachments JSONB NOT NULL DEFAULT '[]'::jsonb ); -- Create indexes for performance CREATE INDEX IF NOT EXISTS idx_tasks_project_id ON tasks(project_id); CREATE INDEX IF NOT EXISTS idx_tasks_sprint_id ON tasks(sprint_id); CREATE INDEX IF NOT EXISTS idx_tasks_assignee_id ON tasks(assignee_id); CREATE INDEX IF NOT EXISTS idx_tasks_status ON tasks(status); CREATE INDEX IF NOT EXISTS idx_tasks_priority ON tasks(priority); CREATE INDEX IF NOT EXISTS idx_tasks_due_date ON tasks(due_date); CREATE INDEX IF NOT EXISTS idx_tasks_updated_at ON tasks(updated_at DESC); -- Create trigger to auto-update updated_at CREATE OR REPLACE FUNCTION update_updated_at_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$ language 'plpgsql'; DROP TRIGGER IF EXISTS update_tasks_updated_at ON tasks; CREATE TRIGGER update_tasks_updated_at BEFORE UPDATE ON tasks FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- Enable RLS ALTER TABLE tasks ENABLE ROW LEVEL SECURITY; -- Policy: All authenticated users can manage tasks CREATE POLICY "Authenticated users can manage tasks" ON tasks FOR ALL USING (auth.role() = 'authenticated'); -- ============================================ -- FUNCTIONS -- ============================================ -- Function to clean up expired sessions (can be called by cron) CREATE OR REPLACE FUNCTION cleanup_expired_sessions() RETURNS void AS $$ BEGIN DELETE FROM sessions WHERE expires_at <= NOW(); END; $$ LANGUAGE plpgsql; -- Function to clean up expired password reset tokens CREATE OR REPLACE FUNCTION cleanup_expired_reset_tokens() RETURNS void AS $$ BEGIN DELETE FROM password_reset_tokens WHERE expires_at <= NOW() OR used = true; END; $$ LANGUAGE plpgsql;