gantt-board/supabase/schema.sql

308 lines
10 KiB
PL/PgSQL

-- 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(),
legacy_id TEXT UNIQUE, -- For migration from SQLite
name TEXT NOT NULL,
email TEXT NOT NULL UNIQUE,
avatar_url TEXT,
password_hash TEXT NOT NULL,
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);
CREATE INDEX IF NOT EXISTS idx_users_legacy_id ON users(legacy_id);
-- 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);
-- ============================================
-- 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(),
legacy_id TEXT UNIQUE, -- For migration from SQLite
name TEXT NOT NULL,
description TEXT,
color TEXT NOT NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- Create index for legacy ID lookups
CREATE INDEX IF NOT EXISTS idx_projects_legacy_id ON projects(legacy_id);
-- 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(),
legacy_id TEXT UNIQUE, -- For migration from SQLite
name TEXT NOT NULL,
goal TEXT,
start_date DATE NOT NULL,
end_date DATE NOT NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- Create indexes
CREATE INDEX IF NOT EXISTS idx_sprints_legacy_id ON sprints(legacy_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(),
legacy_id TEXT UNIQUE, -- For migration from SQLite
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,
created_by_name TEXT,
created_by_avatar_url TEXT,
updated_by_id UUID REFERENCES users(id) ON DELETE SET NULL,
updated_by_name TEXT,
updated_by_avatar_url TEXT,
assignee_id UUID REFERENCES users(id) ON DELETE SET NULL,
assignee_name TEXT,
assignee_email TEXT,
assignee_avatar_url TEXT,
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_legacy_id ON tasks(legacy_id);
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');
-- ============================================
-- META TABLE (for app state like lastUpdated)
-- ============================================
CREATE TABLE IF NOT EXISTS meta (
key TEXT PRIMARY KEY,
value TEXT NOT NULL,
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- Enable RLS
ALTER TABLE meta ENABLE ROW LEVEL SECURITY;
-- Policy: All authenticated users can manage meta
CREATE POLICY "Authenticated users can manage meta" ON meta
FOR ALL USING (auth.role() = 'authenticated');
-- Insert initial lastUpdated value
INSERT INTO meta (key, value) VALUES ('lastUpdated', extract(epoch from now()) * 1000)
ON CONFLICT (key) DO UPDATE SET value = excluded.value;
-- ============================================
-- 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;
-- ============================================
-- NIGHTLY SPRINT AUTO-CLOSE + ROLLOVER
-- ============================================
-- Runs every night at 12:01 AM UTC.
-- If you need local time, convert your desired local time to UTC in the cron expression.
CREATE EXTENSION IF NOT EXISTS pg_cron;
CREATE OR REPLACE FUNCTION public.complete_ended_sprints_and_rollover()
RETURNS void
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path = public
AS $$
DECLARE
ended_sprint RECORD;
next_sprint_id UUID;
BEGIN
FOR ended_sprint IN
SELECT id
FROM public.sprints
WHERE end_date < CURRENT_DATE
ORDER BY end_date ASC, start_date ASC
LOOP
-- Pick the next sprint that has not yet ended.
SELECT s.id
INTO next_sprint_id
FROM public.sprints s
WHERE s.end_date >= CURRENT_DATE
AND s.id <> ended_sprint.id
ORDER BY s.start_date ASC
LIMIT 1;
IF next_sprint_id IS NOT NULL THEN
UPDATE public.tasks
SET sprint_id = next_sprint_id
WHERE sprint_id = ended_sprint.id
AND status NOT IN ('done', 'canceled', 'archived');
END IF;
END LOOP;
END;
$$;
DO $$
DECLARE
existing_job_id BIGINT;
BEGIN
-- Keep this idempotent: replace existing job if present.
SELECT jobid
INTO existing_job_id
FROM cron.job
WHERE jobname = 'nightly-sprint-rollover-0001'
LIMIT 1;
IF existing_job_id IS NOT NULL THEN
PERFORM cron.unschedule(existing_job_id);
END IF;
PERFORM cron.schedule(
'nightly-sprint-rollover-0001',
'1 0 * * *',
'select public.complete_ended_sprints_and_rollover();'
);
END;
$$;