sojorn/go-backend/internal/database/schema.sql
2026-02-15 00:33:24 -06:00

148 lines
5 KiB
SQL

-- Sojorn Go Backend Initial Schema
-- Extensions
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
-- Users (Auth)
CREATE TABLE IF NOT EXISTS public.users (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
email TEXT UNIQUE NOT NULL,
encrypted_password TEXT NOT NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
deleted_at TIMESTAMPTZ
);
-- Profiles
CREATE TABLE IF NOT EXISTS public.profiles (
id UUID PRIMARY KEY REFERENCES public.users(id) ON DELETE CASCADE,
handle TEXT UNIQUE NOT NULL,
display_name TEXT NOT NULL,
bio TEXT,
avatar_url TEXT,
cover_url TEXT,
is_official BOOLEAN DEFAULT FALSE,
beacon_enabled BOOLEAN DEFAULT FALSE,
location TEXT,
website TEXT,
interests TEXT[],
origin_country TEXT,
strikes INTEGER DEFAULT 0,
identity_key TEXT,
encrypted_private_key TEXT,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- Categories
CREATE TABLE IF NOT EXISTS public.categories (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
name TEXT NOT NULL,
slug TEXT UNIQUE NOT NULL,
description TEXT,
icon_url TEXT,
is_active BOOLEAN DEFAULT TRUE,
is_sensitive BOOLEAN DEFAULT FALSE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- Posts
CREATE TABLE IF NOT EXISTS public.posts (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
author_id UUID NOT NULL REFERENCES public.profiles(id) ON DELETE CASCADE,
category_id UUID REFERENCES public.categories(id) ON DELETE SET NULL,
body TEXT NOT NULL,
image_url TEXT,
tags TEXT[],
status TEXT DEFAULT 'active', -- active, flagged, removed
visibility TEXT DEFAULT 'public', -- public, private, circle
content_integrity_score DOUBLE PRECISION DEFAULT 1.0,
detected_tone TEXT DEFAULT 'neutral',
latitude DOUBLE PRECISION,
longitude DOUBLE PRECISION,
is_beacon BOOLEAN DEFAULT FALSE,
beacon_type TEXT,
confidence_score DOUBLE PRECISION,
is_active_beacon BOOLEAN DEFAULT FALSE,
pinned_at TIMESTAMPTZ,
expires_at TIMESTAMPTZ,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
edited_at TIMESTAMPTZ,
deleted_at TIMESTAMPTZ
);
-- Post Metrics
CREATE TABLE IF NOT EXISTS public.post_metrics (
post_id UUID PRIMARY KEY REFERENCES public.posts(id) ON DELETE CASCADE,
like_count INTEGER DEFAULT 0,
save_count INTEGER DEFAULT 0,
comment_count INTEGER DEFAULT 0,
view_count INTEGER DEFAULT 0,
updated_at TIMESTAMPTZ DEFAULT NOW()
);
-- Social Interactions
CREATE TABLE IF NOT EXISTS public.post_likes (
post_id UUID REFERENCES public.posts(id) ON DELETE CASCADE,
user_id UUID REFERENCES public.profiles(id) ON DELETE CASCADE,
created_at TIMESTAMPTZ DEFAULT NOW(),
PRIMARY KEY (post_id, user_id)
);
CREATE TABLE IF NOT EXISTS public.post_saves (
post_id UUID REFERENCES public.posts(id) ON DELETE CASCADE,
user_id UUID REFERENCES public.profiles(id) ON DELETE CASCADE,
created_at TIMESTAMPTZ DEFAULT NOW(),
PRIMARY KEY (post_id, user_id)
);
CREATE TABLE IF NOT EXISTS public.post_reactions (
post_id UUID REFERENCES public.posts(id) ON DELETE CASCADE,
user_id UUID REFERENCES public.profiles(id) ON DELETE CASCADE,
emoji TEXT NOT NULL,
created_at TIMESTAMPTZ DEFAULT NOW(),
PRIMARY KEY (post_id, user_id, emoji)
);
CREATE INDEX IF NOT EXISTS idx_post_reactions_post_id ON public.post_reactions(post_id);
CREATE TABLE IF NOT EXISTS public.follows (
follower_id UUID REFERENCES public.profiles(id) ON DELETE CASCADE,
following_id UUID REFERENCES public.profiles(id) ON DELETE CASCADE,
created_at TIMESTAMPTZ DEFAULT NOW(),
PRIMARY KEY (follower_id, following_id)
);
-- Trust State
CREATE TABLE IF NOT EXISTS public.trust_state (
user_id UUID PRIMARY KEY REFERENCES public.profiles(id) ON DELETE CASCADE,
harmony_score INTEGER DEFAULT 50,
tier TEXT DEFAULT 'new', -- new, trusted, established
posts_today INTEGER DEFAULT 0,
last_post_at TIMESTAMPTZ,
last_harmony_calc_at TIMESTAMPTZ,
updated_at TIMESTAMPTZ DEFAULT NOW()
);
-- Interests / Category Settings
CREATE TABLE IF NOT EXISTS public.user_category_settings (
user_id UUID REFERENCES public.profiles(id) ON DELETE CASCADE,
category_id UUID REFERENCES public.categories(id) ON DELETE CASCADE,
enabled BOOLEAN DEFAULT TRUE,
updated_at TIMESTAMPTZ DEFAULT NOW(),
PRIMARY KEY (user_id, category_id)
);
-- Basic Triggers/Indexes
CREATE INDEX IF NOT EXISTS idx_posts_author_id ON public.posts(author_id);
CREATE INDEX IF NOT EXISTS idx_posts_created_at ON public.posts(created_at DESC);
CREATE INDEX IF NOT EXISTS idx_profiles_handle ON public.profiles(handle);
-- Default categories
INSERT INTO public.categories (name, slug, description) VALUES
('General', 'general', 'General discussions'),
('Politics', 'politics', 'Political news and debates'),
('Tech', 'tech', 'Technology and software'),
('Art', 'art', 'Creative works and inspiration')
ON CONFLICT (slug) DO NOTHING;