Compare commits
3 Commits
7d66c99815
...
60aed51f3c
| Author | SHA1 | Date | |
|---|---|---|---|
| 60aed51f3c | |||
| 7259d24b89 | |||
| 9f0ea70a89 |
@ -5,6 +5,9 @@ Complete command-line interface for the Gantt Board. All web UI operations avail
|
||||
## Quick Start
|
||||
|
||||
```bash
|
||||
# Pull latest schema from Supabase into supabase/schema.sql
|
||||
SUPABASE_DB_URL='postgresql://...' ./scripts/pull-supabase-schema.sh
|
||||
|
||||
# List all tasks
|
||||
./scripts/gantt.sh task list
|
||||
|
||||
@ -24,6 +27,24 @@ Complete command-line interface for the Gantt Board. All web UI operations avail
|
||||
./scripts/gantt.sh task attach <task-id> ./notes.md
|
||||
```
|
||||
|
||||
## Schema Dump Script
|
||||
|
||||
Use `pull-supabase-schema.sh` when `supabase/schema.sql` needs to match the live database:
|
||||
|
||||
```bash
|
||||
SUPABASE_DB_URL='postgresql://postgres:***@db.<project-ref>.supabase.co:5432/postgres?sslmode=require' \
|
||||
./scripts/pull-supabase-schema.sh
|
||||
```
|
||||
|
||||
Optional:
|
||||
|
||||
```bash
|
||||
# Include additional schemas
|
||||
SCHEMAS='public,auth,storage' \
|
||||
SUPABASE_DB_URL='postgresql://...' \
|
||||
./scripts/pull-supabase-schema.sh supabase/full-schema.sql
|
||||
```
|
||||
|
||||
## Main CLI: `gantt.sh`
|
||||
|
||||
A unified CLI that covers all API operations.
|
||||
|
||||
95
scripts/pull-supabase-schema.sh
Executable file
95
scripts/pull-supabase-schema.sh
Executable file
@ -0,0 +1,95 @@
|
||||
#!/usr/bin/env bash
|
||||
set -euo pipefail
|
||||
|
||||
usage() {
|
||||
cat <<'EOF'
|
||||
Usage:
|
||||
SUPABASE_DB_URL='postgresql://...' ./scripts/pull-supabase-schema.sh [output_file]
|
||||
|
||||
Description:
|
||||
Dumps the current Supabase schema using pg_dump and writes it to a file.
|
||||
|
||||
Defaults:
|
||||
output_file: supabase/schema.sql
|
||||
SCHEMAS: public
|
||||
|
||||
Optional env vars:
|
||||
SCHEMAS Comma-separated schemas to include (example: public,auth,storage)
|
||||
SUPABASE_DB_URL Postgres connection URI from Supabase Database settings
|
||||
|
||||
Examples:
|
||||
SUPABASE_DB_URL='postgresql://postgres:***@db.xxx.supabase.co:5432/postgres?sslmode=require' \
|
||||
./scripts/pull-supabase-schema.sh
|
||||
|
||||
SCHEMAS='public,auth,storage' \
|
||||
SUPABASE_DB_URL='postgresql://postgres:***@db.xxx.supabase.co:5432/postgres?sslmode=require' \
|
||||
./scripts/pull-supabase-schema.sh supabase/full-schema.sql
|
||||
EOF
|
||||
}
|
||||
|
||||
if [[ "${1:-}" == "-h" || "${1:-}" == "--help" ]]; then
|
||||
usage
|
||||
exit 0
|
||||
fi
|
||||
|
||||
if ! command -v pg_dump >/dev/null 2>&1; then
|
||||
echo "Error: pg_dump is required but was not found."
|
||||
echo "Install PostgreSQL client tools (e.g. 'brew install postgresql@16')."
|
||||
exit 1
|
||||
fi
|
||||
|
||||
if [[ -z "${SUPABASE_DB_URL:-}" ]]; then
|
||||
echo "Error: SUPABASE_DB_URL is not set."
|
||||
echo "Copy the Postgres connection string from Supabase:"
|
||||
echo " Project Settings -> Database -> Connection string (URI)"
|
||||
usage
|
||||
exit 1
|
||||
fi
|
||||
|
||||
OUTPUT_FILE="${1:-supabase/schema.sql}"
|
||||
SCHEMAS_CSV="${SCHEMAS:-public}"
|
||||
DB_URL="${SUPABASE_DB_URL}"
|
||||
|
||||
# Ensure SSL is required if it is not already present in the URI.
|
||||
if [[ "${DB_URL}" != *"sslmode="* ]]; then
|
||||
if [[ "${DB_URL}" == *"?"* ]]; then
|
||||
DB_URL="${DB_URL}&sslmode=require"
|
||||
else
|
||||
DB_URL="${DB_URL}?sslmode=require"
|
||||
fi
|
||||
fi
|
||||
|
||||
IFS=',' read -r -a RAW_SCHEMAS <<< "${SCHEMAS_CSV}"
|
||||
SCHEMA_ARGS=()
|
||||
for raw_schema in "${RAW_SCHEMAS[@]}"; do
|
||||
schema="$(printf "%s" "${raw_schema}" | tr -d '[:space:]')"
|
||||
if [[ -n "${schema}" ]]; then
|
||||
SCHEMA_ARGS+=(--schema="${schema}")
|
||||
fi
|
||||
done
|
||||
|
||||
if [[ ${#SCHEMA_ARGS[@]} -eq 0 ]]; then
|
||||
echo "Error: no schemas selected. Set SCHEMAS to at least one schema name."
|
||||
exit 1
|
||||
fi
|
||||
|
||||
mkdir -p "$(dirname "${OUTPUT_FILE}")"
|
||||
tmp_file="$(mktemp)"
|
||||
trap 'rm -f "${tmp_file}"' EXIT
|
||||
|
||||
pg_dump "${DB_URL}" \
|
||||
--schema-only \
|
||||
--no-owner \
|
||||
--no-privileges \
|
||||
"${SCHEMA_ARGS[@]}" \
|
||||
> "${tmp_file}"
|
||||
|
||||
{
|
||||
echo "-- Generated by scripts/pull-supabase-schema.sh"
|
||||
echo "-- Generated at: $(date -u +"%Y-%m-%dT%H:%M:%SZ")"
|
||||
echo "-- Schemas: ${SCHEMAS_CSV}"
|
||||
echo
|
||||
cat "${tmp_file}"
|
||||
} > "${OUTPUT_FILE}"
|
||||
|
||||
echo "Schema dump written to ${OUTPUT_FILE}"
|
||||
69
supabase/nightly_sprint_rollover.sql
Normal file
69
supabase/nightly_sprint_rollover.sql
Normal file
@ -0,0 +1,69 @@
|
||||
-- Nightly sprint auto-close + rollover job
|
||||
-- Schedule: 12:01 AM UTC every day
|
||||
|
||||
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, project_id
|
||||
FROM public.sprints
|
||||
WHERE status <> 'completed'
|
||||
AND end_date < CURRENT_DATE
|
||||
ORDER BY end_date ASC, start_date ASC
|
||||
LOOP
|
||||
-- Pick the next non-completed sprint in the same project.
|
||||
SELECT s.id
|
||||
INTO next_sprint_id
|
||||
FROM public.sprints s
|
||||
WHERE s.project_id = ended_sprint.project_id
|
||||
AND s.status <> 'completed'
|
||||
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;
|
||||
|
||||
UPDATE public.sprints
|
||||
SET status = 'completed'
|
||||
WHERE id = ended_sprint.id;
|
||||
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;
|
||||
$$;
|
||||
|
||||
@ -9,14 +9,17 @@ CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
|
||||
-- ============================================
|
||||
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;
|
||||
@ -29,17 +32,6 @@ CREATE POLICY "Users can read own data" ON users
|
||||
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
|
||||
-- ============================================
|
||||
@ -91,12 +83,16 @@ CREATE POLICY "Service role manages reset tokens" ON password_reset_tokens
|
||||
-- ============================================
|
||||
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;
|
||||
|
||||
@ -121,6 +117,7 @@ CREATE POLICY "Authenticated users can delete projects" ON projects
|
||||
-- ============================================
|
||||
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,
|
||||
@ -132,6 +129,7 @@ CREATE TABLE IF NOT EXISTS sprints (
|
||||
|
||||
-- Create indexes
|
||||
CREATE INDEX IF NOT EXISTS idx_sprints_project_id ON sprints(project_id);
|
||||
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
|
||||
@ -146,6 +144,7 @@ CREATE POLICY "Authenticated users can manage sprints" ON sprints
|
||||
-- ============================================
|
||||
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')),
|
||||
@ -156,8 +155,15 @@ CREATE TABLE IF NOT EXISTS tasks (
|
||||
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,
|
||||
@ -171,6 +177,7 @@ 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
|
||||
@ -195,6 +202,26 @@ ALTER TABLE tasks ENABLE ROW LEVEL SECURITY;
|
||||
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
|
||||
-- ============================================
|
||||
@ -214,3 +241,75 @@ 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, project_id
|
||||
FROM public.sprints
|
||||
WHERE status <> 'completed'
|
||||
AND end_date < CURRENT_DATE
|
||||
ORDER BY end_date ASC, start_date ASC
|
||||
LOOP
|
||||
-- Pick the next non-completed sprint in the same project.
|
||||
SELECT s.id
|
||||
INTO next_sprint_id
|
||||
FROM public.sprints s
|
||||
WHERE s.project_id = ended_sprint.project_id
|
||||
AND s.status <> 'completed'
|
||||
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;
|
||||
|
||||
UPDATE public.sprints
|
||||
SET status = 'completed'
|
||||
WHERE id = ended_sprint.id;
|
||||
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;
|
||||
$$;
|
||||
|
||||
Loading…
Reference in New Issue
Block a user