-- 000001_initial_schema.up.sql -- EXTENSIONS CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; CREATE EXTENSION IF NOT EXISTS "pg_trgm"; CREATE EXTENSION IF NOT EXISTS "postgis"; -- TYPES DO $$ BEGIN CREATE TYPE beacon_type AS ENUM ('police', 'checkpoint', 'taskForce', 'hazard', 'safety', 'community'); CREATE TYPE trust_tier AS ENUM ('new', 'trusted', 'established'); CREATE TYPE notification_type AS ENUM ('appreciate', 'chain', 'follow', 'comment', 'mention', 'follow_request', 'new_follower', 'request_accepted'); CREATE TYPE tone_label AS ENUM ('positive', 'neutral', 'mixed', 'negative', 'hostile'); CREATE TYPE post_status AS ENUM ('active', 'flagged', 'removed'); EXCEPTION WHEN duplicate_object THEN null; END $$; -- AUTH SCHEMA (Full Parity) CREATE SCHEMA IF NOT EXISTS auth; CREATE TABLE IF NOT EXISTS auth.users ( instance_id UUID, id UUID PRIMARY KEY, aud TEXT, role TEXT, email TEXT, encrypted_password TEXT, email_confirmed_at TIMESTAMPTZ, invited_at TIMESTAMPTZ, confirmation_token TEXT, confirmation_sent_at TIMESTAMPTZ, recovery_token TEXT, recovery_sent_at TIMESTAMPTZ, email_change_token_new TEXT, email_change TEXT, email_change_sent_at TIMESTAMPTZ, last_sign_in_at TIMESTAMPTZ, raw_app_meta_data JSONB, raw_user_meta_data JSONB, is_super_admin BOOLEAN, created_at TIMESTAMPTZ, updated_at TIMESTAMPTZ, phone TEXT DEFAULT NULL, phone_confirmed_at TIMESTAMPTZ DEFAULT NULL, phone_change TEXT DEFAULT NULL, phone_change_sent_at TIMESTAMPTZ DEFAULT NULL, phone_change_token TEXT DEFAULT NULL, email_change_token_current TEXT DEFAULT NULL, email_change_confirm_status SMALLINT DEFAULT 0, banned_until TIMESTAMPTZ DEFAULT NULL, reauthentication_token TEXT DEFAULT NULL, reauthentication_sent_at TIMESTAMPTZ DEFAULT NULL, is_sso_user BOOLEAN DEFAULT FALSE, deleted_at TIMESTAMPTZ DEFAULT NULL, is_anonymous BOOLEAN DEFAULT FALSE ); -- SUPABASE FUNCTIONS (Compatibility) CREATE SCHEMA IF NOT EXISTS supabase_functions; CREATE TABLE IF NOT EXISTS supabase_functions.hooks ( id BIGSERIAL PRIMARY KEY, hook_table_id INTEGER, hook_name TEXT, created_at TIMESTAMPTZ, request_id TEXT ); -- CORE TABLES CREATE TABLE IF NOT EXISTS users ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), email TEXT UNIQUE NOT NULL, password_hash TEXT, supabase_id UUID UNIQUE, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), deleted_at TIMESTAMPTZ, is_anonymous BOOLEAN DEFAULT FALSE ); CREATE TABLE IF NOT EXISTS profiles ( id UUID PRIMARY KEY REFERENCES auth.users(id) ON DELETE CASCADE, handle TEXT UNIQUE NOT NULL, display_name TEXT NOT NULL, bio TEXT, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), is_official BOOLEAN DEFAULT FALSE, location TEXT, website TEXT, interests TEXT[], avatar_url TEXT, cover_url TEXT, account_status TEXT DEFAULT 'active', deactivated_at TIMESTAMPTZ, deletion_requested_at TIMESTAMPTZ, last_handle_change_at TIMESTAMPTZ, beacon_enabled BOOLEAN NOT NULL DEFAULT FALSE, strikes INTEGER NOT NULL DEFAULT 0, role TEXT NOT NULL DEFAULT 'user', origin_country TEXT, is_private BOOLEAN NOT NULL DEFAULT FALSE, identity_key TEXT, registration_id INTEGER, encrypted_private_key TEXT ); CREATE TABLE IF NOT EXISTS categories ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), slug TEXT UNIQUE NOT NULL, name TEXT NOT NULL, description TEXT, is_sensitive BOOLEAN NOT NULL DEFAULT FALSE, default_off BOOLEAN NOT NULL DEFAULT FALSE, created_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, tier TEXT NOT NULL DEFAULT 'new', counters JSONB NOT NULL DEFAULT '{}'::jsonb, last_post_at TIMESTAMPTZ, posts_today INTEGER NOT NULL DEFAULT 0, updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), tier_changed_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 REFERENCES categories(id) ON DELETE SET NULL, body TEXT NOT NULL, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), tone_label TEXT, cis_score NUMERIC, status TEXT NOT NULL DEFAULT 'active', edited_at TIMESTAMPTZ, deleted_at TIMESTAMPTZ, allow_chain BOOLEAN NOT NULL DEFAULT TRUE, chain_parent_id UUID REFERENCES posts(id) ON DELETE SET NULL, image_url TEXT, body_format TEXT, background_id TEXT, is_edited BOOLEAN NOT NULL DEFAULT FALSE, tags TEXT[], location geography(POINT), is_beacon BOOLEAN DEFAULT FALSE, beacon_type TEXT, confidence_score DOUBLE PRECISION, is_active_beacon BOOLEAN DEFAULT TRUE, fts TSVECTOR, expires_at TIMESTAMPTZ, moderation_status TEXT NOT NULL DEFAULT 'approved', visibility TEXT NOT NULL DEFAULT 'authenticated', pinned_at TIMESTAMPTZ, type TEXT NOT NULL DEFAULT 'post', video_url TEXT, thumbnail_url TEXT, duration_ms INTEGER ); 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, save_count INTEGER NOT NULL DEFAULT 0, view_count INTEGER NOT NULL DEFAULT 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, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), tone_label TEXT, status TEXT NOT NULL DEFAULT 'active', deleted_at TIMESTAMPTZ ); CREATE TABLE IF NOT EXISTS beacon_votes ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), 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, 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(), status TEXT NOT NULL DEFAULT 'accepted', PRIMARY KEY (follower_id, following_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 TEXT NOT NULL, actor_id UUID NOT NULL REFERENCES profiles(id) ON DELETE CASCADE, post_id UUID REFERENCES posts(id) ON DELETE SET NULL, comment_id UUID REFERENCES comments(id) ON DELETE SET NULL, is_read BOOLEAN NOT NULL DEFAULT FALSE, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), metadata JSONB NOT NULL DEFAULT '{}'::jsonb, archived_at TIMESTAMPTZ ); CREATE TABLE IF NOT EXISTS user_fcm_tokens ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES profiles(id) ON DELETE CASCADE, token TEXT NOT NULL, device_type TEXT, last_updated TIMESTAMPTZ DEFAULT NOW(), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE(user_id, token) ); CREATE TABLE IF NOT EXISTS profile_privacy_settings ( user_id UUID PRIMARY KEY REFERENCES profiles(id) ON DELETE CASCADE, show_location BOOLEAN DEFAULT TRUE, show_interests BOOLEAN DEFAULT TRUE, profile_visibility TEXT DEFAULT 'public', posts_visibility TEXT DEFAULT 'public', saved_visibility TEXT DEFAULT 'public', follow_request_policy TEXT DEFAULT 'anyone', created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE TABLE IF NOT EXISTS sponsored_posts ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), post_id UUID NOT NULL REFERENCES posts(id) ON DELETE CASCADE, advertiser_name TEXT, -- Added created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- INDEXES CREATE INDEX IF NOT EXISTS idx_profiles_handle ON profiles(handle); CREATE INDEX IF NOT EXISTS idx_posts_author ON posts(author_id); CREATE INDEX IF NOT EXISTS idx_posts_category ON posts(category_id); CREATE INDEX IF NOT EXISTS idx_posts_location ON posts USING GIST (location);