sojorn/_legacy/supabase/setup_complete.sql
2026-02-15 00:33:24 -06:00

362 lines
18 KiB
PL/PgSQL

-- ============================================================================
-- SOJORN DATABASE SETUP
-- Complete, idempotent schema for Sojorn social platform
-- ============================================================================
-- Extensions
DO $$ BEGIN CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; EXCEPTION WHEN duplicate_object THEN null; END $$;
DO $$ BEGIN CREATE EXTENSION IF NOT EXISTS "pg_trgm"; EXCEPTION WHEN duplicate_object THEN null; END $$;
DO $$ BEGIN CREATE EXTENSION IF NOT EXISTS "postgis"; EXCEPTION WHEN duplicate_object THEN null; END $$;
-- Types
DO $$ BEGIN CREATE TYPE beacon_type AS ENUM ('police', 'checkpoint', 'taskForce', 'hazard', 'safety', 'community'); EXCEPTION WHEN duplicate_object THEN null; END $$;
DO $$ BEGIN CREATE TYPE trust_tier AS ENUM ('new', 'trusted', 'established'); EXCEPTION WHEN duplicate_object THEN null; END $$;
DO $$ BEGIN CREATE TYPE notification_type AS ENUM ('appreciate', 'chain', 'follow', 'comment', 'mention', 'follow_request', 'new_follower', 'request_accepted'); EXCEPTION WHEN duplicate_object THEN null; END $$;
DO $$ BEGIN CREATE TYPE tone_label AS ENUM ('positive', 'neutral', 'mixed', 'negative', 'hostile'); EXCEPTION WHEN duplicate_object THEN null; END $$;
DO $$ BEGIN CREATE TYPE post_status AS ENUM ('active', 'flagged', 'removed'); EXCEPTION WHEN duplicate_object THEN null; END $$;
-- Tables
CREATE TABLE IF NOT EXISTS profiles (
id UUID PRIMARY KEY REFERENCES auth.users(id) ON DELETE CASCADE,
handle TEXT UNIQUE NOT NULL CHECK (handle ~ '^[a-z0-9_]{3,20}$'),
display_name TEXT NOT NULL CHECK (length(trim(display_name)) >= 1 AND length(display_name) <= 50),
bio TEXT CHECK (length(bio) <= 300),
avatar_url TEXT,
cover_url TEXT,
is_official BOOLEAN NOT NULL DEFAULT FALSE,
beacon_enabled BOOLEAN NOT NULL DEFAULT FALSE,
location TEXT,
website TEXT,
interests TEXT[],
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE TABLE IF NOT EXISTS trust_state (
user_id UUID PRIMARY KEY REFERENCES profiles(id) ON DELETE CASCADE,
harmony_score INTEGER NOT NULL DEFAULT 50 CHECK (harmony_score >= 0 AND harmony_score <= 100),
tier trust_tier NOT NULL DEFAULT 'new',
posts_today INTEGER NOT NULL DEFAULT 0 CHECK (posts_today >= 0),
last_post_at TIMESTAMPTZ,
last_harmony_calc_at TIMESTAMPTZ,
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE TABLE IF NOT EXISTS categories (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
slug TEXT UNIQUE NOT NULL CHECK (slug ~ '^[a-z0-9_]{2,30}$'),
name TEXT NOT NULL CHECK (length(trim(name)) >= 1 AND length(name) <= 60),
description TEXT CHECK (length(description) <= 200),
is_sensitive BOOLEAN NOT NULL DEFAULT FALSE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE TABLE IF NOT EXISTS posts (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
author_id UUID NOT NULL REFERENCES profiles(id) ON DELETE CASCADE,
category_id UUID NOT NULL REFERENCES categories(id) ON DELETE CASCADE,
body TEXT NOT NULL CHECK (length(trim(body)) >= 1 AND length(body) <= 500),
status post_status NOT NULL DEFAULT 'active',
tone_label tone_label,
cis_score NUMERIC(3,2) CHECK (cis_score >= 0 AND cis_score <= 1),
image_url TEXT,
body_format TEXT DEFAULT 'plain' CHECK (body_format IN ('plain', 'markdown')),
background_id TEXT CHECK (background_id IN ('white', 'grey', 'blue', 'green', 'yellow', 'orange', 'red', 'purple', 'pink')),
tags TEXT[],
is_beacon BOOLEAN NOT NULL DEFAULT FALSE,
beacon_type beacon_type,
location geography(POINT),
confidence_score NUMERIC(3,2) CHECK (confidence_score >= 0 AND confidence_score <= 1),
is_active_beacon BOOLEAN DEFAULT TRUE,
allow_chain BOOLEAN NOT NULL DEFAULT TRUE,
chain_parent_id UUID REFERENCES posts(id) ON DELETE SET NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
edited_at TIMESTAMPTZ,
deleted_at TIMESTAMPTZ
);
CREATE TABLE IF NOT EXISTS post_metrics (
post_id UUID PRIMARY KEY REFERENCES posts(id) ON DELETE CASCADE,
like_count INTEGER NOT NULL DEFAULT 0 CHECK (like_count >= 0),
save_count INTEGER NOT NULL DEFAULT 0 CHECK (save_count >= 0),
view_count INTEGER NOT NULL DEFAULT 0 CHECK (view_count >= 0),
comment_count INTEGER NOT NULL DEFAULT 0 CHECK (comment_count >= 0),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE TABLE IF NOT EXISTS post_likes (
user_id UUID NOT NULL REFERENCES profiles(id) ON DELETE CASCADE,
post_id UUID NOT NULL REFERENCES posts(id) ON DELETE CASCADE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
PRIMARY KEY (user_id, post_id)
);
CREATE TABLE IF NOT EXISTS post_saves (
user_id UUID NOT NULL REFERENCES profiles(id) ON DELETE CASCADE,
post_id UUID NOT NULL REFERENCES posts(id) ON DELETE CASCADE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
PRIMARY KEY (user_id, post_id)
);
CREATE TABLE IF NOT EXISTS comments (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
post_id UUID NOT NULL REFERENCES posts(id) ON DELETE CASCADE,
author_id UUID NOT NULL REFERENCES profiles(id) ON DELETE CASCADE,
body TEXT NOT NULL CHECK (length(trim(body)) >= 1 AND length(body) <= 300),
status post_status NOT NULL DEFAULT 'active',
tone_label tone_label,
deleted_at TIMESTAMPTZ,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE TABLE IF NOT EXISTS beacon_votes (
beacon_id UUID NOT NULL REFERENCES posts(id) ON DELETE CASCADE,
user_id UUID NOT NULL REFERENCES profiles(id) ON DELETE CASCADE,
vote_type TEXT NOT NULL CHECK (vote_type IN ('vouch', 'report')),
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
PRIMARY KEY (beacon_id, user_id)
);
CREATE TABLE IF NOT EXISTS notifications (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
user_id UUID NOT NULL REFERENCES profiles(id) ON DELETE CASCADE,
type notification_type NOT NULL,
actor_id UUID REFERENCES profiles(id) ON DELETE SET NULL,
post_id UUID REFERENCES posts(id) ON DELETE SET NULL,
comment_id UUID REFERENCES comments(id) ON DELETE SET NULL,
metadata JSONB NOT NULL DEFAULT '{}'::jsonb,
is_read BOOLEAN NOT NULL DEFAULT FALSE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE TABLE IF NOT EXISTS follows (
follower_id UUID NOT NULL REFERENCES profiles(id) ON DELETE CASCADE,
following_id UUID NOT NULL REFERENCES profiles(id) ON DELETE CASCADE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
PRIMARY KEY (follower_id, following_id),
CHECK (follower_id != following_id)
);
CREATE TABLE IF NOT EXISTS blocks (
blocker_id UUID NOT NULL REFERENCES profiles(id) ON DELETE CASCADE,
blocked_id UUID NOT NULL REFERENCES profiles(id) ON DELETE CASCADE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
PRIMARY KEY (blocker_id, blocked_id),
CHECK (blocker_id != blocked_id)
);
CREATE TABLE IF NOT EXISTS reports (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
reporter_id UUID NOT NULL REFERENCES profiles(id) ON DELETE CASCADE,
target_type TEXT NOT NULL CHECK (target_type IN ('post', 'comment', 'profile')),
target_id UUID NOT NULL,
reason TEXT NOT NULL CHECK (length(trim(reason)) >= 10 AND length(reason) <= 500),
status TEXT NOT NULL DEFAULT 'pending' CHECK (status IN ('pending', 'reviewing', 'resolved', 'dismissed')),
reviewed_by UUID REFERENCES profiles(id),
reviewed_at TIMESTAMPTZ,
resolution_note TEXT CHECK (length(resolution_note) <= 1000),
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
UNIQUE (reporter_id, target_type, target_id)
);
-- Indexes
CREATE INDEX IF NOT EXISTS idx_profiles_handle ON profiles(handle);
CREATE INDEX IF NOT EXISTS idx_profiles_handle_trgm ON profiles USING GIN (handle gin_trgm_ops);
CREATE INDEX IF NOT EXISTS idx_profiles_beacon_enabled ON profiles(beacon_enabled) WHERE beacon_enabled = TRUE;
CREATE INDEX IF NOT EXISTS idx_posts_tags ON posts USING GIN (tags);
CREATE INDEX IF NOT EXISTS idx_posts_beacon_active ON posts(is_beacon, is_active_beacon) WHERE is_beacon = TRUE AND is_active_beacon = TRUE;
CREATE INDEX IF NOT EXISTS idx_posts_location ON posts USING GIST (location);
-- Functions
CREATE OR REPLACE FUNCTION has_block_between(user_a UUID, user_b UUID)
RETURNS BOOLEAN LANGUAGE plpgsql STABLE SECURITY DEFINER AS $$
BEGIN
IF user_a IS NULL OR user_b IS NULL THEN RETURN FALSE; END IF;
RETURN EXISTS (SELECT 1 FROM blocks WHERE (blocker_id = user_a AND blocked_id = user_b) OR (blocker_id = user_b AND blocked_id = user_a));
END;
$$;
CREATE OR REPLACE FUNCTION is_mutual_follow(user_a UUID, user_b UUID)
RETURNS BOOLEAN LANGUAGE plpgsql STABLE SECURITY DEFINER AS $$
BEGIN
IF user_a IS NULL OR user_b IS NULL THEN RETURN FALSE; END IF;
RETURN EXISTS (SELECT 1 FROM follows WHERE follower_id = user_a AND following_id = user_b)
AND EXISTS (SELECT 1 FROM follows WHERE follower_id = user_b AND following_id = user_a);
END;
$$;
CREATE OR REPLACE FUNCTION get_beacon_status_color(score NUMERIC)
RETURNS TEXT LANGUAGE plpgsql STABLE AS $$
BEGIN
IF score > 0.7 THEN RETURN 'green';
ELSIF score >= 0.3 THEN RETURN 'yellow';
ELSE RETURN 'red'; END IF;
END;
$$;
CREATE OR REPLACE FUNCTION search_sojorn(p_query TEXT, limit_count INTEGER DEFAULT 10)
RETURNS JSON LANGUAGE plpgsql STABLE AS $$
DECLARE result JSON;
BEGIN
SELECT json_build_object(
'users', (SELECT json_agg(json_build_object('id', p.id, 'username', p.handle, 'display_name', p.display_name, 'avatar_url', p.avatar_url, 'harmony_tier', COALESCE(ts.tier, 'new')))
FROM profiles p LEFT JOIN trust_state ts ON p.id = ts.user_id WHERE p.handle ILIKE '%' || p_query || '%' OR p.display_name ILIKE '%' || p_query || '%' LIMIT limit_count),
'tags', (SELECT json_agg(json_build_object('tag', tag, 'count', cnt)) FROM (
SELECT LOWER(UNNEST(tags)) AS tag, COUNT(*) AS cnt FROM posts WHERE tags IS NOT NULL AND deleted_at IS NULL
GROUP BY tag HAVING LOWER(tag) LIKE '%' || LOWER(p_query) || '%' ORDER BY cnt DESC LIMIT limit_count) t),
'posts', (SELECT json_agg(json_build_object('id', post.id, 'body', post.body, 'author_id', post.author_id, 'author_handle', post.handle, 'author_display_name', post.display_name, 'created_at', post.created_at)) FROM (
SELECT po.id, po.body, po.author_id, pr.handle, pr.display_name, po.created_at
FROM posts po
LEFT JOIN profiles pr ON po.author_id = pr.id
WHERE po.deleted_at IS NULL AND po.status = 'active' AND (
po.body ILIKE '%' || p_query || '%' OR
EXISTS (SELECT 1 FROM UNNEST(po.tags) AS tag WHERE LOWER(tag) = LOWER(p_query))
)
ORDER BY po.created_at DESC
LIMIT limit_count
) post)
) INTO result;
RETURN result;
END;
$$;
CREATE OR REPLACE FUNCTION fetch_beacons(lat DOUBLE PRECISION, long DOUBLE PRECISION, radius_meters DOUBLE PRECISION DEFAULT 5000, beacon_type_filter TEXT DEFAULT NULL, limit_count INTEGER DEFAULT 50)
RETURNS TABLE (
id UUID, body TEXT, author_id UUID, beacon_type TEXT, confidence_score NUMERIC, is_active_beacon BOOLEAN, created_at TIMESTAMPTZ,
distance_meters DOUBLE PRECISION, author_handle TEXT, author_display_name TEXT, author_avatar_url TEXT, vouch_count INTEGER, report_count INTEGER, status_color TEXT
) LANGUAGE plpgsql STABLE AS $$
BEGIN
RETURN QUERY
SELECT p.id, p.body, p.author_id, p.beacon_type::TEXT, p.confidence_score, p.is_active_beacon, p.created_at,
ST_Distance(p.location, ST_SetSRID(ST_MakePoint(long, lat), 4326)::geography) AS distance_meters,
p.handle AS author_handle, p.display_name AS author_display_name, p.avatar_url AS author_avatar_url,
COALESCE(vouch.cnt, 0)::INT, COALESCE(report.cnt, 0)::INT, get_beacon_status_color(p.confidence_score)
FROM posts p
LEFT JOIN (SELECT beacon_id, COUNT(*)::INT AS cnt FROM beacon_votes WHERE vote_type = 'vouch' GROUP BY beacon_id) vouch ON p.id = vouch.beacon_id
LEFT JOIN (SELECT beacon_id, COUNT(*)::INT AS cnt FROM beacon_votes WHERE vote_type = 'report' GROUP BY beacon_id) report ON p.id = report.beacon_id
WHERE p.is_beacon = TRUE AND p.is_active_beacon = TRUE AND p.deleted_at IS NULL
AND (beacon_type_filter IS NULL OR p.beacon_type::TEXT = beacon_type_filter)
AND ST_DWithin(p.location, ST_SetSRID(ST_MakePoint(long, lat), 4326)::geography, radius_meters)
ORDER BY p.confidence_score DESC, p.created_at DESC LIMIT limit_count;
END;
$$;
CREATE OR REPLACE FUNCTION handle_new_user()
RETURNS TRIGGER LANGUAGE plpgsql SECURITY DEFINER AS $$
BEGIN
INSERT INTO public.profiles (id, handle, display_name)
VALUES (NEW.id, COALESCE(NEW.raw_user_meta_data->>'handle', NEW.email), COALESCE(NEW.raw_user_meta_data->>'display_name', NEW.email));
INSERT INTO public.trust_state (user_id, harmony_score, tier, posts_today) VALUES (NEW.id, 50, 'new', 0);
RETURN NEW;
END;
$$;
CREATE OR REPLACE FUNCTION init_post_metrics()
RETURNS TRIGGER LANGUAGE plpgsql AS $$
BEGIN INSERT INTO post_metrics (post_id) VALUES (NEW.id); RETURN NEW; END;
$$;
CREATE OR REPLACE FUNCTION update_post_like_count()
RETURNS TRIGGER LANGUAGE plpgsql AS $$
BEGIN
IF TG_OP = 'INSERT' THEN UPDATE post_metrics SET like_count = like_count + 1, updated_at = NOW() WHERE post_id = NEW.post_id;
ELSIF TG_OP = 'DELETE' THEN UPDATE post_metrics SET like_count = like_count - 1, updated_at = NOW() WHERE post_id = OLD.post_id; END IF;
RETURN NULL;
END;
$$;
CREATE OR REPLACE FUNCTION update_post_save_count()
RETURNS TRIGGER LANGUAGE plpgsql AS $$
BEGIN
IF TG_OP = 'INSERT' THEN UPDATE post_metrics SET save_count = save_count + 1, updated_at = NOW() WHERE post_id = NEW.post_id;
ELSIF TG_OP = 'DELETE' THEN UPDATE post_metrics SET save_count = save_count - 1, updated_at = NOW() WHERE post_id = OLD.post_id; END IF;
RETURN NULL;
END;
$$;
CREATE OR REPLACE FUNCTION update_post_comment_count()
RETURNS TRIGGER LANGUAGE plpgsql AS $$
BEGIN
IF TG_OP = 'INSERT' THEN UPDATE post_metrics SET comment_count = comment_count + 1, updated_at = NOW() WHERE post_id = NEW.post_id;
ELSIF TG_OP = 'DELETE' THEN UPDATE post_metrics SET comment_count = comment_count - 1, updated_at = NOW() WHERE post_id = OLD.post_id; END IF;
RETURN NULL;
END;
$$;
CREATE OR REPLACE FUNCTION update_beacon_score_on_vouch()
RETURNS TRIGGER LANGUAGE plpgsql AS $$
DECLARE voucher_trust INTEGER;
BEGIN
IF NEW.vote_type = 'vouch' THEN
SELECT COALESCE(ts.harmony_score, 50) INTO voucher_trust FROM trust_state ts WHERE ts.user_id = NEW.user_id;
UPDATE posts SET confidence_score = LEAST(1.0, confidence_score + (voucher_trust::NUMERIC / 1000)) WHERE id = NEW.beacon_id;
END IF;
RETURN NEW;
END;
$$;
CREATE OR REPLACE FUNCTION prune_inactive_beacons()
RETURNS INTEGER LANGUAGE plpgsql AS $$
DECLARE disabled_count INTEGER;
BEGIN
UPDATE posts SET is_active_beacon = FALSE WHERE is_beacon = TRUE AND is_active_beacon = TRUE
AND confidence_score < 0.3 AND created_at < NOW() - INTERVAL '10 minutes' AND deleted_at IS NULL;
GET DIAGNOSTICS disabled_count = ROW_COUNT;
RETURN disabled_count;
END;
$$;
-- Triggers
CREATE TRIGGER handle_new_user AFTER INSERT ON auth.users FOR EACH ROW EXECUTE FUNCTION handle_new_user();
CREATE TRIGGER init_metrics_on_post AFTER INSERT ON posts FOR EACH ROW EXECUTE FUNCTION init_post_metrics();
CREATE TRIGGER update_like_count AFTER INSERT OR DELETE ON post_likes FOR EACH ROW EXECUTE FUNCTION update_post_like_count();
CREATE TRIGGER update_save_count AFTER INSERT OR DELETE ON post_saves FOR EACH ROW EXECUTE FUNCTION update_post_save_count();
CREATE TRIGGER update_comment_count AFTER INSERT OR DELETE ON comments FOR EACH ROW EXECUTE FUNCTION update_post_comment_count();
CREATE TRIGGER update_beacon_score AFTER INSERT ON beacon_votes FOR EACH ROW EXECUTE FUNCTION update_beacon_score_on_vouch();
-- RLS
ALTER TABLE profiles ENABLE ROW LEVEL SECURITY;
ALTER TABLE trust_state ENABLE ROW LEVEL SECURITY;
ALTER TABLE categories ENABLE ROW LEVEL SECURITY;
ALTER TABLE posts ENABLE ROW LEVEL SECURITY;
ALTER TABLE post_metrics ENABLE ROW LEVEL SECURITY;
ALTER TABLE post_likes ENABLE ROW LEVEL SECURITY;
ALTER TABLE post_saves ENABLE ROW LEVEL SECURITY;
ALTER TABLE comments ENABLE ROW LEVEL SECURITY;
ALTER TABLE beacon_votes ENABLE ROW LEVEL SECURITY;
ALTER TABLE notifications ENABLE ROW LEVEL SECURITY;
ALTER TABLE follows ENABLE ROW LEVEL SECURITY;
ALTER TABLE blocks ENABLE ROW LEVEL SECURITY;
ALTER TABLE reports ENABLE ROW LEVEL SECURITY;
CREATE POLICY "Public profiles" ON profiles FOR SELECT USING (true);
CREATE POLICY "Own profile" ON profiles FOR UPDATE USING (auth.uid() = id);
CREATE POLICY "Own trust state" ON trust_state FOR SELECT USING (auth.uid() = user_id);
CREATE POLICY "Categories are public" ON categories FOR SELECT USING (true);
CREATE POLICY "Anyone can insert categories" ON categories FOR INSERT WITH CHECK (true);
CREATE POLICY "Public posts" ON posts FOR SELECT USING (deleted_at IS NULL AND status = 'active');
CREATE POLICY "Create posts" ON posts FOR INSERT WITH CHECK (auth.uid() = author_id);
CREATE POLICY "Own posts" ON posts FOR UPDATE USING (auth.uid() = author_id AND deleted_at IS NULL);
CREATE POLICY "Metrics" ON post_metrics FOR SELECT USING (true);
CREATE POLICY "Likes" ON post_likes FOR ALL USING (auth.uid() = user_id);
CREATE POLICY "Saves" ON post_saves FOR ALL USING (auth.uid() = user_id);
CREATE POLICY "Comments" ON comments FOR SELECT USING (deleted_at IS NULL AND status = 'active');
CREATE POLICY "Create comments" ON comments FOR INSERT WITH CHECK (auth.uid() = author_id);
CREATE POLICY "Own comments" ON comments FOR UPDATE USING (auth.uid() = author_id AND deleted_at IS NULL);
CREATE POLICY "Beacon votes" ON beacon_votes FOR ALL USING (auth.uid() = user_id);
CREATE POLICY "Notifications" ON notifications FOR SELECT USING (auth.uid() = user_id);
CREATE POLICY "Follows" ON follows FOR SELECT USING (true);
CREATE POLICY "Manage follows" ON follows FOR ALL USING (auth.uid() = follower_id);
CREATE POLICY "Blocks" ON blocks FOR SELECT USING (auth.uid() = blocker_id);
CREATE POLICY "Manage blocks" ON blocks FOR ALL USING (auth.uid() = blocker_id);
CREATE POLICY "Reports" ON reports FOR SELECT USING (auth.uid() = reporter_id);
-- Seed Data
INSERT INTO categories (slug, name, description, is_sensitive) VALUES
('general', 'General', 'General discussion', false),
('news', 'News', 'News and current events', false),
('help', 'Help', 'Ask for help', false),
('events', 'Events', 'Community events', false),
('beacon-alerts', 'Beacon Alerts', 'Community safety alerts', false)
ON CONFLICT (slug) DO NOTHING;