database schema adjustments to server/realm/scene

This commit is contained in:
Evan Carroll 2026-01-16 10:57:47 -06:00
parent a102c96bb4
commit 09590edd95
79 changed files with 7100 additions and 100 deletions

149
db/schema/000_init.sql Normal file
View file

@ -0,0 +1,149 @@
-- Chattyness Database Schema Initialization
-- PostgreSQL 18
--
-- This file drops all existing schema and recreates from scratch.
-- Load via: psql -d chattyness -f schema/000_init.sql
--
-- WARNING: This destroys all data!
\set ON_ERROR_STOP on
BEGIN;
-- =============================================================================
-- Drop Everything (CASCADE removes all dependent objects)
-- =============================================================================
DROP SCHEMA IF EXISTS audit CASCADE;
DROP SCHEMA IF EXISTS chat CASCADE;
DROP SCHEMA IF EXISTS scene CASCADE;
DROP SCHEMA IF EXISTS realm CASCADE;
DROP SCHEMA IF EXISTS auth CASCADE;
DROP SCHEMA IF EXISTS server CASCADE;
-- Drop public domains we create (not removed by schema drops)
DROP DOMAIN IF EXISTS public.scene_bounds CASCADE;
DROP DOMAIN IF EXISTS public.virtual_point CASCADE;
DROP DOMAIN IF EXISTS public.asset_path CASCADE;
DROP DOMAIN IF EXISTS public.url CASCADE;
DROP DOMAIN IF EXISTS public.hex_color CASCADE;
DROP DOMAIN IF EXISTS public.slug CASCADE;
DROP DOMAIN IF EXISTS public.display_name CASCADE;
DROP DOMAIN IF EXISTS public.nonempty_text CASCADE;
DROP DOMAIN IF EXISTS public.percentage CASCADE;
-- Drop all objects owned by application roles (required to avoid dependency errors)
DO $$
BEGIN
-- Drop objects owned by chattyness_owner
IF EXISTS (SELECT 1 FROM pg_roles WHERE rolname = 'chattyness_owner') THEN
DROP OWNED BY chattyness_owner CASCADE;
END IF;
-- Drop objects owned by chattyness_app
IF EXISTS (SELECT 1 FROM pg_roles WHERE rolname = 'chattyness_app') THEN
DROP OWNED BY chattyness_app CASCADE;
END IF;
END $$;
-- Drop all application roles
DROP ROLE IF EXISTS chattyness_app;
DROP ROLE IF EXISTS chattyness_owner;
-- =============================================================================
-- Extensions
-- =============================================================================
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
CREATE EXTENSION IF NOT EXISTS "pgcrypto";
CREATE EXTENSION IF NOT EXISTS "btree_gist";
CREATE EXTENSION IF NOT EXISTS "pg_trgm";
CREATE EXTENSION IF NOT EXISTS "postgis";
-- =============================================================================
-- Schemas
-- =============================================================================
CREATE SCHEMA server;
COMMENT ON SCHEMA server IS 'Server-wide configuration, global props, shared resources, and server-level moderation';
CREATE SCHEMA auth;
COMMENT ON SCHEMA auth IS 'User authentication, accounts, identity management, inventory, and avatars';
CREATE SCHEMA realm;
COMMENT ON SCHEMA realm IS 'Realms, scenes, memberships, realm props, and realm-level moderation';
CREATE SCHEMA scene;
COMMENT ON SCHEMA scene IS 'Scene instances, members, spots, loose props, and decorations';
CREATE SCHEMA chat;
COMMENT ON SCHEMA chat IS 'Messages, whispers, shouts, and reactions';
CREATE SCHEMA audit;
COMMENT ON SCHEMA audit IS 'Audit trails and activity logging';
-- =============================================================================
-- Application Roles
-- =============================================================================
-- Application login role for normal operations (subject to RLS)
-- Password is set in load.sql
CREATE ROLE chattyness_app LOGIN;
COMMENT ON ROLE chattyness_app IS 'Application login role - subject to RLS, user context passed via session variables';
-- Owner role with full access (bypasses RLS)
-- Password is set in load.sql
CREATE ROLE chattyness_owner LOGIN BYPASSRLS;
COMMENT ON ROLE chattyness_owner IS 'Owner role - bypasses RLS for server management';
-- =============================================================================
-- Grant Full Access to Owner Role
-- =============================================================================
-- Grant usage on all schemas
GRANT USAGE ON SCHEMA public TO chattyness_owner;
GRANT USAGE ON SCHEMA server TO chattyness_owner;
GRANT USAGE ON SCHEMA auth TO chattyness_owner;
GRANT USAGE ON SCHEMA realm TO chattyness_owner;
GRANT USAGE ON SCHEMA scene TO chattyness_owner;
GRANT USAGE ON SCHEMA chat TO chattyness_owner;
GRANT USAGE ON SCHEMA audit TO chattyness_owner;
-- Grant all privileges on all tables in each schema
-- These will apply to tables created later in the load sequence
ALTER DEFAULT PRIVILEGES IN SCHEMA public GRANT ALL ON TABLES TO chattyness_owner;
ALTER DEFAULT PRIVILEGES IN SCHEMA server GRANT ALL ON TABLES TO chattyness_owner;
ALTER DEFAULT PRIVILEGES IN SCHEMA auth GRANT ALL ON TABLES TO chattyness_owner;
ALTER DEFAULT PRIVILEGES IN SCHEMA realm GRANT ALL ON TABLES TO chattyness_owner;
ALTER DEFAULT PRIVILEGES IN SCHEMA scene GRANT ALL ON TABLES TO chattyness_owner;
ALTER DEFAULT PRIVILEGES IN SCHEMA chat GRANT ALL ON TABLES TO chattyness_owner;
ALTER DEFAULT PRIVILEGES IN SCHEMA audit GRANT ALL ON TABLES TO chattyness_owner;
-- Grant all privileges on sequences (for identity columns)
ALTER DEFAULT PRIVILEGES IN SCHEMA public GRANT ALL ON SEQUENCES TO chattyness_owner;
ALTER DEFAULT PRIVILEGES IN SCHEMA server GRANT ALL ON SEQUENCES TO chattyness_owner;
ALTER DEFAULT PRIVILEGES IN SCHEMA auth GRANT ALL ON SEQUENCES TO chattyness_owner;
ALTER DEFAULT PRIVILEGES IN SCHEMA realm GRANT ALL ON SEQUENCES TO chattyness_owner;
ALTER DEFAULT PRIVILEGES IN SCHEMA scene GRANT ALL ON SEQUENCES TO chattyness_owner;
ALTER DEFAULT PRIVILEGES IN SCHEMA chat GRANT ALL ON SEQUENCES TO chattyness_owner;
ALTER DEFAULT PRIVILEGES IN SCHEMA audit GRANT ALL ON SEQUENCES TO chattyness_owner;
-- Grant execute on all functions
ALTER DEFAULT PRIVILEGES IN SCHEMA public GRANT EXECUTE ON FUNCTIONS TO chattyness_owner;
ALTER DEFAULT PRIVILEGES IN SCHEMA server GRANT EXECUTE ON FUNCTIONS TO chattyness_owner;
ALTER DEFAULT PRIVILEGES IN SCHEMA auth GRANT EXECUTE ON FUNCTIONS TO chattyness_owner;
ALTER DEFAULT PRIVILEGES IN SCHEMA realm GRANT EXECUTE ON FUNCTIONS TO chattyness_owner;
ALTER DEFAULT PRIVILEGES IN SCHEMA scene GRANT EXECUTE ON FUNCTIONS TO chattyness_owner;
ALTER DEFAULT PRIVILEGES IN SCHEMA chat GRANT EXECUTE ON FUNCTIONS TO chattyness_owner;
ALTER DEFAULT PRIVILEGES IN SCHEMA audit GRANT EXECUTE ON FUNCTIONS TO chattyness_owner;
-- =============================================================================
-- Schema Search Path
-- =============================================================================
DO $$
BEGIN
EXECUTE format('ALTER DATABASE %I SET search_path TO public, server, auth, realm, scene, chat, audit', current_database());
END
$$;
COMMIT;

View file

@ -0,0 +1,280 @@
-- Chattyness Helper Functions
-- PostgreSQL 18
--
-- Utility functions and common operations
-- Load via: psql -f schema/functions/001_helpers.sql
\set ON_ERROR_STOP on
BEGIN;
-- =============================================================================
-- Updated At Trigger Function
-- =============================================================================
-- Automatically updates updated_at column on row modification.
-- =============================================================================
CREATE OR REPLACE FUNCTION public.update_updated_at_column()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = now();
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
COMMENT ON FUNCTION public.update_updated_at_column() IS
'Trigger function to automatically update updated_at timestamp';
-- =============================================================================
-- Session Context Functions
-- =============================================================================
-- Functions to get/set session context for RLS policies.
-- Application sets these variables when handling requests.
-- =============================================================================
-- Set current user ID for RLS
CREATE OR REPLACE FUNCTION public.set_current_user_id(user_id UUID)
RETURNS VOID AS $$
BEGIN
PERFORM set_config('app.current_user_id', user_id::TEXT, false);
END;
$$ LANGUAGE plpgsql;
-- Get current user ID for RLS
CREATE OR REPLACE FUNCTION public.current_user_id()
RETURNS UUID AS $$
BEGIN
RETURN NULLIF(current_setting('app.current_user_id', true), '')::UUID;
EXCEPTION
WHEN OTHERS THEN RETURN NULL;
END;
$$ LANGUAGE plpgsql STABLE;
-- Set current realm ID for RLS
CREATE OR REPLACE FUNCTION public.set_current_realm_id(realm_id UUID)
RETURNS VOID AS $$
BEGIN
PERFORM set_config('app.current_realm_id', realm_id::TEXT, false);
END;
$$ LANGUAGE plpgsql;
-- Get current realm ID for RLS
CREATE OR REPLACE FUNCTION public.current_realm_id()
RETURNS UUID AS $$
BEGIN
RETURN NULLIF(current_setting('app.current_realm_id', true), '')::UUID;
EXCEPTION
WHEN OTHERS THEN RETURN NULL;
END;
$$ LANGUAGE plpgsql STABLE;
-- Set current guest session ID for RLS
CREATE OR REPLACE FUNCTION public.set_current_guest_session_id(guest_session_id UUID)
RETURNS VOID AS $$
BEGIN
PERFORM set_config('app.current_guest_session_id', guest_session_id::TEXT, false);
END;
$$ LANGUAGE plpgsql;
-- Get current guest session ID for RLS
CREATE OR REPLACE FUNCTION public.current_guest_session_id()
RETURNS UUID AS $$
BEGIN
RETURN NULLIF(current_setting('app.current_guest_session_id', true), '')::UUID;
EXCEPTION
WHEN OTHERS THEN RETURN NULL;
END;
$$ LANGUAGE plpgsql STABLE;
-- Check if current user is a server admin
CREATE OR REPLACE FUNCTION public.is_server_admin()
RETURNS BOOLEAN AS $$
BEGIN
RETURN EXISTS (
SELECT 1 FROM server.staff
WHERE user_id = public.current_user_id()
AND role IN ('owner', 'admin')
);
EXCEPTION
WHEN OTHERS THEN RETURN FALSE;
END;
$$ LANGUAGE plpgsql STABLE SECURITY DEFINER;
-- Check if current user is a server moderator (or higher)
CREATE OR REPLACE FUNCTION public.is_server_moderator()
RETURNS BOOLEAN AS $$
BEGIN
RETURN EXISTS (
SELECT 1 FROM server.staff
WHERE user_id = public.current_user_id()
AND role IN ('owner', 'admin', 'moderator')
);
EXCEPTION
WHEN OTHERS THEN RETURN FALSE;
END;
$$ LANGUAGE plpgsql STABLE SECURITY DEFINER;
-- Check if current user is a realm owner/moderator
CREATE OR REPLACE FUNCTION public.is_realm_moderator(check_realm_id UUID)
RETURNS BOOLEAN AS $$
BEGIN
-- Server admins are moderators everywhere
IF public.is_server_admin() THEN
RETURN TRUE;
END IF;
RETURN EXISTS (
SELECT 1 FROM realm.memberships
WHERE realm_id = check_realm_id
AND user_id = public.current_user_id()
AND role IN ('owner', 'moderator')
);
EXCEPTION
WHEN OTHERS THEN RETURN FALSE;
END;
$$ LANGUAGE plpgsql STABLE SECURITY DEFINER;
-- Check if current user has membership in a realm
CREATE OR REPLACE FUNCTION public.has_realm_membership(check_realm_id UUID)
RETURNS BOOLEAN AS $$
BEGIN
RETURN EXISTS (
SELECT 1 FROM realm.memberships
WHERE realm_id = check_realm_id
AND user_id = public.current_user_id()
);
EXCEPTION
WHEN OTHERS THEN RETURN FALSE;
END;
$$ LANGUAGE plpgsql STABLE SECURITY DEFINER;
-- =============================================================================
-- Friendship Helper Functions
-- =============================================================================
-- Check if two users are friends
CREATE OR REPLACE FUNCTION auth.are_friends(user_a UUID, user_b UUID)
RETURNS BOOLEAN AS $$
BEGIN
RETURN EXISTS (
SELECT 1 FROM auth.friendships
WHERE friend_a = LEAST(user_a, user_b)
AND friend_b = GREATEST(user_a, user_b)
AND is_accepted = true
);
END;
$$ LANGUAGE plpgsql STABLE;
-- Check if user_a has blocked user_b
CREATE OR REPLACE FUNCTION auth.has_blocked(blocker UUID, blocked UUID)
RETURNS BOOLEAN AS $$
BEGIN
RETURN EXISTS (
SELECT 1 FROM auth.blocks
WHERE blocker_id = blocker
AND blocked_id = blocked
);
END;
$$ LANGUAGE plpgsql STABLE;
-- Check if either user has blocked the other
CREATE OR REPLACE FUNCTION auth.is_blocked_either_way(user_a UUID, user_b UUID)
RETURNS BOOLEAN AS $$
BEGIN
RETURN EXISTS (
SELECT 1 FROM auth.blocks
WHERE (blocker_id = user_a AND blocked_id = user_b)
OR (blocker_id = user_b AND blocked_id = user_a)
);
END;
$$ LANGUAGE plpgsql STABLE;
-- =============================================================================
-- Spatial Helper Functions
-- =============================================================================
-- Create a virtual point from x,y coordinates
CREATE OR REPLACE FUNCTION public.make_virtual_point(x REAL, y REAL)
RETURNS public.virtual_point AS $$
BEGIN
RETURN ST_SetSRID(ST_MakePoint(x, y), 0)::public.virtual_point;
END;
$$ LANGUAGE plpgsql IMMUTABLE;
-- Create scene bounds from width and height (origin at 0,0)
CREATE OR REPLACE FUNCTION public.make_scene_bounds(width REAL, height REAL)
RETURNS public.scene_bounds AS $$
BEGIN
RETURN ST_MakeEnvelope(0, 0, width, height, 0)::public.scene_bounds;
END;
$$ LANGUAGE plpgsql IMMUTABLE;
-- Get distance between two virtual points
CREATE OR REPLACE FUNCTION public.virtual_distance(p1 public.virtual_point, p2 public.virtual_point)
RETURNS REAL AS $$
BEGIN
RETURN ST_Distance(p1, p2)::REAL;
END;
$$ LANGUAGE plpgsql IMMUTABLE;
-- Check if a point is within scene bounds
CREATE OR REPLACE FUNCTION public.point_in_bounds(
point public.virtual_point,
bounds public.scene_bounds
)
RETURNS BOOLEAN AS $$
BEGIN
RETURN ST_Within(point, bounds);
END;
$$ LANGUAGE plpgsql IMMUTABLE;
-- =============================================================================
-- Audit Helper Functions
-- =============================================================================
-- Log an audit event
CREATE OR REPLACE FUNCTION audit.log_event(
p_category audit.event_category,
p_action TEXT,
p_target_type TEXT DEFAULT NULL,
p_target_id UUID DEFAULT NULL,
p_details JSONB DEFAULT '{}',
p_success BOOLEAN DEFAULT TRUE,
p_error_message TEXT DEFAULT NULL
)
RETURNS UUID AS $$
DECLARE
v_event_id UUID;
BEGIN
INSERT INTO audit.events (
category,
action,
user_id,
ip_address,
target_type,
target_id,
realm_id,
details,
success,
error_message
) VALUES (
p_category,
p_action,
public.current_user_id(),
NULLIF(current_setting('app.client_ip', true), '')::INET,
p_target_type,
p_target_id,
public.current_realm_id(),
p_details,
p_success,
p_error_message
)
RETURNING id INTO v_event_id;
RETURN v_event_id;
END;
$$ LANGUAGE plpgsql;
COMMENT ON FUNCTION audit.log_event IS 'Helper to create audit log entries';
COMMIT;

View file

@ -0,0 +1,170 @@
-- Chattyness User Initialization Functions
-- PostgreSQL 18
--
-- Functions to initialize new users with default props and avatars.
-- Load via: psql -f schema/functions/002_user_init.sql
\set ON_ERROR_STOP on
BEGIN;
-- =============================================================================
-- Initialize New User with Default Props and Avatar
-- =============================================================================
-- Called when a new user is created to give them:
-- 1. All face-tagged server props in their inventory
-- 2. A default avatar (slot 0) with the Face prop and all emotions configured
--
-- Note: active_avatars entry is NOT created here - it's created when the user
-- joins a realm for the first time (per-realm avatar state).
-- =============================================================================
CREATE OR REPLACE FUNCTION auth.initialize_new_user(p_user_id UUID)
RETURNS VOID AS $$
DECLARE
v_avatar_id UUID;
v_face_inventory_id UUID;
v_neutral_inventory_id UUID;
v_happy_inventory_id UUID;
v_sad_inventory_id UUID;
v_angry_inventory_id UUID;
v_surprised_inventory_id UUID;
v_thinking_inventory_id UUID;
v_laughing_inventory_id UUID;
v_crying_inventory_id UUID;
v_love_inventory_id UUID;
v_confused_inventory_id UUID;
v_sleeping_inventory_id UUID;
v_wink_inventory_id UUID;
v_prop RECORD;
BEGIN
-- Insert all face-tagged server props into user's inventory
-- Note: inventory layer/position are only for content layer props (skin/clothes/accessories).
-- Emotion props have default_emotion instead of default_layer, so they get NULL layer/position.
FOR v_prop IN
SELECT id, name, asset_path, default_layer, default_emotion, default_position, slug,
is_transferable, is_portable, is_droppable
FROM server.props
WHERE tags @> ARRAY['face']
AND is_active = true
LOOP
-- Use a local variable for the inserted inventory ID
DECLARE
v_new_inventory_id UUID;
BEGIN
INSERT INTO auth.inventory (
user_id,
server_prop_id,
prop_name,
prop_asset_path,
layer,
position,
origin,
is_transferable,
is_portable,
is_droppable
)
VALUES (
p_user_id,
v_prop.id,
v_prop.name,
v_prop.asset_path,
v_prop.default_layer, -- NULL for emotion props
CASE WHEN v_prop.default_layer IS NOT NULL THEN v_prop.default_position ELSE NULL END,
'server_library',
v_prop.is_transferable,
v_prop.is_portable,
v_prop.is_droppable
)
RETURNING id INTO v_new_inventory_id;
-- Track inventory IDs for avatar assignment based on slug
CASE v_prop.slug
WHEN 'face' THEN v_face_inventory_id := v_new_inventory_id;
WHEN 'neutral' THEN v_neutral_inventory_id := v_new_inventory_id;
WHEN 'smile' THEN v_happy_inventory_id := v_new_inventory_id;
WHEN 'sad' THEN v_sad_inventory_id := v_new_inventory_id;
WHEN 'angry' THEN v_angry_inventory_id := v_new_inventory_id;
WHEN 'surprised' THEN v_surprised_inventory_id := v_new_inventory_id;
WHEN 'thinking' THEN v_thinking_inventory_id := v_new_inventory_id;
WHEN 'laughing' THEN v_laughing_inventory_id := v_new_inventory_id;
WHEN 'crying' THEN v_crying_inventory_id := v_new_inventory_id;
WHEN 'love' THEN v_love_inventory_id := v_new_inventory_id;
WHEN 'confused' THEN v_confused_inventory_id := v_new_inventory_id;
WHEN 'sleeping' THEN v_sleeping_inventory_id := v_new_inventory_id;
WHEN 'wink' THEN v_wink_inventory_id := v_new_inventory_id;
ELSE NULL;
END CASE;
END;
END LOOP;
-- Create default avatar (slot 0) with the Face prop in skin layer
-- and all emotion props in their respective emotion slots at position 4 (center)
INSERT INTO auth.avatars (
user_id,
name,
slot_number,
last_emotion,
-- Content layer: Face goes in skin layer, center position
l_skin_4,
-- Emotion layers: Each emotion prop goes to its matching emotion at center position
e_neutral_4,
e_happy_4,
e_sad_4,
e_angry_4,
e_surprised_4,
e_thinking_4,
e_laughing_4,
e_crying_4,
e_love_4,
e_confused_4,
e_sleeping_4,
e_wink_4
)
VALUES (
p_user_id,
'Default',
0,
0, -- Start with neutral emotion
v_face_inventory_id,
v_neutral_inventory_id,
v_happy_inventory_id,
v_sad_inventory_id,
v_angry_inventory_id,
v_surprised_inventory_id,
v_thinking_inventory_id,
v_laughing_inventory_id,
v_crying_inventory_id,
v_love_inventory_id,
v_confused_inventory_id,
v_sleeping_inventory_id,
v_wink_inventory_id
)
RETURNING id INTO v_avatar_id;
-- Note: We don't create an active_avatars entry here because that's per-realm.
-- The active_avatars entry will be created when the user first joins a realm.
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
COMMENT ON FUNCTION auth.initialize_new_user(UUID) IS
'Initialize a new user with default props in inventory and a default avatar configuration';
-- =============================================================================
-- Trigger Function for User Registration
-- =============================================================================
-- Wrapper trigger function that calls initialize_new_user.
-- =============================================================================
CREATE OR REPLACE FUNCTION auth.initialize_new_user_trigger()
RETURNS TRIGGER AS $$
BEGIN
PERFORM auth.initialize_new_user(NEW.id);
RETURN NEW;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
COMMENT ON FUNCTION auth.initialize_new_user_trigger() IS
'Trigger function to initialize new users on registration';
COMMIT;

View file

@ -0,0 +1,197 @@
-- Chattyness Admin Restore Props Function
-- PostgreSQL 18
--
-- Admin function to restore missing essential props for users.
-- Load via: psql -f schema/functions/003_admin_restore_props.sql
\set ON_ERROR_STOP on
BEGIN;
-- =============================================================================
-- Restore Essential Props for a Single User
-- =============================================================================
-- Restores missing face-tagged server props to a user's inventory and fixes
-- any broken avatar slot references.
--
-- Usage: SELECT * FROM auth.restore_essential_props('username');
-- =============================================================================
CREATE OR REPLACE FUNCTION auth.restore_essential_props(p_username TEXT)
RETURNS TABLE(
action TEXT,
prop_slug TEXT,
inventory_id UUID
) AS $$
DECLARE
v_user_id UUID;
v_prop RECORD;
v_inventory_id UUID;
v_avatar_id UUID;
BEGIN
-- Get user ID
SELECT id INTO v_user_id FROM auth.users WHERE username = p_username;
IF v_user_id IS NULL THEN
RAISE EXCEPTION 'User not found: %', p_username;
END IF;
-- For each face-tagged server prop
FOR v_prop IN
SELECT id, name, asset_path, default_layer, default_emotion, default_position, slug,
is_transferable, is_portable, is_droppable
FROM server.props
WHERE tags @> ARRAY['face'] AND is_active = true
LOOP
-- Check if user already has this prop
SELECT inv.id INTO v_inventory_id
FROM auth.inventory inv
WHERE inv.user_id = v_user_id AND inv.server_prop_id = v_prop.id;
IF v_inventory_id IS NULL THEN
-- Insert missing prop
INSERT INTO auth.inventory (
user_id, server_prop_id, prop_name, prop_asset_path,
layer, position, origin,
is_transferable, is_portable, is_droppable
)
VALUES (
v_user_id, v_prop.id, v_prop.name, v_prop.asset_path,
v_prop.default_layer,
CASE WHEN v_prop.default_layer IS NOT NULL THEN v_prop.default_position ELSE NULL END,
'server_library',
v_prop.is_transferable, v_prop.is_portable, v_prop.is_droppable
)
RETURNING id INTO v_inventory_id;
action := 'restored';
prop_slug := v_prop.slug;
inventory_id := v_inventory_id;
RETURN NEXT;
ELSE
action := 'exists';
prop_slug := v_prop.slug;
inventory_id := v_inventory_id;
RETURN NEXT;
END IF;
END LOOP;
-- Get the user's default avatar (slot 0)
SELECT id INTO v_avatar_id FROM auth.avatars WHERE user_id = v_user_id AND slot_number = 0;
IF v_avatar_id IS NOT NULL THEN
-- Update avatar slots with correct inventory references where NULL
UPDATE auth.avatars a
SET
l_skin_4 = COALESCE(a.l_skin_4, (
SELECT inv.id FROM auth.inventory inv
JOIN server.props sp ON inv.server_prop_id = sp.id
WHERE inv.user_id = v_user_id AND sp.slug = 'face'
)),
e_neutral_4 = COALESCE(a.e_neutral_4, (
SELECT inv.id FROM auth.inventory inv
JOIN server.props sp ON inv.server_prop_id = sp.id
WHERE inv.user_id = v_user_id AND sp.slug = 'neutral'
)),
e_happy_4 = COALESCE(a.e_happy_4, (
SELECT inv.id FROM auth.inventory inv
JOIN server.props sp ON inv.server_prop_id = sp.id
WHERE inv.user_id = v_user_id AND sp.slug = 'smile'
)),
e_sad_4 = COALESCE(a.e_sad_4, (
SELECT inv.id FROM auth.inventory inv
JOIN server.props sp ON inv.server_prop_id = sp.id
WHERE inv.user_id = v_user_id AND sp.slug = 'sad'
)),
e_angry_4 = COALESCE(a.e_angry_4, (
SELECT inv.id FROM auth.inventory inv
JOIN server.props sp ON inv.server_prop_id = sp.id
WHERE inv.user_id = v_user_id AND sp.slug = 'angry'
)),
e_surprised_4 = COALESCE(a.e_surprised_4, (
SELECT inv.id FROM auth.inventory inv
JOIN server.props sp ON inv.server_prop_id = sp.id
WHERE inv.user_id = v_user_id AND sp.slug = 'surprised'
)),
e_thinking_4 = COALESCE(a.e_thinking_4, (
SELECT inv.id FROM auth.inventory inv
JOIN server.props sp ON inv.server_prop_id = sp.id
WHERE inv.user_id = v_user_id AND sp.slug = 'thinking'
)),
e_laughing_4 = COALESCE(a.e_laughing_4, (
SELECT inv.id FROM auth.inventory inv
JOIN server.props sp ON inv.server_prop_id = sp.id
WHERE inv.user_id = v_user_id AND sp.slug = 'laughing'
)),
e_crying_4 = COALESCE(a.e_crying_4, (
SELECT inv.id FROM auth.inventory inv
JOIN server.props sp ON inv.server_prop_id = sp.id
WHERE inv.user_id = v_user_id AND sp.slug = 'crying'
)),
e_love_4 = COALESCE(a.e_love_4, (
SELECT inv.id FROM auth.inventory inv
JOIN server.props sp ON inv.server_prop_id = sp.id
WHERE inv.user_id = v_user_id AND sp.slug = 'love'
)),
e_confused_4 = COALESCE(a.e_confused_4, (
SELECT inv.id FROM auth.inventory inv
JOIN server.props sp ON inv.server_prop_id = sp.id
WHERE inv.user_id = v_user_id AND sp.slug = 'confused'
)),
e_sleeping_4 = COALESCE(a.e_sleeping_4, (
SELECT inv.id FROM auth.inventory inv
JOIN server.props sp ON inv.server_prop_id = sp.id
WHERE inv.user_id = v_user_id AND sp.slug = 'sleeping'
)),
e_wink_4 = COALESCE(a.e_wink_4, (
SELECT inv.id FROM auth.inventory inv
JOIN server.props sp ON inv.server_prop_id = sp.id
WHERE inv.user_id = v_user_id AND sp.slug = 'wink'
))
WHERE a.id = v_avatar_id;
action := 'avatar_fixed';
prop_slug := NULL;
inventory_id := v_avatar_id;
RETURN NEXT;
END IF;
END;
$$ LANGUAGE plpgsql;
COMMENT ON FUNCTION auth.restore_essential_props(TEXT) IS
'Restore missing essential (face-tagged) props to a user''s inventory and fix avatar slots';
-- =============================================================================
-- Restore Essential Props for All Users
-- =============================================================================
-- Batch operation to restore props for all users.
--
-- Usage: SELECT * FROM auth.restore_essential_props_all_users();
-- =============================================================================
CREATE OR REPLACE FUNCTION auth.restore_essential_props_all_users()
RETURNS TABLE(
username TEXT,
props_restored INTEGER
) AS $$
DECLARE
v_user RECORD;
v_count INTEGER;
BEGIN
FOR v_user IN SELECT id, u.username FROM auth.users u LOOP
SELECT COUNT(*) INTO v_count
FROM auth.restore_essential_props(v_user.username)
WHERE action = 'restored';
IF v_count > 0 THEN
username := v_user.username;
props_restored := v_count;
RETURN NEXT;
END IF;
END LOOP;
END;
$$ LANGUAGE plpgsql;
COMMENT ON FUNCTION auth.restore_essential_props_all_users() IS
'Restore missing essential props for all users - returns users who had props restored';
COMMIT;

122
db/schema/load.sql Normal file
View file

@ -0,0 +1,122 @@
-- Chattyness Database Schema Loader
-- PostgreSQL 18 with PostGIS
--
-- Master file to load all schema components in correct order.
--
-- Usage:
-- psql -d your_database -f schema/load.sql
--
-- Or from psql:
-- \i schema/load.sql
--
-- Prerequisites:
-- - PostgreSQL 18 with PostGIS extension available
-- - Database already created
-- - Superuser or appropriate privileges
\set ON_ERROR_STOP on
\timing on
\echo '=============================================='
\echo 'Chattyness Database Schema Loader'
\echo '=============================================='
\echo ''
-- =============================================================================
-- Phase 1: Initialization (schemas, extensions, roles)
-- =============================================================================
\echo 'Phase 1: Initialization...'
\ir 000_init.sql
\echo ''
-- =============================================================================
-- Phase 2: Types (ENUMs, domains)
-- =============================================================================
\echo 'Phase 2: Creating types...'
\ir types/001_enums.sql
\ir types/002_domains.sql
\echo ''
-- =============================================================================
-- Phase 3: Tables (in dependency order)
-- =============================================================================
-- Schema: server (010) → auth (020) → realm (030) → scene (045) → chat (050) → audit (080)
-- Note: props and moderation schemas removed; tables distributed to server/auth/realm/scene
\echo 'Phase 3: Creating tables...'
\ir tables/010_server.sql
\ir tables/020_auth.sql
\ir tables/030_realm.sql
\ir tables/045_scene.sql
\ir tables/050_chat.sql
\ir tables/080_audit.sql
\echo ''
-- =============================================================================
-- Phase 4: Functions
-- =============================================================================
\echo 'Phase 4: Creating functions...'
\ir functions/001_helpers.sql
\ir functions/002_user_init.sql
\echo ''
-- =============================================================================
-- Phase 5: Triggers
-- =============================================================================
\echo 'Phase 5: Creating triggers...'
\ir triggers/001_updated_at.sql
\ir triggers/002_user_init.sql
\echo ''
-- =============================================================================
-- Phase 6: Row-Level Security Policies
-- =============================================================================
\echo 'Phase 6: Enabling Row-Level Security...'
\ir policies/001_rls.sql
\echo ''
-- =============================================================================
-- Complete
-- =============================================================================
\echo '=============================================='
\echo 'Schema loaded successfully!'
\echo '=============================================='
\echo ''
-- =============================================================================
-- Phase 7: Set Passwords for Application Roles
-- =============================================================================
\echo 'Phase 7: Setting up application credentials...'
-- Generate secure passwords
\set app_password `pwgen -s 80 1`
\set owner_password `pwgen -s 80 1`
-- Set passwords for roles (created in init.sql)
ALTER ROLE chattyness_app WITH PASSWORD :'app_password';
ALTER ROLE chattyness_owner WITH PASSWORD :'owner_password';
\echo ''
\echo '=============================================='
\echo 'Application Credentials Set'
\echo '=============================================='
\echo ''
\echo 'chattyness_app (application role, subject to RLS):'
\echo ' Password: ' :app_password
\echo ''
\echo 'chattyness_owner (owner role, bypasses RLS):'
\echo ' Password: ' :owner_password
\echo ''
-- Write .env file
\! echo "# Chattyness Database Credentials" > .env
\! echo "# Generated by load.sql" >> .env
\! echo "" >> .env
\set write_app `echo "export DB_CHATTYNESS_APP=":app_password >> .env`
\set write_owner `echo "export DB_CHATTYNESS_OWNER=":owner_password >> .env`
\echo 'Credentials written to: .env'
\echo ''
\echo 'Login roles:'
\echo ' chattyness_app - Application operations (subject to RLS)'
\echo ' chattyness_owner - Owner operations (bypasses RLS)'
\echo ''

View file

@ -0,0 +1,985 @@
-- Chattyness Row-Level Security Policies
-- PostgreSQL 18
--
-- RLS policies for data isolation and access control
-- Load via: psql -f schema/policies/001_rls.sql
--
-- IMPORTANT: The application must set session variables before queries:
--
-- For authenticated users:
-- SELECT public.set_current_user_id('user-uuid-here');
-- SELECT public.set_current_realm_id('realm-uuid-here'); -- when in a realm
--
-- For guest users:
-- SELECT public.set_current_user_id(NULL);
-- SELECT public.set_current_guest_session_id('guest-session-uuid-here');
-- SELECT public.set_current_realm_id('realm-uuid-here'); -- when in a realm
--
-- The chattyness_app role is used by the application backend.
\set ON_ERROR_STOP on
BEGIN;
-- =============================================================================
-- Grant Usage on Schemas to Application Role
-- =============================================================================
GRANT USAGE ON SCHEMA server TO chattyness_app;
GRANT USAGE ON SCHEMA auth TO chattyness_app;
GRANT USAGE ON SCHEMA realm TO chattyness_app;
GRANT USAGE ON SCHEMA scene TO chattyness_app;
GRANT USAGE ON SCHEMA chat TO chattyness_app;
GRANT USAGE ON SCHEMA audit TO chattyness_app;
-- =============================================================================
-- SERVER SCHEMA POLICIES
-- =============================================================================
-- Server data is readable by all, writable only by server admins.
-- =============================================================================
-- server.config
ALTER TABLE server.config ENABLE ROW LEVEL SECURITY;
CREATE POLICY server_config_select ON server.config
FOR SELECT TO chattyness_app
USING (true);
GRANT SELECT ON server.config TO chattyness_app;
-- server.staff
ALTER TABLE server.staff ENABLE ROW LEVEL SECURITY;
CREATE POLICY server_staff_select ON server.staff
FOR SELECT TO chattyness_app
USING (true);
GRANT SELECT ON server.staff TO chattyness_app;
-- server.props
ALTER TABLE server.props ENABLE ROW LEVEL SECURITY;
CREATE POLICY server_props_select ON server.props
FOR SELECT TO chattyness_app
USING (true);
CREATE POLICY server_props_insert ON server.props
FOR INSERT TO chattyness_app
WITH CHECK (public.is_server_admin());
CREATE POLICY server_props_update ON server.props
FOR UPDATE TO chattyness_app
USING (public.is_server_admin())
WITH CHECK (public.is_server_admin());
CREATE POLICY server_props_delete ON server.props
FOR DELETE TO chattyness_app
USING (public.is_server_admin());
GRANT SELECT ON server.props TO chattyness_app;
GRANT INSERT, UPDATE, DELETE ON server.props TO chattyness_app;
-- server.audio
ALTER TABLE server.audio ENABLE ROW LEVEL SECURITY;
CREATE POLICY server_audio_select ON server.audio
FOR SELECT TO chattyness_app
USING (true);
CREATE POLICY server_audio_modify ON server.audio
FOR ALL TO chattyness_app
USING (public.is_server_admin())
WITH CHECK (public.is_server_admin());
GRANT SELECT, INSERT, UPDATE, DELETE ON server.audio TO chattyness_app;
-- server.reserved_names
ALTER TABLE server.reserved_names ENABLE ROW LEVEL SECURITY;
CREATE POLICY server_reserved_names_select ON server.reserved_names
FOR SELECT TO chattyness_app
USING (true);
CREATE POLICY server_reserved_names_modify ON server.reserved_names
FOR ALL TO chattyness_app
USING (public.is_server_admin())
WITH CHECK (public.is_server_admin());
GRANT SELECT, INSERT, UPDATE, DELETE ON server.reserved_names TO chattyness_app;
-- server.scripts
ALTER TABLE server.scripts ENABLE ROW LEVEL SECURITY;
CREATE POLICY server_scripts_select ON server.scripts
FOR SELECT TO chattyness_app
USING (true);
CREATE POLICY server_scripts_modify ON server.scripts
FOR ALL TO chattyness_app
USING (public.is_server_admin())
WITH CHECK (public.is_server_admin());
GRANT SELECT, INSERT, UPDATE, DELETE ON server.scripts TO chattyness_app;
-- server.ip_bans
ALTER TABLE server.ip_bans ENABLE ROW LEVEL SECURITY;
CREATE POLICY server_ip_bans_select ON server.ip_bans
FOR SELECT TO chattyness_app
USING (true);
CREATE POLICY server_ip_bans_modify ON server.ip_bans
FOR ALL TO chattyness_app
USING (public.is_server_admin())
WITH CHECK (public.is_server_admin());
GRANT SELECT, INSERT, UPDATE, DELETE ON server.ip_bans TO chattyness_app;
-- server.bans
ALTER TABLE server.bans ENABLE ROW LEVEL SECURITY;
CREATE POLICY server_bans_select ON server.bans
FOR SELECT TO chattyness_app
USING (true);
CREATE POLICY server_bans_modify ON server.bans
FOR ALL TO chattyness_app
USING (public.is_server_moderator())
WITH CHECK (public.is_server_moderator());
GRANT SELECT, INSERT, UPDATE, DELETE ON server.bans TO chattyness_app;
-- server.mutes
ALTER TABLE server.mutes ENABLE ROW LEVEL SECURITY;
CREATE POLICY server_mutes_select ON server.mutes
FOR SELECT TO chattyness_app
USING (true);
CREATE POLICY server_mutes_modify ON server.mutes
FOR ALL TO chattyness_app
USING (public.is_server_moderator())
WITH CHECK (public.is_server_moderator());
GRANT SELECT, INSERT, UPDATE, DELETE ON server.mutes TO chattyness_app;
-- server.content_filters
ALTER TABLE server.content_filters ENABLE ROW LEVEL SECURITY;
CREATE POLICY server_content_filters_select ON server.content_filters
FOR SELECT TO chattyness_app
USING (true);
CREATE POLICY server_content_filters_modify ON server.content_filters
FOR ALL TO chattyness_app
USING (public.is_server_admin())
WITH CHECK (public.is_server_admin());
GRANT SELECT, INSERT, UPDATE, DELETE ON server.content_filters TO chattyness_app;
-- server.moderation_actions
ALTER TABLE server.moderation_actions ENABLE ROW LEVEL SECURITY;
CREATE POLICY server_moderation_actions_target ON server.moderation_actions
FOR SELECT TO chattyness_app
USING (target_user_id = public.current_user_id());
CREATE POLICY server_moderation_actions_mod ON server.moderation_actions
FOR ALL TO chattyness_app
USING (public.is_server_moderator())
WITH CHECK (public.is_server_moderator());
GRANT SELECT, INSERT ON server.moderation_actions TO chattyness_app;
-- =============================================================================
-- AUTH SCHEMA POLICIES
-- =============================================================================
-- auth.users
ALTER TABLE auth.users ENABLE ROW LEVEL SECURITY;
CREATE POLICY auth_users_select ON auth.users
FOR SELECT TO chattyness_app
USING (
id = public.current_user_id()
OR NOT auth.has_blocked(id, public.current_user_id())
);
CREATE POLICY auth_users_update ON auth.users
FOR UPDATE TO chattyness_app
USING (id = public.current_user_id())
WITH CHECK (id = public.current_user_id());
CREATE POLICY auth_users_insert ON auth.users
FOR INSERT TO chattyness_app
WITH CHECK (true);
CREATE POLICY auth_users_admin ON auth.users
FOR ALL TO chattyness_app
USING (public.is_server_admin())
WITH CHECK (public.is_server_admin());
GRANT SELECT, UPDATE ON auth.users TO chattyness_app;
GRANT INSERT, DELETE ON auth.users TO chattyness_app;
-- auth.sessions
ALTER TABLE auth.sessions ENABLE ROW LEVEL SECURITY;
CREATE POLICY auth_sessions_own ON auth.sessions
FOR ALL TO chattyness_app
USING (user_id = public.current_user_id())
WITH CHECK (user_id = public.current_user_id());
CREATE POLICY auth_sessions_admin ON auth.sessions
FOR SELECT TO chattyness_app
USING (public.is_server_admin());
GRANT SELECT, INSERT, UPDATE, DELETE ON auth.sessions TO chattyness_app;
-- auth.guest_sessions
ALTER TABLE auth.guest_sessions ENABLE ROW LEVEL SECURITY;
CREATE POLICY auth_guest_sessions_all ON auth.guest_sessions
FOR ALL TO chattyness_app
USING (true)
WITH CHECK (true);
GRANT SELECT, INSERT, UPDATE, DELETE ON auth.guest_sessions TO chattyness_app;
-- auth.tower_sessions
ALTER TABLE auth.tower_sessions ENABLE ROW LEVEL SECURITY;
CREATE POLICY auth_tower_sessions_all ON auth.tower_sessions
FOR ALL TO chattyness_app
USING (true)
WITH CHECK (true);
GRANT SELECT, INSERT, UPDATE, DELETE ON auth.tower_sessions TO chattyness_app;
-- auth.friendships
ALTER TABLE auth.friendships ENABLE ROW LEVEL SECURITY;
CREATE POLICY auth_friendships_own ON auth.friendships
FOR ALL TO chattyness_app
USING (
friend_a = public.current_user_id()
OR friend_b = public.current_user_id()
)
WITH CHECK (
friend_a = public.current_user_id()
OR friend_b = public.current_user_id()
);
GRANT SELECT, INSERT, UPDATE, DELETE ON auth.friendships TO chattyness_app;
-- auth.blocks
ALTER TABLE auth.blocks ENABLE ROW LEVEL SECURITY;
CREATE POLICY auth_blocks_own ON auth.blocks
FOR ALL TO chattyness_app
USING (blocker_id = public.current_user_id())
WITH CHECK (blocker_id = public.current_user_id());
CREATE POLICY auth_blocks_mod ON auth.blocks
FOR SELECT TO chattyness_app
USING (public.is_server_moderator());
GRANT SELECT, INSERT, DELETE ON auth.blocks TO chattyness_app;
-- auth.mutes (user personal mutes)
ALTER TABLE auth.mutes ENABLE ROW LEVEL SECURITY;
CREATE POLICY auth_mutes_own ON auth.mutes
FOR ALL TO chattyness_app
USING (muter_id = public.current_user_id())
WITH CHECK (muter_id = public.current_user_id());
GRANT SELECT, INSERT, DELETE ON auth.mutes TO chattyness_app;
-- auth.user_scripts
ALTER TABLE auth.user_scripts ENABLE ROW LEVEL SECURITY;
CREATE POLICY auth_user_scripts_own ON auth.user_scripts
FOR ALL TO chattyness_app
USING (user_id = public.current_user_id())
WITH CHECK (user_id = public.current_user_id());
CREATE POLICY auth_user_scripts_admin ON auth.user_scripts
FOR SELECT TO chattyness_app
USING (public.is_server_admin());
GRANT SELECT, INSERT, UPDATE, DELETE ON auth.user_scripts TO chattyness_app;
-- auth.inventory
ALTER TABLE auth.inventory ENABLE ROW LEVEL SECURITY;
CREATE POLICY auth_inventory_own ON auth.inventory
FOR ALL TO chattyness_app
USING (user_id = public.current_user_id())
WITH CHECK (user_id = public.current_user_id());
CREATE POLICY auth_inventory_view ON auth.inventory
FOR SELECT TO chattyness_app
USING (true);
GRANT SELECT, INSERT, UPDATE, DELETE ON auth.inventory TO chattyness_app;
-- auth.avatars
ALTER TABLE auth.avatars ENABLE ROW LEVEL SECURITY;
CREATE POLICY auth_avatars_own ON auth.avatars
FOR ALL TO chattyness_app
USING (user_id = public.current_user_id())
WITH CHECK (user_id = public.current_user_id());
CREATE POLICY auth_avatars_view ON auth.avatars
FOR SELECT TO chattyness_app
USING (true);
GRANT SELECT, INSERT, UPDATE, DELETE ON auth.avatars TO chattyness_app;
-- auth.active_avatars
ALTER TABLE auth.active_avatars ENABLE ROW LEVEL SECURITY;
CREATE POLICY auth_active_avatars_own ON auth.active_avatars
FOR ALL TO chattyness_app
USING (user_id = public.current_user_id())
WITH CHECK (user_id = public.current_user_id());
CREATE POLICY auth_active_avatars_view ON auth.active_avatars
FOR SELECT TO chattyness_app
USING (true);
GRANT SELECT, INSERT, UPDATE, DELETE ON auth.active_avatars TO chattyness_app;
-- =============================================================================
-- REALM SCHEMA POLICIES
-- =============================================================================
-- realm.realms
ALTER TABLE realm.realms ENABLE ROW LEVEL SECURITY;
CREATE POLICY realm_realms_select ON realm.realms
FOR SELECT TO chattyness_app
USING (
privacy = 'public'
OR privacy = 'unlisted'
OR owner_id = public.current_user_id()
OR public.has_realm_membership(id)
OR public.is_server_admin()
);
CREATE POLICY realm_realms_owner ON realm.realms
FOR UPDATE TO chattyness_app
USING (owner_id = public.current_user_id())
WITH CHECK (owner_id = public.current_user_id());
CREATE POLICY realm_realms_insert ON realm.realms
FOR INSERT TO chattyness_app
WITH CHECK (owner_id = public.current_user_id());
CREATE POLICY realm_realms_delete ON realm.realms
FOR DELETE TO chattyness_app
USING (owner_id = public.current_user_id() OR public.is_server_admin());
CREATE POLICY realm_realms_admin ON realm.realms
FOR ALL TO chattyness_app
USING (public.is_server_admin())
WITH CHECK (public.is_server_admin());
GRANT SELECT, INSERT, UPDATE, DELETE ON realm.realms TO chattyness_app;
-- realm.scenes
ALTER TABLE realm.scenes ENABLE ROW LEVEL SECURITY;
CREATE POLICY realm_scenes_select ON realm.scenes
FOR SELECT TO chattyness_app
USING (
EXISTS (
SELECT 1 FROM realm.realms r
WHERE r.id = realm_id
AND (
r.privacy IN ('public', 'unlisted')
OR r.owner_id = public.current_user_id()
OR public.has_realm_membership(r.id)
OR public.is_server_admin()
)
)
);
CREATE POLICY realm_scenes_modify ON realm.scenes
FOR ALL TO chattyness_app
USING (
EXISTS (
SELECT 1 FROM realm.memberships m
WHERE m.realm_id = realm.scenes.realm_id
AND m.user_id = public.current_user_id()
AND m.role IN ('owner', 'builder')
)
OR public.is_server_admin()
)
WITH CHECK (
EXISTS (
SELECT 1 FROM realm.memberships m
WHERE m.realm_id = realm.scenes.realm_id
AND m.user_id = public.current_user_id()
AND m.role IN ('owner', 'builder')
)
OR public.is_server_admin()
);
GRANT SELECT, INSERT, UPDATE, DELETE ON realm.scenes TO chattyness_app;
-- realm.memberships
ALTER TABLE realm.memberships ENABLE ROW LEVEL SECURITY;
CREATE POLICY realm_memberships_select ON realm.memberships
FOR SELECT TO chattyness_app
USING (
user_id = public.current_user_id()
OR EXISTS (
SELECT 1 FROM realm.realms r
WHERE r.id = realm_id
AND (r.privacy = 'public' OR public.has_realm_membership(r.id))
)
OR public.is_server_admin()
);
CREATE POLICY realm_memberships_own ON realm.memberships
FOR ALL TO chattyness_app
USING (user_id = public.current_user_id())
WITH CHECK (user_id = public.current_user_id());
CREATE POLICY realm_memberships_mod ON realm.memberships
FOR ALL TO chattyness_app
USING (public.is_realm_moderator(realm_id))
WITH CHECK (public.is_realm_moderator(realm_id));
GRANT SELECT, INSERT, UPDATE, DELETE ON realm.memberships TO chattyness_app;
-- realm.realm_scripts
ALTER TABLE realm.realm_scripts ENABLE ROW LEVEL SECURITY;
CREATE POLICY realm_realm_scripts_select ON realm.realm_scripts
FOR SELECT TO chattyness_app
USING (
EXISTS (
SELECT 1 FROM realm.realms r
WHERE r.id = realm_id
)
);
CREATE POLICY realm_realm_scripts_modify ON realm.realm_scripts
FOR ALL TO chattyness_app
USING (
EXISTS (
SELECT 1 FROM realm.memberships m
WHERE m.realm_id = realm.realm_scripts.realm_id
AND m.user_id = public.current_user_id()
AND m.role IN ('owner', 'builder')
)
OR public.is_server_admin()
);
GRANT SELECT, INSERT, UPDATE, DELETE ON realm.realm_scripts TO chattyness_app;
-- realm.props
ALTER TABLE realm.props ENABLE ROW LEVEL SECURITY;
CREATE POLICY realm_props_select ON realm.props
FOR SELECT TO chattyness_app
USING (
public.has_realm_membership(realm_id)
OR public.is_server_admin()
);
CREATE POLICY realm_props_modify ON realm.props
FOR ALL TO chattyness_app
USING (
EXISTS (
SELECT 1 FROM realm.memberships m
WHERE m.realm_id = realm.props.realm_id
AND m.user_id = public.current_user_id()
AND m.role IN ('owner', 'builder')
)
OR public.is_server_admin()
);
GRANT SELECT, INSERT, UPDATE, DELETE ON realm.props TO chattyness_app;
-- realm.reports
ALTER TABLE realm.reports ENABLE ROW LEVEL SECURITY;
CREATE POLICY realm_reports_own ON realm.reports
FOR SELECT TO chattyness_app
USING (reporter_id = public.current_user_id());
CREATE POLICY realm_reports_insert ON realm.reports
FOR INSERT TO chattyness_app
WITH CHECK (reporter_id = public.current_user_id());
CREATE POLICY realm_reports_mod ON realm.reports
FOR ALL TO chattyness_app
USING (
public.is_server_moderator()
OR public.is_realm_moderator(realm_id)
);
GRANT SELECT, INSERT, UPDATE ON realm.reports TO chattyness_app;
-- realm.bans
ALTER TABLE realm.bans ENABLE ROW LEVEL SECURITY;
CREATE POLICY realm_bans_select ON realm.bans
FOR SELECT TO chattyness_app
USING (true);
CREATE POLICY realm_bans_modify ON realm.bans
FOR ALL TO chattyness_app
USING (
public.is_server_moderator()
OR public.is_realm_moderator(realm_id)
);
GRANT SELECT, INSERT, UPDATE, DELETE ON realm.bans TO chattyness_app;
-- realm.mutes (realm moderation mutes)
ALTER TABLE realm.mutes ENABLE ROW LEVEL SECURITY;
CREATE POLICY realm_mutes_select ON realm.mutes
FOR SELECT TO chattyness_app
USING (true);
CREATE POLICY realm_mutes_modify ON realm.mutes
FOR ALL TO chattyness_app
USING (
public.is_server_moderator()
OR public.is_realm_moderator(realm_id)
);
GRANT SELECT, INSERT, UPDATE, DELETE ON realm.mutes TO chattyness_app;
-- realm.content_filters
ALTER TABLE realm.content_filters ENABLE ROW LEVEL SECURITY;
CREATE POLICY realm_content_filters_select ON realm.content_filters
FOR SELECT TO chattyness_app
USING (
public.has_realm_membership(realm_id)
OR public.is_server_admin()
);
CREATE POLICY realm_content_filters_modify ON realm.content_filters
FOR ALL TO chattyness_app
USING (
EXISTS (
SELECT 1 FROM realm.memberships m
WHERE m.realm_id = realm.content_filters.realm_id
AND m.user_id = public.current_user_id()
AND m.role IN ('owner', 'moderator')
)
OR public.is_server_admin()
);
GRANT SELECT, INSERT, UPDATE, DELETE ON realm.content_filters TO chattyness_app;
-- realm.moderation_actions
ALTER TABLE realm.moderation_actions ENABLE ROW LEVEL SECURITY;
CREATE POLICY realm_moderation_actions_target ON realm.moderation_actions
FOR SELECT TO chattyness_app
USING (target_user_id = public.current_user_id());
CREATE POLICY realm_moderation_actions_mod ON realm.moderation_actions
FOR ALL TO chattyness_app
USING (
public.is_server_moderator()
OR public.is_realm_moderator(realm_id)
);
GRANT SELECT, INSERT ON realm.moderation_actions TO chattyness_app;
-- =============================================================================
-- SCENE SCHEMA POLICIES
-- =============================================================================
-- scene.instances
ALTER TABLE scene.instances ENABLE ROW LEVEL SECURITY;
CREATE POLICY scene_instances_select ON scene.instances
FOR SELECT TO chattyness_app
USING (
instance_type = 'public'
AND EXISTS (
SELECT 1 FROM realm.scenes s
JOIN realm.realms r ON r.id = s.realm_id
WHERE s.id = scene_id
AND (
r.privacy IN ('public', 'unlisted')
OR r.owner_id = public.current_user_id()
OR public.has_realm_membership(r.id)
)
)
OR
(
instance_type = 'private'
AND (
created_by = public.current_user_id()
OR EXISTS (
SELECT 1 FROM scene.instance_invites ii
WHERE ii.instance_id = scene.instances.id
AND ii.invited_user_id = public.current_user_id()
AND ii.accepted_at IS NOT NULL
)
)
)
OR public.is_server_admin()
);
CREATE POLICY scene_instances_insert ON scene.instances
FOR INSERT TO chattyness_app
WITH CHECK (true);
CREATE POLICY scene_instances_modify ON scene.instances
FOR UPDATE TO chattyness_app
USING (
created_by = public.current_user_id()
OR public.is_realm_moderator(
(SELECT s.realm_id FROM realm.scenes s WHERE s.id = scene_id)
)
);
CREATE POLICY scene_instances_delete ON scene.instances
FOR DELETE TO chattyness_app
USING (
created_by = public.current_user_id()
OR public.is_realm_moderator(
(SELECT s.realm_id FROM realm.scenes s WHERE s.id = scene_id)
)
);
GRANT SELECT, INSERT, UPDATE, DELETE ON scene.instances TO chattyness_app;
-- scene.instance_members
ALTER TABLE scene.instance_members ENABLE ROW LEVEL SECURITY;
CREATE POLICY scene_instance_members_select ON scene.instance_members
FOR SELECT TO chattyness_app
USING (
EXISTS (
SELECT 1 FROM realm.scenes s
WHERE s.id = instance_id
)
);
CREATE POLICY scene_instance_members_own ON scene.instance_members
FOR ALL TO chattyness_app
USING (
user_id = public.current_user_id()
OR guest_session_id = public.current_guest_session_id()
)
WITH CHECK (
user_id = public.current_user_id()
OR guest_session_id = public.current_guest_session_id()
);
GRANT SELECT, INSERT, UPDATE, DELETE ON scene.instance_members TO chattyness_app;
-- scene.instance_invites
ALTER TABLE scene.instance_invites ENABLE ROW LEVEL SECURITY;
CREATE POLICY scene_instance_invites_select ON scene.instance_invites
FOR SELECT TO chattyness_app
USING (
invited_user_id = public.current_user_id()
OR invited_by = public.current_user_id()
OR public.is_server_admin()
);
CREATE POLICY scene_instance_invites_own ON scene.instance_invites
FOR ALL TO chattyness_app
USING (
invited_user_id = public.current_user_id()
OR invited_by = public.current_user_id()
)
WITH CHECK (
invited_by = public.current_user_id()
);
GRANT SELECT, INSERT, UPDATE, DELETE ON scene.instance_invites TO chattyness_app;
-- scene.spots
ALTER TABLE scene.spots ENABLE ROW LEVEL SECURITY;
CREATE POLICY scene_spots_select ON scene.spots
FOR SELECT TO chattyness_app
USING (
EXISTS (
SELECT 1 FROM realm.scenes s
WHERE s.id = scene_id
)
);
CREATE POLICY scene_spots_modify ON scene.spots
FOR ALL TO chattyness_app
USING (
EXISTS (
SELECT 1 FROM realm.scenes s
JOIN realm.memberships m ON m.realm_id = s.realm_id
WHERE s.id = scene_id
AND m.user_id = public.current_user_id()
AND m.role IN ('owner', 'builder')
)
OR public.is_server_admin()
)
WITH CHECK (
EXISTS (
SELECT 1 FROM realm.scenes s
JOIN realm.memberships m ON m.realm_id = s.realm_id
WHERE s.id = scene_id
AND m.user_id = public.current_user_id()
AND m.role IN ('owner', 'builder')
)
OR public.is_server_admin()
);
GRANT SELECT, INSERT, UPDATE, DELETE ON scene.spots TO chattyness_app;
-- scene.spot_states
ALTER TABLE scene.spot_states ENABLE ROW LEVEL SECURITY;
CREATE POLICY scene_spot_states_select ON scene.spot_states
FOR SELECT TO chattyness_app
USING (
EXISTS (
SELECT 1 FROM scene.spots sp
WHERE sp.id = spot_id
)
);
CREATE POLICY scene_spot_states_modify ON scene.spot_states
FOR ALL TO chattyness_app
USING (
EXISTS (
SELECT 1 FROM scene.spots sp
JOIN realm.scenes s ON s.id = sp.scene_id
JOIN realm.memberships m ON m.realm_id = s.realm_id
WHERE sp.id = spot_id
AND m.user_id = public.current_user_id()
AND m.role IN ('owner', 'builder')
)
OR public.is_server_admin()
)
WITH CHECK (
EXISTS (
SELECT 1 FROM scene.spots sp
JOIN realm.scenes s ON s.id = sp.scene_id
JOIN realm.memberships m ON m.realm_id = s.realm_id
WHERE sp.id = spot_id
AND m.user_id = public.current_user_id()
AND m.role IN ('owner', 'builder')
)
OR public.is_server_admin()
);
GRANT SELECT, INSERT, UPDATE, DELETE ON scene.spot_states TO chattyness_app;
-- scene.scripts
ALTER TABLE scene.scripts ENABLE ROW LEVEL SECURITY;
CREATE POLICY scene_scripts_select ON scene.scripts
FOR SELECT TO chattyness_app
USING (
EXISTS (
SELECT 1 FROM realm.scenes s
WHERE s.id = scene_id
)
);
CREATE POLICY scene_scripts_modify ON scene.scripts
FOR ALL TO chattyness_app
USING (
EXISTS (
SELECT 1 FROM realm.scenes s
JOIN realm.memberships m ON m.realm_id = s.realm_id
WHERE s.id = scene_id
AND m.user_id = public.current_user_id()
AND m.role IN ('owner', 'builder')
)
OR public.is_server_admin()
);
GRANT SELECT, INSERT, UPDATE, DELETE ON scene.scripts TO chattyness_app;
-- scene.loose_props
ALTER TABLE scene.loose_props ENABLE ROW LEVEL SECURITY;
CREATE POLICY scene_loose_props_select ON scene.loose_props
FOR SELECT TO chattyness_app
USING (
EXISTS (
SELECT 1 FROM scene.instances i
WHERE i.id = instance_id
)
);
CREATE POLICY scene_loose_props_modify ON scene.loose_props
FOR ALL TO chattyness_app
USING (true)
WITH CHECK (true);
GRANT SELECT, INSERT, UPDATE, DELETE ON scene.loose_props TO chattyness_app;
-- scene.decorations
ALTER TABLE scene.decorations ENABLE ROW LEVEL SECURITY;
CREATE POLICY scene_decorations_select ON scene.decorations
FOR SELECT TO chattyness_app
USING (
EXISTS (
SELECT 1 FROM realm.scenes s
WHERE s.id = scene_id
)
);
CREATE POLICY scene_decorations_modify ON scene.decorations
FOR ALL TO chattyness_app
USING (
EXISTS (
SELECT 1 FROM realm.scenes s
JOIN realm.memberships m ON m.realm_id = s.realm_id
WHERE s.id = scene_id
AND m.user_id = public.current_user_id()
AND m.role IN ('owner', 'builder')
)
OR public.is_server_admin()
);
GRANT SELECT, INSERT, UPDATE, DELETE ON scene.decorations TO chattyness_app;
-- =============================================================================
-- CHAT SCHEMA POLICIES
-- =============================================================================
-- chat.messages
ALTER TABLE chat.messages ENABLE ROW LEVEL SECURITY;
CREATE POLICY chat_messages_select ON chat.messages
FOR SELECT TO chattyness_app
USING (
(NOT is_deleted OR public.is_server_moderator())
AND EXISTS (
SELECT 1 FROM scene.instances i
WHERE i.id = instance_id
)
);
CREATE POLICY chat_messages_insert ON chat.messages
FOR INSERT TO chattyness_app
WITH CHECK (
user_id = public.current_user_id()
OR guest_session_id = public.current_guest_session_id()
);
CREATE POLICY chat_messages_update ON chat.messages
FOR UPDATE TO chattyness_app
USING (
user_id = public.current_user_id()
OR guest_session_id = public.current_guest_session_id()
OR public.is_server_moderator()
);
GRANT SELECT, INSERT, UPDATE ON chat.messages TO chattyness_app;
-- chat.whispers
ALTER TABLE chat.whispers ENABLE ROW LEVEL SECURITY;
CREATE POLICY chat_whispers_own ON chat.whispers
FOR ALL TO chattyness_app
USING (
sender_id = public.current_user_id()
OR recipient_id = public.current_user_id()
)
WITH CHECK (
sender_id = public.current_user_id()
);
GRANT SELECT, INSERT, UPDATE ON chat.whispers TO chattyness_app;
-- chat.reactions
ALTER TABLE chat.reactions ENABLE ROW LEVEL SECURITY;
CREATE POLICY chat_reactions_select ON chat.reactions
FOR SELECT TO chattyness_app
USING (true);
CREATE POLICY chat_reactions_own ON chat.reactions
FOR ALL TO chattyness_app
USING (user_id = public.current_user_id())
WITH CHECK (user_id = public.current_user_id());
GRANT SELECT, INSERT, DELETE ON chat.reactions TO chattyness_app;
-- chat.shouts
ALTER TABLE chat.shouts ENABLE ROW LEVEL SECURITY;
CREATE POLICY chat_shouts_select ON chat.shouts
FOR SELECT TO chattyness_app
USING (true);
CREATE POLICY chat_shouts_insert ON chat.shouts
FOR INSERT TO chattyness_app
WITH CHECK (public.is_server_admin());
GRANT SELECT, INSERT ON chat.shouts TO chattyness_app;
-- =============================================================================
-- AUDIT SCHEMA POLICIES
-- =============================================================================
-- audit.events
ALTER TABLE audit.events ENABLE ROW LEVEL SECURITY;
CREATE POLICY audit_events_own ON audit.events
FOR SELECT TO chattyness_app
USING (user_id = public.current_user_id());
CREATE POLICY audit_events_admin ON audit.events
FOR SELECT TO chattyness_app
USING (public.is_server_admin());
CREATE POLICY audit_events_realm ON audit.events
FOR SELECT TO chattyness_app
USING (
realm_id IS NOT NULL
AND EXISTS (
SELECT 1 FROM realm.realms r
WHERE r.id = realm_id
AND r.owner_id = public.current_user_id()
)
);
CREATE POLICY audit_events_insert ON audit.events
FOR INSERT TO chattyness_app
WITH CHECK (true);
GRANT SELECT, INSERT ON audit.events TO chattyness_app;
-- audit.login_history
ALTER TABLE audit.login_history ENABLE ROW LEVEL SECURITY;
CREATE POLICY audit_login_history_own ON audit.login_history
FOR SELECT TO chattyness_app
USING (user_id = public.current_user_id());
CREATE POLICY audit_login_history_admin ON audit.login_history
FOR SELECT TO chattyness_app
USING (public.is_server_admin());
CREATE POLICY audit_login_history_insert ON audit.login_history
FOR INSERT TO chattyness_app
WITH CHECK (true);
GRANT SELECT, INSERT ON audit.login_history TO chattyness_app;
COMMIT;

View file

@ -0,0 +1,47 @@
-- Chattyness Server Schema Tables
-- PostgreSQL 18 with PostGIS
--
-- Server-wide configuration, global resources, and settings
\set ON_ERROR_STOP on
BEGIN;
-- =============================================================================
-- Server Configuration (Singleton)
-- =============================================================================
CREATE TABLE server.config (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
name public.nonempty_text NOT NULL,
description TEXT,
welcome_message TEXT,
default_scene_bounds public.scene_bounds NOT NULL
DEFAULT ST_MakeEnvelope(0, 0, 800, 600, 0),
max_users_per_channel INTEGER NOT NULL DEFAULT 50
CHECK (max_users_per_channel > 0 AND max_users_per_channel <= 1000),
message_rate_limit INTEGER NOT NULL DEFAULT 10 CHECK (message_rate_limit > 0),
message_rate_window_seconds INTEGER NOT NULL DEFAULT 60 CHECK (message_rate_window_seconds > 0),
allow_guest_access BOOLEAN NOT NULL DEFAULT true,
allow_user_uploads BOOLEAN NOT NULL DEFAULT true,
require_email_verification BOOLEAN NOT NULL DEFAULT false,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now(),
CONSTRAINT chk_server_config_singleton CHECK (id = '00000000-0000-0000-0000-000000000001'::UUID)
);
COMMENT ON TABLE server.config IS 'Server-wide configuration settings (singleton table)';
INSERT INTO server.config (id, name, description) VALUES (
'00000000-0000-0000-0000-000000000001'::UUID,
'Chattyness Server',
'A 2D virtual chat world'
);
COMMIT;

View file

@ -0,0 +1,782 @@
-- Chattyness Auth Schema Tables
-- PostgreSQL 18
--
-- User authentication, accounts, and identity management
\set ON_ERROR_STOP on
BEGIN;
-- =============================================================================
-- User Accounts
-- =============================================================================
CREATE TABLE auth.users (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
username auth.username NOT NULL,
email auth.email,
password_hash TEXT,
auth_provider auth.auth_provider NOT NULL DEFAULT 'local',
oauth_id TEXT,
display_name public.display_name NOT NULL,
bio TEXT,
avatar_url public.url,
reputation_tier server.reputation_tier NOT NULL DEFAULT 'member',
reputation_promoted_at TIMESTAMPTZ,
status auth.account_status NOT NULL DEFAULT 'active',
email_verified BOOLEAN NOT NULL DEFAULT false,
email_verified_at TIMESTAMPTZ,
force_pw_reset BOOLEAN NOT NULL DEFAULT false,
last_seen_at TIMESTAMPTZ,
total_time_online_seconds BIGINT NOT NULL DEFAULT 0,
script_state JSONB NOT NULL DEFAULT '{}',
-- User tags for feature gating and access control
tags auth.user_tag[] NOT NULL DEFAULT '{}',
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now(),
CONSTRAINT uq_auth_users_username UNIQUE (username),
CONSTRAINT uq_auth_users_email UNIQUE (email),
CONSTRAINT uq_auth_users_oauth UNIQUE (auth_provider, oauth_id),
CONSTRAINT chk_auth_users_password_or_oauth_or_guest
CHECK (password_hash IS NOT NULL OR oauth_id IS NOT NULL OR 'guest' = ANY(tags))
);
COMMENT ON TABLE auth.users IS 'User accounts and authentication';
CREATE INDEX idx_auth_users_email ON auth.users (lower(email));
CREATE INDEX idx_auth_users_status ON auth.users (status);
CREATE INDEX idx_auth_users_reputation ON auth.users (reputation_tier);
CREATE INDEX idx_auth_users_last_seen ON auth.users (last_seen_at DESC NULLS LAST);
CREATE INDEX idx_auth_users_tags ON auth.users USING GIN (tags);
-- =============================================================================
-- User Sessions
-- =============================================================================
CREATE TABLE auth.sessions (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
token_hash TEXT NOT NULL,
user_agent TEXT,
ip_address INET,
expires_at TIMESTAMPTZ NOT NULL,
last_activity_at TIMESTAMPTZ NOT NULL DEFAULT now(),
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
CONSTRAINT uq_auth_sessions_token UNIQUE (token_hash)
);
COMMENT ON TABLE auth.sessions IS 'Active user sessions';
CREATE INDEX idx_auth_sessions_user ON auth.sessions (user_id);
CREATE INDEX idx_auth_sessions_expires ON auth.sessions (expires_at);
-- =============================================================================
-- Tower Sessions (tower-sessions crate)
-- =============================================================================
CREATE TABLE auth.tower_sessions (
id TEXT PRIMARY KEY,
data BYTEA NOT NULL,
expiry_date TIMESTAMPTZ NOT NULL
);
COMMENT ON TABLE auth.tower_sessions IS 'Session storage for tower-sessions crate';
CREATE INDEX idx_auth_tower_sessions_expiry ON auth.tower_sessions (expiry_date);
-- =============================================================================
-- Friends List
-- =============================================================================
CREATE TABLE auth.friendships (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
friend_a UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
friend_b UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
initiated_by UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
is_accepted BOOLEAN NOT NULL DEFAULT false,
accepted_at TIMESTAMPTZ,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
CONSTRAINT uq_auth_friendships UNIQUE (friend_a, friend_b),
CONSTRAINT chk_auth_friendships_ordered CHECK (friend_a < friend_b),
CONSTRAINT chk_auth_friendships_initiator CHECK (initiated_by = friend_a OR initiated_by = friend_b)
);
COMMENT ON TABLE auth.friendships IS 'Friend relationships (normalized: friend_a < friend_b)';
CREATE INDEX idx_auth_friendships_friend_a ON auth.friendships (friend_a);
CREATE INDEX idx_auth_friendships_friend_b ON auth.friendships (friend_b);
CREATE INDEX idx_auth_friendships_pending ON auth.friendships (is_accepted) WHERE is_accepted = false;
-- =============================================================================
-- Block List
-- =============================================================================
CREATE TABLE auth.blocks (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
blocker_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
blocked_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
reason TEXT,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
CONSTRAINT uq_auth_blocks UNIQUE (blocker_id, blocked_id),
CONSTRAINT chk_auth_blocks_not_self CHECK (blocker_id != blocked_id)
);
COMMENT ON TABLE auth.blocks IS 'User block list';
CREATE INDEX idx_auth_blocks_blocker ON auth.blocks (blocker_id);
CREATE INDEX idx_auth_blocks_blocked ON auth.blocks (blocked_id);
-- =============================================================================
-- Mute List
-- =============================================================================
CREATE TABLE auth.mutes (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
muter_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
muted_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
expires_at TIMESTAMPTZ,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
CONSTRAINT uq_auth_mutes UNIQUE (muter_id, muted_id),
CONSTRAINT chk_auth_mutes_not_self CHECK (muter_id != muted_id)
);
COMMENT ON TABLE auth.mutes IS 'User mute list';
CREATE INDEX idx_auth_mutes_muter ON auth.mutes (muter_id);
CREATE INDEX idx_auth_mutes_muted ON auth.mutes (muted_id);
-- =============================================================================
-- Password Reset Tokens
-- =============================================================================
CREATE TABLE auth.password_resets (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
token_hash TEXT NOT NULL,
expires_at TIMESTAMPTZ NOT NULL,
used_at TIMESTAMPTZ,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
CONSTRAINT uq_auth_password_resets_token UNIQUE (token_hash)
);
COMMENT ON TABLE auth.password_resets IS 'Password reset tokens';
CREATE INDEX idx_auth_password_resets_user ON auth.password_resets (user_id);
CREATE INDEX idx_auth_password_resets_expires ON auth.password_resets (expires_at) WHERE used_at IS NULL;
-- =============================================================================
-- Email Verification Tokens
-- =============================================================================
CREATE TABLE auth.email_verifications (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
email auth.email NOT NULL,
token_hash TEXT NOT NULL,
expires_at TIMESTAMPTZ NOT NULL,
verified_at TIMESTAMPTZ,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
CONSTRAINT uq_auth_email_verifications_token UNIQUE (token_hash)
);
COMMENT ON TABLE auth.email_verifications IS 'Email verification tokens';
CREATE INDEX idx_auth_email_verifications_user ON auth.email_verifications (user_id);
-- =============================================================================
-- User Scripts
-- =============================================================================
CREATE TABLE auth.user_scripts (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
name public.nonempty_text NOT NULL,
slug public.slug NOT NULL,
description TEXT,
source TEXT NOT NULL,
config JSONB NOT NULL DEFAULT '{}',
state JSONB NOT NULL DEFAULT '{}',
is_enabled BOOLEAN NOT NULL DEFAULT true,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now(),
CONSTRAINT uq_auth_user_scripts_slug UNIQUE (user_id, slug)
);
COMMENT ON TABLE auth.user_scripts IS 'Per-user Rhai scripts';
CREATE INDEX idx_auth_user_scripts_user ON auth.user_scripts (user_id);
CREATE INDEX idx_auth_user_scripts_enabled ON auth.user_scripts (user_id, is_enabled) WHERE is_enabled = true;
-- =============================================================================
-- Server Staff (created here since it references auth.users)
-- =============================================================================
CREATE TABLE server.staff (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
role server.server_role NOT NULL,
appointed_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
appointed_at TIMESTAMPTZ NOT NULL DEFAULT now(),
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now(),
CONSTRAINT uq_server_staff_user UNIQUE (user_id)
);
COMMENT ON TABLE server.staff IS 'Server-level administrative staff';
-- =============================================================================
-- Server Prop Library (Global Props)
-- =============================================================================
CREATE TABLE server.props (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
name public.nonempty_text NOT NULL,
slug public.slug NOT NULL,
description TEXT,
tags TEXT[] NOT NULL DEFAULT '{}',
asset_path public.asset_path NOT NULL,
thumbnail_path public.asset_path,
-- Default avatar positioning (content layer OR emotion layer, mutually exclusive)
default_layer server.avatar_layer,
default_emotion server.emotion_state,
default_position SMALLINT CHECK (default_position IS NULL OR default_position BETWEEN 0 AND 8),
is_unique BOOLEAN NOT NULL DEFAULT false,
is_transferable BOOLEAN NOT NULL DEFAULT true,
is_portable BOOLEAN NOT NULL DEFAULT true,
is_droppable BOOLEAN NOT NULL DEFAULT true,
is_active BOOLEAN NOT NULL DEFAULT true,
available_from TIMESTAMPTZ,
available_until TIMESTAMPTZ,
created_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now(),
CONSTRAINT uq_server_props_slug UNIQUE (slug),
CONSTRAINT chk_server_props_availability CHECK (
available_from IS NULL OR available_until IS NULL OR available_from < available_until
),
-- Props can be: non-avatar (all NULL), content layer, OR emotion layer (mutually exclusive)
CONSTRAINT chk_server_props_positioning CHECK (
-- Nothing set (non-avatar prop)
(default_layer IS NULL AND default_emotion IS NULL AND default_position IS NULL) OR
-- Content layer prop (skin/clothes/accessories at position 0-8)
(default_layer IS NOT NULL AND default_emotion IS NULL AND default_position IS NOT NULL) OR
-- Emotion layer prop (neutral/happy/sad/etc at position 0-8)
(default_layer IS NULL AND default_emotion IS NOT NULL AND default_position IS NOT NULL)
)
);
COMMENT ON TABLE server.props IS 'Global prop library (64x64 pixels, center-anchored)';
CREATE INDEX idx_server_props_tags ON server.props USING GIN (tags);
CREATE INDEX idx_server_props_active ON server.props (is_active) WHERE is_active = true;
-- =============================================================================
-- Audio Library
-- =============================================================================
CREATE TABLE server.audio (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
name public.nonempty_text NOT NULL,
slug public.slug NOT NULL,
description TEXT,
category server.audio_category NOT NULL,
tags TEXT[] NOT NULL DEFAULT '{}',
asset_path public.asset_path NOT NULL,
duration_seconds REAL NOT NULL CHECK (duration_seconds > 0),
is_loopable BOOLEAN NOT NULL DEFAULT false,
is_active BOOLEAN NOT NULL DEFAULT true,
created_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now(),
CONSTRAINT uq_server_audio_slug UNIQUE (slug)
);
COMMENT ON TABLE server.audio IS 'Global audio library';
CREATE INDEX idx_server_audio_category ON server.audio (category);
CREATE INDEX idx_server_audio_tags ON server.audio USING GIN (tags);
-- =============================================================================
-- Reserved Names
-- =============================================================================
CREATE TABLE server.reserved_names (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
name TEXT NOT NULL,
name_type server.reserved_name_type NOT NULL,
reason TEXT,
reserved_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
COMMENT ON TABLE server.reserved_names IS 'Names reserved from use by users';
CREATE UNIQUE INDEX uq_server_reserved_names ON server.reserved_names (lower(name), name_type);
-- =============================================================================
-- Server Scripts
-- =============================================================================
CREATE TABLE server.scripts (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
name public.nonempty_text NOT NULL,
slug public.slug NOT NULL,
description TEXT,
source TEXT NOT NULL,
config JSONB NOT NULL DEFAULT '{}',
state JSONB NOT NULL DEFAULT '{}',
is_enabled BOOLEAN NOT NULL DEFAULT true,
run_on_user_login BOOLEAN NOT NULL DEFAULT false,
run_on_user_logout BOOLEAN NOT NULL DEFAULT false,
run_on_registration BOOLEAN NOT NULL DEFAULT false,
run_on_server_shutdown BOOLEAN NOT NULL DEFAULT false,
created_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now(),
CONSTRAINT uq_server_scripts_slug UNIQUE (slug)
);
COMMENT ON TABLE server.scripts IS 'Server-wide Rhai scripts';
CREATE INDEX idx_server_scripts_enabled ON server.scripts (is_enabled) WHERE is_enabled = true;
-- =============================================================================
-- User Inventory (moved from props.inventory)
-- =============================================================================
-- User inventory stores props owned by users (worn on avatar or in bag).
-- Inventory items reference a source: server prop, realm prop, or user upload.
-- The denormalized prop_name/prop_asset_path are cached at acquisition time.
-- =============================================================================
CREATE TABLE auth.inventory (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
-- Source of the prop (at least one required)
server_prop_id UUID REFERENCES server.props(id) ON DELETE SET NULL,
realm_prop_id UUID, -- FK added in 030_realm.sql
upload_id UUID, -- Future: user uploads
-- Denormalized display info (cached at acquisition)
prop_name TEXT NOT NULL,
prop_asset_path public.asset_path NOT NULL,
layer server.avatar_layer,
position SMALLINT CHECK (position IS NULL OR position BETWEEN 0 AND 8),
-- Provenance chain for tracking history
provenance JSONB NOT NULL DEFAULT '[]',
origin server.prop_origin NOT NULL,
-- Behavioral flags (cached from source at acquisition)
is_transferable BOOLEAN NOT NULL DEFAULT true,
is_portable BOOLEAN NOT NULL DEFAULT true,
is_droppable BOOLEAN NOT NULL DEFAULT true,
acquired_at TIMESTAMPTZ NOT NULL DEFAULT now(),
-- At least one source must be present
CONSTRAINT chk_auth_inventory_has_source CHECK (
server_prop_id IS NOT NULL OR realm_prop_id IS NOT NULL OR upload_id IS NOT NULL
)
);
COMMENT ON TABLE auth.inventory IS 'User-owned props (denormalized for performance)';
COMMENT ON COLUMN auth.inventory.provenance IS 'Array of {from_user, timestamp, method} objects';
CREATE INDEX idx_auth_inventory_user ON auth.inventory (user_id);
CREATE INDEX idx_auth_inventory_server_prop ON auth.inventory (server_prop_id)
WHERE server_prop_id IS NOT NULL;
CREATE INDEX idx_auth_inventory_realm_prop ON auth.inventory (realm_prop_id)
WHERE realm_prop_id IS NOT NULL;
-- =============================================================================
-- User Avatars (moved from props.avatars)
-- =============================================================================
-- Avatar configurations per user (up to 10 slots: 0-9).
-- Uses 15 columns per layer, 135 total for the 9-position grid system.
-- =============================================================================
CREATE TABLE auth.avatars (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
slot_number SMALLINT NOT NULL CHECK (slot_number >= 0 AND slot_number <= 9),
name public.display_name,
is_default BOOLEAN NOT NULL DEFAULT false,
last_emotion SMALLINT NOT NULL DEFAULT 0 CHECK (last_emotion >= 0 AND last_emotion <= 11),
-- Content layers: skin (3), clothes (3), accessories (3) = 9 layers x 9 positions = 81 potential slots
-- But we use 3 layers x 9 positions = 27 content slots
l_skin_0 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
l_skin_1 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
l_skin_2 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
l_skin_3 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
l_skin_4 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
l_skin_5 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
l_skin_6 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
l_skin_7 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
l_skin_8 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
l_clothes_0 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
l_clothes_1 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
l_clothes_2 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
l_clothes_3 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
l_clothes_4 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
l_clothes_5 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
l_clothes_6 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
l_clothes_7 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
l_clothes_8 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
l_accessories_0 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
l_accessories_1 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
l_accessories_2 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
l_accessories_3 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
l_accessories_4 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
l_accessories_5 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
l_accessories_6 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
l_accessories_7 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
l_accessories_8 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
-- Emotion layers: 12 emotions x 9 positions = 108 slots
e_neutral_0 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_neutral_1 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_neutral_2 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_neutral_3 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_neutral_4 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_neutral_5 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_neutral_6 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_neutral_7 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_neutral_8 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_happy_0 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_happy_1 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_happy_2 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_happy_3 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_happy_4 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_happy_5 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_happy_6 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_happy_7 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_happy_8 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_sad_0 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_sad_1 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_sad_2 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_sad_3 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_sad_4 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_sad_5 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_sad_6 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_sad_7 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_sad_8 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_angry_0 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_angry_1 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_angry_2 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_angry_3 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_angry_4 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_angry_5 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_angry_6 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_angry_7 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_angry_8 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_surprised_0 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_surprised_1 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_surprised_2 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_surprised_3 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_surprised_4 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_surprised_5 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_surprised_6 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_surprised_7 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_surprised_8 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_thinking_0 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_thinking_1 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_thinking_2 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_thinking_3 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_thinking_4 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_thinking_5 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_thinking_6 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_thinking_7 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_thinking_8 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_laughing_0 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_laughing_1 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_laughing_2 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_laughing_3 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_laughing_4 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_laughing_5 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_laughing_6 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_laughing_7 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_laughing_8 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_crying_0 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_crying_1 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_crying_2 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_crying_3 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_crying_4 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_crying_5 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_crying_6 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_crying_7 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_crying_8 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_love_0 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_love_1 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_love_2 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_love_3 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_love_4 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_love_5 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_love_6 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_love_7 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_love_8 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_confused_0 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_confused_1 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_confused_2 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_confused_3 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_confused_4 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_confused_5 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_confused_6 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_confused_7 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_confused_8 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_sleeping_0 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_sleeping_1 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_sleeping_2 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_sleeping_3 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_sleeping_4 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_sleeping_5 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_sleeping_6 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_sleeping_7 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_sleeping_8 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_wink_0 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_wink_1 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_wink_2 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_wink_3 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_wink_4 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_wink_5 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_wink_6 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_wink_7 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
e_wink_8 UUID REFERENCES auth.inventory(id) ON DELETE SET NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now(),
CONSTRAINT uq_auth_avatars_slot UNIQUE (user_id, slot_number)
);
COMMENT ON TABLE auth.avatars IS 'User avatar configurations with 135 prop slots';
CREATE INDEX idx_auth_avatars_user ON auth.avatars (user_id);
CREATE INDEX idx_auth_avatars_default ON auth.avatars (user_id, is_default) WHERE is_default = true;
-- =============================================================================
-- Active Avatars (moved from props.active_avatars)
-- =============================================================================
-- Tracks which avatar a user is currently using in each realm.
-- =============================================================================
CREATE TABLE auth.active_avatars (
user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
realm_id UUID NOT NULL, -- FK added in 030_realm.sql after realm.realms exists
avatar_id UUID NOT NULL REFERENCES auth.avatars(id) ON DELETE CASCADE,
current_emotion SMALLINT NOT NULL DEFAULT 0 CHECK (current_emotion >= 0 AND current_emotion <= 11),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now(),
PRIMARY KEY (user_id, realm_id)
);
COMMENT ON TABLE auth.active_avatars IS 'Current avatar per user per realm';
-- =============================================================================
-- Server-Level Moderation: IP Bans
-- =============================================================================
CREATE TABLE server.ip_bans (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
ip_address INET NOT NULL,
ip_range CIDR, -- Optional CIDR range for subnet bans
reason TEXT NOT NULL,
evidence JSONB NOT NULL DEFAULT '[]',
banned_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
expires_at TIMESTAMPTZ, -- NULL = permanent
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now(),
CONSTRAINT uq_server_ip_bans_address UNIQUE (ip_address)
);
COMMENT ON TABLE server.ip_bans IS 'Server-wide IP address bans';
CREATE INDEX idx_server_ip_bans_range ON server.ip_bans USING GIST (ip_range inet_ops)
WHERE ip_range IS NOT NULL;
CREATE INDEX idx_server_ip_bans_expires ON server.ip_bans (expires_at)
WHERE expires_at IS NOT NULL;
-- =============================================================================
-- Server-Level Moderation: User Bans
-- =============================================================================
CREATE TABLE server.bans (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
reason TEXT NOT NULL,
evidence JSONB NOT NULL DEFAULT '[]',
banned_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
expires_at TIMESTAMPTZ, -- NULL = permanent
is_active BOOLEAN NOT NULL DEFAULT true,
unbanned_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
unbanned_at TIMESTAMPTZ,
unban_reason TEXT,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
COMMENT ON TABLE server.bans IS 'Server-wide user bans';
CREATE INDEX idx_server_bans_user ON server.bans (user_id);
CREATE INDEX idx_server_bans_active ON server.bans (user_id, is_active) WHERE is_active = true;
CREATE INDEX idx_server_bans_expires ON server.bans (expires_at) WHERE expires_at IS NOT NULL AND is_active = true;
-- =============================================================================
-- Server-Level Moderation: Server Mutes
-- =============================================================================
CREATE TABLE server.mutes (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
reason TEXT NOT NULL,
muted_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
expires_at TIMESTAMPTZ, -- NULL = permanent
is_active BOOLEAN NOT NULL DEFAULT true,
unmuted_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
unmuted_at TIMESTAMPTZ,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
COMMENT ON TABLE server.mutes IS 'Server-wide user mutes (cannot send messages anywhere)';
CREATE INDEX idx_server_mutes_user ON server.mutes (user_id);
CREATE INDEX idx_server_mutes_active ON server.mutes (user_id, is_active) WHERE is_active = true;
-- =============================================================================
-- Server-Level Moderation: Content Filters
-- =============================================================================
CREATE TABLE server.content_filters (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
pattern TEXT NOT NULL,
is_regex BOOLEAN NOT NULL DEFAULT false,
is_case_sensitive BOOLEAN NOT NULL DEFAULT false,
action server.filter_action NOT NULL DEFAULT 'block',
replacement TEXT,
reason TEXT,
is_active BOOLEAN NOT NULL DEFAULT true,
created_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
COMMENT ON TABLE server.content_filters IS 'Server-wide content filtering rules';
CREATE INDEX idx_server_content_filters_active ON server.content_filters (is_active) WHERE is_active = true;
-- =============================================================================
-- Server-Level Moderation: Action Log
-- =============================================================================
CREATE TABLE server.moderation_actions (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
action_type server.action_type NOT NULL,
target_user_id UUID REFERENCES auth.users(id) ON DELETE SET NULL,
moderator_id UUID REFERENCES auth.users(id) ON DELETE SET NULL,
reason TEXT NOT NULL,
evidence JSONB NOT NULL DEFAULT '[]',
metadata JSONB NOT NULL DEFAULT '{}',
created_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
COMMENT ON TABLE server.moderation_actions IS 'Log of server-level moderation actions';
CREATE INDEX idx_server_moderation_actions_target ON server.moderation_actions (target_user_id);
CREATE INDEX idx_server_moderation_actions_moderator ON server.moderation_actions (moderator_id);
CREATE INDEX idx_server_moderation_actions_type ON server.moderation_actions (action_type);
CREATE INDEX idx_server_moderation_actions_created ON server.moderation_actions (created_at DESC);
COMMIT;

View file

@ -0,0 +1,422 @@
-- Chattyness Realm Schema Tables
-- PostgreSQL 18 with PostGIS
--
-- Realms, scenes, memberships, realm props, and realm-level moderation
\set ON_ERROR_STOP on
BEGIN;
-- =============================================================================
-- Realms
-- =============================================================================
CREATE TABLE realm.realms (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
name public.nonempty_text NOT NULL,
slug public.slug NOT NULL,
description TEXT,
tagline TEXT,
owner_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE RESTRICT,
privacy realm.realm_privacy NOT NULL DEFAULT 'public',
is_nsfw BOOLEAN NOT NULL DEFAULT false,
min_reputation_tier server.reputation_tier NOT NULL DEFAULT 'guest',
theme_color public.hex_color,
banner_image_path public.asset_path,
thumbnail_path public.asset_path,
max_users INTEGER NOT NULL DEFAULT 100 CHECK (max_users > 0 AND max_users <= 10000),
allow_guest_access BOOLEAN NOT NULL DEFAULT true,
default_scene_id UUID,
member_count INTEGER NOT NULL DEFAULT 0 CHECK (member_count >= 0),
current_user_count INTEGER NOT NULL DEFAULT 0 CHECK (current_user_count >= 0),
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now(),
CONSTRAINT uq_realm_realms_slug UNIQUE (slug)
);
COMMENT ON TABLE realm.realms IS 'Themed virtual spaces';
CREATE INDEX idx_realm_realms_owner ON realm.realms (owner_id);
CREATE INDEX idx_realm_realms_privacy ON realm.realms (privacy);
CREATE INDEX idx_realm_realms_public ON realm.realms (privacy, is_nsfw) WHERE privacy = 'public';
-- =============================================================================
-- Scenes
-- =============================================================================
CREATE TABLE realm.scenes (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
realm_id UUID NOT NULL REFERENCES realm.realms(id) ON DELETE CASCADE,
name public.nonempty_text NOT NULL,
slug public.slug NOT NULL,
description TEXT,
background_image_path public.asset_path,
background_image_url public.url,
background_color public.hex_color DEFAULT '#1a1a2e',
bounds public.scene_bounds NOT NULL DEFAULT ST_MakeEnvelope(0, 0, 800, 600, 0),
dimension_mode realm.dimension_mode NOT NULL DEFAULT 'fixed',
ambient_audio_id UUID REFERENCES server.audio(id) ON DELETE SET NULL,
ambient_volume public.percentage DEFAULT 0.5,
sort_order INTEGER NOT NULL DEFAULT 0,
is_entry_point BOOLEAN NOT NULL DEFAULT false,
is_hidden BOOLEAN NOT NULL DEFAULT false,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now(),
CONSTRAINT uq_realm_scenes_slug UNIQUE (realm_id, slug)
);
COMMENT ON TABLE realm.scenes IS 'Rooms within a realm';
CREATE INDEX idx_realm_scenes_realm ON realm.scenes (realm_id);
CREATE INDEX idx_realm_scenes_realm_order ON realm.scenes (realm_id, sort_order);
-- Add FK for default_scene_id
ALTER TABLE realm.realms
ADD CONSTRAINT fk_realm_realms_default_scene
FOREIGN KEY (default_scene_id) REFERENCES realm.scenes(id) ON DELETE SET NULL;
-- =============================================================================
-- Guest Sessions (created here since it references realm tables)
-- =============================================================================
-- Note: current_instance_id FK is added in 045_scene.sql after scene.instances exists
CREATE TABLE auth.guest_sessions (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
guest_name public.display_name NOT NULL,
token_hash TEXT NOT NULL,
user_agent TEXT,
ip_address INET,
current_realm_id UUID REFERENCES realm.realms(id) ON DELETE SET NULL,
current_instance_id UUID, -- FK added in 045_scene.sql
expires_at TIMESTAMPTZ NOT NULL,
last_activity_at TIMESTAMPTZ NOT NULL DEFAULT now(),
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
CONSTRAINT uq_auth_guest_sessions_token UNIQUE (token_hash)
);
COMMENT ON TABLE auth.guest_sessions IS 'Anonymous guest sessions';
CREATE INDEX idx_auth_guest_sessions_expires ON auth.guest_sessions (expires_at);
CREATE INDEX idx_auth_guest_sessions_ip ON auth.guest_sessions (ip_address);
-- =============================================================================
-- Realm Memberships
-- =============================================================================
CREATE TABLE realm.memberships (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
realm_id UUID NOT NULL REFERENCES realm.realms(id) ON DELETE CASCADE,
user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
nickname public.display_name,
role realm.realm_role NOT NULL DEFAULT 'member',
role_granted_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
role_granted_at TIMESTAMPTZ,
exp_score BIGINT NOT NULL DEFAULT 0 CHECK (exp_score >= 0),
last_scene_id UUID REFERENCES realm.scenes(id) ON DELETE SET NULL,
last_position public.virtual_point,
last_visited_at TIMESTAMPTZ,
total_time_seconds BIGINT NOT NULL DEFAULT 0 CHECK (total_time_seconds >= 0),
script_state JSONB NOT NULL DEFAULT '{}',
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now(),
CONSTRAINT uq_realm_memberships UNIQUE (realm_id, user_id)
);
COMMENT ON TABLE realm.memberships IS 'User membership within a realm';
CREATE UNIQUE INDEX uq_realm_memberships_nickname ON realm.memberships (realm_id, lower(nickname)) WHERE nickname IS NOT NULL;
CREATE INDEX idx_realm_memberships_realm ON realm.memberships (realm_id);
CREATE INDEX idx_realm_memberships_user ON realm.memberships (user_id);
CREATE INDEX idx_realm_memberships_role ON realm.memberships (realm_id, role) WHERE role IN ('owner', 'moderator', 'builder');
-- =============================================================================
-- Realm Scripts
-- =============================================================================
CREATE TABLE realm.realm_scripts (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
realm_id UUID NOT NULL REFERENCES realm.realms(id) ON DELETE CASCADE,
name public.nonempty_text NOT NULL,
description TEXT,
source TEXT NOT NULL,
config JSONB NOT NULL DEFAULT '{}',
state JSONB NOT NULL DEFAULT '{}',
is_enabled BOOLEAN NOT NULL DEFAULT true,
run_on_realm_enter BOOLEAN NOT NULL DEFAULT false,
created_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
COMMENT ON TABLE realm.realm_scripts IS 'Rhai scripts for realms';
CREATE INDEX idx_realm_realm_scripts_realm ON realm.realm_scripts (realm_id);
CREATE INDEX idx_realm_realm_scripts_enabled ON realm.realm_scripts (realm_id, is_enabled) WHERE is_enabled = true;
-- =============================================================================
-- Realm Prop Library (moved from props.realm_props)
-- =============================================================================
-- Custom props specific to a realm (can only be used in that realm)
-- =============================================================================
CREATE TABLE realm.props (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
realm_id UUID NOT NULL REFERENCES realm.realms(id) ON DELETE CASCADE,
name public.nonempty_text NOT NULL,
slug public.slug NOT NULL,
description TEXT,
tags TEXT[] NOT NULL DEFAULT '{}',
asset_path public.asset_path NOT NULL,
thumbnail_path public.asset_path,
-- Default avatar positioning
default_layer server.avatar_layer,
default_emotion server.emotion_state,
default_position SMALLINT CHECK (default_position IS NULL OR default_position BETWEEN 0 AND 8),
is_unique BOOLEAN NOT NULL DEFAULT false,
is_transferable BOOLEAN NOT NULL DEFAULT true,
is_droppable BOOLEAN NOT NULL DEFAULT true,
is_active BOOLEAN NOT NULL DEFAULT true,
available_from TIMESTAMPTZ,
available_until TIMESTAMPTZ,
created_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now(),
CONSTRAINT uq_realm_props_slug UNIQUE (realm_id, slug),
CONSTRAINT chk_realm_props_availability CHECK (
available_from IS NULL OR available_until IS NULL OR available_from < available_until
),
-- Props can be: non-avatar (all NULL), content layer, OR emotion layer
CONSTRAINT chk_realm_props_positioning CHECK (
(default_layer IS NULL AND default_emotion IS NULL AND default_position IS NULL) OR
(default_layer IS NOT NULL AND default_emotion IS NULL AND default_position IS NOT NULL) OR
(default_layer IS NULL AND default_emotion IS NOT NULL AND default_position IS NOT NULL)
)
);
COMMENT ON TABLE realm.props IS 'Realm-specific prop library';
CREATE INDEX idx_realm_props_realm ON realm.props (realm_id);
CREATE INDEX idx_realm_props_tags ON realm.props USING GIN (tags);
CREATE INDEX idx_realm_props_active ON realm.props (realm_id, is_active) WHERE is_active = true;
-- =============================================================================
-- Add Foreign Keys to auth tables (now that realm.realms and realm.props exist)
-- =============================================================================
-- Add FK for auth.inventory.realm_prop_id
ALTER TABLE auth.inventory
ADD CONSTRAINT fk_auth_inventory_realm_prop
FOREIGN KEY (realm_prop_id) REFERENCES realm.props(id) ON DELETE SET NULL;
-- Add FK for auth.active_avatars.realm_id
ALTER TABLE auth.active_avatars
ADD CONSTRAINT fk_auth_active_avatars_realm
FOREIGN KEY (realm_id) REFERENCES realm.realms(id) ON DELETE CASCADE;
-- =============================================================================
-- Realm-Level Moderation: Reports
-- =============================================================================
-- Reports are always realm-scoped (but server admins can resolve them)
-- =============================================================================
CREATE TABLE realm.reports (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
realm_id UUID NOT NULL REFERENCES realm.realms(id) ON DELETE CASCADE,
reporter_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
reported_user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
category TEXT NOT NULL,
description TEXT NOT NULL,
evidence JSONB NOT NULL DEFAULT '[]',
-- Context
scene_id UUID REFERENCES realm.scenes(id) ON DELETE SET NULL,
message_id UUID, -- FK added when chat schema loads
status server.report_status NOT NULL DEFAULT 'pending',
resolved_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
resolved_at TIMESTAMPTZ,
resolution_notes TEXT,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now(),
CONSTRAINT chk_realm_reports_not_self CHECK (reporter_id != reported_user_id)
);
COMMENT ON TABLE realm.reports IS 'User reports within a realm';
CREATE INDEX idx_realm_reports_realm ON realm.reports (realm_id);
CREATE INDEX idx_realm_reports_reporter ON realm.reports (reporter_id);
CREATE INDEX idx_realm_reports_reported ON realm.reports (reported_user_id);
CREATE INDEX idx_realm_reports_status ON realm.reports (realm_id, status) WHERE status = 'pending';
-- =============================================================================
-- Realm-Level Moderation: Realm Bans
-- =============================================================================
CREATE TABLE realm.bans (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
realm_id UUID NOT NULL REFERENCES realm.realms(id) ON DELETE CASCADE,
user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
reason TEXT NOT NULL,
evidence JSONB NOT NULL DEFAULT '[]',
banned_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
expires_at TIMESTAMPTZ, -- NULL = permanent
is_active BOOLEAN NOT NULL DEFAULT true,
unbanned_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
unbanned_at TIMESTAMPTZ,
unban_reason TEXT,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now(),
CONSTRAINT uq_realm_bans_active UNIQUE (realm_id, user_id) -- Only one active ban per user per realm
);
COMMENT ON TABLE realm.bans IS 'Realm-specific user bans';
CREATE INDEX idx_realm_bans_realm ON realm.bans (realm_id);
CREATE INDEX idx_realm_bans_user ON realm.bans (user_id);
CREATE INDEX idx_realm_bans_active ON realm.bans (realm_id, user_id, is_active) WHERE is_active = true;
CREATE INDEX idx_realm_bans_expires ON realm.bans (expires_at) WHERE expires_at IS NOT NULL AND is_active = true;
-- =============================================================================
-- Realm-Level Moderation: Realm Mutes
-- =============================================================================
CREATE TABLE realm.mutes (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
realm_id UUID NOT NULL REFERENCES realm.realms(id) ON DELETE CASCADE,
user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
reason TEXT NOT NULL,
muted_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
expires_at TIMESTAMPTZ, -- NULL = permanent
is_active BOOLEAN NOT NULL DEFAULT true,
unmuted_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
unmuted_at TIMESTAMPTZ,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
COMMENT ON TABLE realm.mutes IS 'Realm-specific user mutes (cannot send messages in this realm)';
CREATE INDEX idx_realm_mutes_realm ON realm.mutes (realm_id);
CREATE INDEX idx_realm_mutes_user ON realm.mutes (user_id);
CREATE INDEX idx_realm_mutes_active ON realm.mutes (realm_id, user_id, is_active) WHERE is_active = true;
-- =============================================================================
-- Realm-Level Moderation: Content Filters
-- =============================================================================
CREATE TABLE realm.content_filters (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
realm_id UUID NOT NULL REFERENCES realm.realms(id) ON DELETE CASCADE,
pattern TEXT NOT NULL,
is_regex BOOLEAN NOT NULL DEFAULT false,
is_case_sensitive BOOLEAN NOT NULL DEFAULT false,
action server.filter_action NOT NULL DEFAULT 'block',
replacement TEXT,
reason TEXT,
is_active BOOLEAN NOT NULL DEFAULT true,
created_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
COMMENT ON TABLE realm.content_filters IS 'Realm-specific content filtering rules';
CREATE INDEX idx_realm_content_filters_realm ON realm.content_filters (realm_id);
CREATE INDEX idx_realm_content_filters_active ON realm.content_filters (realm_id, is_active) WHERE is_active = true;
-- =============================================================================
-- Realm-Level Moderation: Action Log
-- =============================================================================
CREATE TABLE realm.moderation_actions (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
realm_id UUID NOT NULL REFERENCES realm.realms(id) ON DELETE CASCADE,
action_type server.action_type NOT NULL,
target_user_id UUID REFERENCES auth.users(id) ON DELETE SET NULL,
moderator_id UUID REFERENCES auth.users(id) ON DELETE SET NULL,
reason TEXT NOT NULL,
evidence JSONB NOT NULL DEFAULT '[]',
metadata JSONB NOT NULL DEFAULT '{}',
created_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
COMMENT ON TABLE realm.moderation_actions IS 'Log of realm-level moderation actions';
CREATE INDEX idx_realm_moderation_actions_realm ON realm.moderation_actions (realm_id);
CREATE INDEX idx_realm_moderation_actions_target ON realm.moderation_actions (target_user_id);
CREATE INDEX idx_realm_moderation_actions_moderator ON realm.moderation_actions (moderator_id);
CREATE INDEX idx_realm_moderation_actions_type ON realm.moderation_actions (realm_id, action_type);
CREATE INDEX idx_realm_moderation_actions_created ON realm.moderation_actions (realm_id, created_at DESC);
COMMIT;

View file

@ -0,0 +1,306 @@
-- Chattyness Scene Schema Tables
-- PostgreSQL 18 with PostGIS
--
-- Scene-level runtime state: instances, members, spots, loose props, decorations
-- Load via: psql -f schema/tables/045_scene.sql
\set ON_ERROR_STOP on
BEGIN;
-- =============================================================================
-- Instances (renamed from realm.channels)
-- =============================================================================
-- Instances are ephemeral scene rooms where users can interact.
-- Each scene can have multiple instances (public default + private rooms).
-- =============================================================================
CREATE TABLE scene.instances (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
scene_id UUID NOT NULL REFERENCES realm.scenes(id) ON DELETE CASCADE,
instance_type scene.instance_type NOT NULL DEFAULT 'public',
name public.display_name,
created_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
max_users INTEGER NOT NULL DEFAULT 50 CHECK (max_users > 0 AND max_users <= 1000),
current_user_count INTEGER NOT NULL DEFAULT 0 CHECK (current_user_count >= 0),
expires_at TIMESTAMPTZ,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
COMMENT ON TABLE scene.instances IS 'Ephemeral scene rooms where users interact';
CREATE INDEX idx_scene_instances_scene ON scene.instances (scene_id);
CREATE INDEX idx_scene_instances_type ON scene.instances (scene_id, instance_type);
CREATE INDEX idx_scene_instances_expires ON scene.instances (expires_at) WHERE expires_at IS NOT NULL;
-- =============================================================================
-- Add FK from auth.guest_sessions to scene.instances
-- =============================================================================
-- guest_sessions.current_instance_id was added without FK in 030_realm.sql
-- Now we can add the constraint since scene.instances exists
-- =============================================================================
ALTER TABLE auth.guest_sessions
ADD CONSTRAINT fk_auth_guest_sessions_instance
FOREIGN KEY (current_instance_id) REFERENCES scene.instances(id) ON DELETE SET NULL;
-- =============================================================================
-- Instance Members (renamed from realm.channel_members)
-- =============================================================================
-- Users currently present in an instance with their positions.
-- Note: instance_id is actually scene_id in this system (scenes are used directly as instances).
-- =============================================================================
CREATE TABLE scene.instance_members (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
instance_id UUID NOT NULL REFERENCES realm.scenes(id) ON DELETE CASCADE,
user_id UUID REFERENCES auth.users(id) ON DELETE CASCADE,
guest_session_id UUID REFERENCES auth.guest_sessions(id) ON DELETE CASCADE,
position public.virtual_point NOT NULL DEFAULT ST_SetSRID(ST_MakePoint(400, 300), 0),
facing_direction SMALLINT NOT NULL DEFAULT 0 CHECK (facing_direction >= 0 AND facing_direction < 360),
is_moving BOOLEAN NOT NULL DEFAULT false,
is_afk BOOLEAN NOT NULL DEFAULT false,
joined_at TIMESTAMPTZ NOT NULL DEFAULT now(),
last_moved_at TIMESTAMPTZ NOT NULL DEFAULT now(),
CONSTRAINT chk_scene_instance_members_user_or_guest CHECK (
(user_id IS NOT NULL AND guest_session_id IS NULL) OR
(user_id IS NULL AND guest_session_id IS NOT NULL)
),
CONSTRAINT uq_scene_instance_members_user UNIQUE (instance_id, user_id),
CONSTRAINT uq_scene_instance_members_guest UNIQUE (instance_id, guest_session_id)
);
COMMENT ON TABLE scene.instance_members IS 'Users in an instance with positions';
CREATE INDEX idx_scene_instance_members_instance ON scene.instance_members (instance_id);
CREATE INDEX idx_scene_instance_members_user ON scene.instance_members (user_id) WHERE user_id IS NOT NULL;
CREATE INDEX idx_scene_instance_members_guest ON scene.instance_members (guest_session_id) WHERE guest_session_id IS NOT NULL;
CREATE INDEX idx_scene_instance_members_position ON scene.instance_members USING GIST (position);
-- =============================================================================
-- Instance Invites (renamed from realm.channel_invites)
-- =============================================================================
CREATE TABLE scene.instance_invites (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
instance_id UUID NOT NULL REFERENCES scene.instances(id) ON DELETE CASCADE,
invited_by UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
invited_user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
accepted_at TIMESTAMPTZ,
declined_at TIMESTAMPTZ,
expires_at TIMESTAMPTZ NOT NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
CONSTRAINT uq_scene_instance_invites UNIQUE (instance_id, invited_user_id),
CONSTRAINT chk_scene_instance_invites_not_self CHECK (invited_by != invited_user_id)
);
COMMENT ON TABLE scene.instance_invites IS 'Private instance invitations';
CREATE INDEX idx_scene_instance_invites_instance ON scene.instance_invites (instance_id);
CREATE INDEX idx_scene_instance_invites_user ON scene.instance_invites (invited_user_id);
CREATE INDEX idx_scene_instance_invites_pending ON scene.instance_invites (invited_user_id, expires_at)
WHERE accepted_at IS NULL AND declined_at IS NULL;
-- =============================================================================
-- Spots (moved from realm.spots)
-- =============================================================================
CREATE TABLE scene.spots (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
scene_id UUID NOT NULL REFERENCES realm.scenes(id) ON DELETE CASCADE,
name TEXT,
slug public.slug,
region GEOMETRY(GEOMETRY, 0) NOT NULL,
spot_type scene.spot_type NOT NULL DEFAULT 'normal',
destination_scene_id UUID REFERENCES realm.scenes(id) ON DELETE SET NULL,
destination_position GEOMETRY(POINT, 0),
current_state SMALLINT NOT NULL DEFAULT 0,
sort_order INTEGER NOT NULL DEFAULT 0,
is_visible BOOLEAN NOT NULL DEFAULT true,
is_active BOOLEAN NOT NULL DEFAULT true,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now(),
CONSTRAINT uq_scene_spots_slug UNIQUE (scene_id, slug)
);
COMMENT ON TABLE scene.spots IS 'Interactive regions in scenes';
CREATE INDEX idx_scene_spots_scene ON scene.spots (scene_id);
CREATE INDEX idx_scene_spots_region ON scene.spots USING GIST (region);
CREATE INDEX idx_scene_spots_active ON scene.spots (scene_id, is_active) WHERE is_active = true;
-- =============================================================================
-- Spot States (moved from realm.spot_states)
-- =============================================================================
CREATE TABLE scene.spot_states (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
spot_id UUID NOT NULL REFERENCES scene.spots(id) ON DELETE CASCADE,
state_number SMALLINT NOT NULL,
asset_path public.asset_path,
offset_x REAL NOT NULL DEFAULT 0,
offset_y REAL NOT NULL DEFAULT 0,
audio_id UUID REFERENCES server.audio(id) ON DELETE SET NULL,
CONSTRAINT uq_scene_spot_states UNIQUE (spot_id, state_number)
);
COMMENT ON TABLE scene.spot_states IS 'Visual configurations for spot states';
CREATE INDEX idx_scene_spot_states_spot ON scene.spot_states (spot_id);
-- =============================================================================
-- Scene Scripts (moved from realm.scene_scripts)
-- =============================================================================
CREATE TABLE scene.scripts (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
scene_id UUID NOT NULL REFERENCES realm.scenes(id) ON DELETE CASCADE,
name public.nonempty_text NOT NULL,
description TEXT,
source TEXT NOT NULL,
config JSONB NOT NULL DEFAULT '{}',
state JSONB NOT NULL DEFAULT '{}',
is_enabled BOOLEAN NOT NULL DEFAULT true,
run_on_enter BOOLEAN NOT NULL DEFAULT false,
handle_private_instances BOOLEAN NOT NULL DEFAULT true,
created_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
COMMENT ON TABLE scene.scripts IS 'Rhai scripts for scenes';
CREATE INDEX idx_scene_scripts_scene ON scene.scripts (scene_id);
CREATE INDEX idx_scene_scripts_enabled ON scene.scripts (scene_id, is_enabled) WHERE is_enabled = true;
-- =============================================================================
-- Loose Props (moved from props.loose_props)
-- =============================================================================
-- Props that exist at a position in an instance, not worn by anyone.
-- Can be picked up by users.
-- =============================================================================
CREATE TABLE scene.loose_props (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
instance_id UUID NOT NULL REFERENCES scene.instances(id) ON DELETE CASCADE,
-- Source of the prop (either server or realm library)
server_prop_id UUID REFERENCES server.props(id) ON DELETE CASCADE,
realm_prop_id UUID REFERENCES realm.props(id) ON DELETE CASCADE,
-- Position in scene (PostGIS point, SRID 0)
position public.virtual_point NOT NULL,
-- Who dropped it (NULL = spawned by system/script)
dropped_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
-- Auto-decay
expires_at TIMESTAMPTZ, -- NULL = permanent
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
-- Must reference exactly one source
CONSTRAINT chk_scene_loose_props_source CHECK (
(server_prop_id IS NOT NULL AND realm_prop_id IS NULL) OR
(server_prop_id IS NULL AND realm_prop_id IS NOT NULL)
)
);
COMMENT ON TABLE scene.loose_props IS 'Props dropped in instances that can be picked up';
COMMENT ON COLUMN scene.loose_props.position IS 'Location in scene as PostGIS point (SRID 0)';
COMMENT ON COLUMN scene.loose_props.expires_at IS 'When prop auto-decays (NULL = permanent)';
CREATE INDEX idx_scene_loose_props_instance ON scene.loose_props (instance_id);
CREATE INDEX idx_scene_loose_props_expires ON scene.loose_props (expires_at)
WHERE expires_at IS NOT NULL;
-- Spatial index for finding props near a position
CREATE INDEX idx_scene_loose_props_position ON scene.loose_props
USING GIST (position);
-- =============================================================================
-- Scene Decorations (moved from props.scene_decorations)
-- =============================================================================
-- Props placed in scenes by builders/owners as permanent decoration.
-- Can optionally be copied by users into their inventory.
-- =============================================================================
CREATE TABLE scene.decorations (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
scene_id UUID NOT NULL REFERENCES realm.scenes(id) ON DELETE CASCADE,
-- Source of the prop
server_prop_id UUID REFERENCES server.props(id) ON DELETE CASCADE,
realm_prop_id UUID REFERENCES realm.props(id) ON DELETE CASCADE,
-- Position and display
position public.virtual_point NOT NULL,
z_index INTEGER NOT NULL DEFAULT 0,
scale REAL NOT NULL DEFAULT 1.0 CHECK (scale > 0 AND scale <= 10),
rotation SMALLINT NOT NULL DEFAULT 0 CHECK (rotation >= 0 AND rotation < 360),
opacity public.percentage NOT NULL DEFAULT 1.0,
-- Interaction
is_copyable BOOLEAN NOT NULL DEFAULT false, -- Users can copy to inventory
click_action JSONB, -- Optional click behavior
-- Management
placed_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now(),
-- Must reference exactly one source
CONSTRAINT chk_scene_decorations_source CHECK (
(server_prop_id IS NOT NULL AND realm_prop_id IS NULL) OR
(server_prop_id IS NULL AND realm_prop_id IS NOT NULL)
)
);
COMMENT ON TABLE scene.decorations IS 'Permanent prop decorations placed in scenes';
COMMENT ON COLUMN scene.decorations.is_copyable IS 'If true, users can copy this prop to their inventory';
COMMENT ON COLUMN scene.decorations.click_action IS 'Optional JSON action config for click behavior';
CREATE INDEX idx_scene_decorations_scene ON scene.decorations (scene_id);
-- Spatial index for rendering props in view
CREATE INDEX idx_scene_decorations_position ON scene.decorations
USING GIST (position);
COMMIT;

View file

@ -0,0 +1,174 @@
-- Chattyness Chat Schema Tables
-- PostgreSQL 18
--
-- Messages, whispers, shouts, and reactions
-- Load via: psql -f schema/tables/050_chat.sql
--
-- NOTE: This table is designed for future partitioning by created_at.
-- When message volume grows, convert to a partitioned table:
-- 1. Rename chat.messages to chat.messages_old
-- 2. Create new partitioned chat.messages with PARTITION BY RANGE (created_at)
-- 3. Create monthly partitions (e.g., chat.messages_2025_01)
-- 4. Migrate data from old table
-- 5. Consider pg_partman extension for automatic partition management
-- 6. Add archive table for long-term storage of old partitions
\set ON_ERROR_STOP on
BEGIN;
-- =============================================================================
-- Instance Messages (Scene-wide chat)
-- =============================================================================
-- Messages visible to everyone in an instance.
-- =============================================================================
CREATE TABLE chat.messages (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
instance_id UUID NOT NULL REFERENCES scene.instances(id) ON DELETE CASCADE,
-- Sender (either user or guest)
user_id UUID REFERENCES auth.users(id) ON DELETE SET NULL,
guest_session_id UUID REFERENCES auth.guest_sessions(id) ON DELETE SET NULL,
-- Cached sender info (in case account deleted)
sender_name public.display_name NOT NULL,
-- Message content
message_type chat.message_type NOT NULL DEFAULT 'normal',
content TEXT NOT NULL,
-- Position when message was sent (for speech bubble placement)
position public.virtual_point,
-- Reply threading
reply_to_id UUID REFERENCES chat.messages(id) ON DELETE SET NULL,
-- Moderation
is_deleted BOOLEAN NOT NULL DEFAULT false,
deleted_by UUID REFERENCES auth.users(id) ON DELETE SET NULL,
deleted_at TIMESTAMPTZ,
-- Timestamps
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
-- Either user_id or guest_session_id must be set
CONSTRAINT chk_chat_messages_sender CHECK (
(user_id IS NOT NULL AND guest_session_id IS NULL) OR
(user_id IS NULL AND guest_session_id IS NOT NULL)
)
);
COMMENT ON TABLE chat.messages IS 'Instance messages (design supports future time-based partitioning)';
COMMENT ON COLUMN chat.messages.position IS 'Sender position when message sent (for speech bubbles)';
COMMENT ON COLUMN chat.messages.reply_to_id IS 'ID of message being replied to';
CREATE INDEX idx_chat_messages_instance_time ON chat.messages (instance_id, created_at DESC);
CREATE INDEX idx_chat_messages_user ON chat.messages (user_id, created_at DESC)
WHERE user_id IS NOT NULL;
CREATE INDEX idx_chat_messages_reply ON chat.messages (reply_to_id)
WHERE reply_to_id IS NOT NULL;
CREATE INDEX idx_chat_messages_created ON chat.messages (created_at DESC);
-- =============================================================================
-- Shouts (Server-wide broadcasts)
-- =============================================================================
-- Messages broadcast to all users on the server.
-- Typically limited to admins or special events.
-- =============================================================================
CREATE TABLE chat.shouts (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE SET NULL,
sender_name public.display_name NOT NULL,
content TEXT NOT NULL,
-- Targeting
target_realm_id UUID REFERENCES realm.realms(id) ON DELETE CASCADE, -- NULL = all realms
-- TTL for display
expires_at TIMESTAMPTZ,
created_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
COMMENT ON TABLE chat.shouts IS 'Server-wide or realm-wide broadcast messages';
COMMENT ON COLUMN chat.shouts.target_realm_id IS 'NULL = broadcast to all realms';
CREATE INDEX idx_chat_shouts_time ON chat.shouts (created_at DESC);
CREATE INDEX idx_chat_shouts_realm ON chat.shouts (target_realm_id, created_at DESC)
WHERE target_realm_id IS NOT NULL;
-- =============================================================================
-- Whispers (Private Direct Messages)
-- =============================================================================
-- Private messages between two users, cross-realm capable.
-- =============================================================================
CREATE TABLE chat.whispers (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
-- Sender and recipient
sender_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
recipient_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
content TEXT NOT NULL,
-- Read status
read_at TIMESTAMPTZ,
-- Moderation
is_deleted_by_sender BOOLEAN NOT NULL DEFAULT false,
is_deleted_by_recipient BOOLEAN NOT NULL DEFAULT false,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
CONSTRAINT chk_chat_whispers_not_self CHECK (sender_id != recipient_id)
);
COMMENT ON TABLE chat.whispers IS 'Private direct messages between users';
CREATE INDEX idx_chat_whispers_sender ON chat.whispers (sender_id, created_at DESC);
CREATE INDEX idx_chat_whispers_recipient ON chat.whispers (recipient_id, created_at DESC);
CREATE INDEX idx_chat_whispers_unread ON chat.whispers (recipient_id, read_at)
WHERE read_at IS NULL;
-- Composite index for conversation view between two users
CREATE INDEX idx_chat_whispers_conversation ON chat.whispers (
LEAST(sender_id, recipient_id),
GREATEST(sender_id, recipient_id),
created_at DESC
);
-- =============================================================================
-- Message Reactions
-- =============================================================================
-- Emoji reactions to channel messages.
-- =============================================================================
CREATE TABLE chat.reactions (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
message_id UUID NOT NULL REFERENCES chat.messages(id) ON DELETE CASCADE,
-- Reactor
user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
-- Reaction (emoji or predefined reaction code)
reaction TEXT NOT NULL CHECK (length(reaction) <= 32),
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
-- One reaction type per user per message
CONSTRAINT uq_chat_reactions UNIQUE (message_id, user_id, reaction)
);
COMMENT ON TABLE chat.reactions IS 'Emoji reactions to channel messages';
CREATE INDEX idx_chat_reactions_message ON chat.reactions (message_id);
CREATE INDEX idx_chat_reactions_user ON chat.reactions (user_id);
COMMIT;

View file

@ -0,0 +1,186 @@
-- Chattyness Audit Schema Tables
-- PostgreSQL 18
--
-- Audit trails and activity logging
-- Load via: psql -f schema/tables/080_audit.sql
\set ON_ERROR_STOP on
BEGIN;
-- =============================================================================
-- Audit Event Types
-- =============================================================================
CREATE TYPE audit.event_category AS ENUM (
'auth', -- Login, logout, password changes
'account', -- Profile updates, settings changes
'realm', -- Realm creation, modification, deletion
'scene', -- Scene creation, modification
'moderation', -- Moderation actions
'prop', -- Prop transfers, creation
'admin' -- Administrative actions
);
-- =============================================================================
-- Audit Log
-- =============================================================================
-- Immutable log of significant events for compliance and debugging.
-- =============================================================================
CREATE TABLE audit.events (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
-- Event classification
category audit.event_category NOT NULL,
action TEXT NOT NULL, -- Specific action (e.g., 'login', 'create_realm', 'ban_user')
-- Actor
user_id UUID REFERENCES auth.users(id) ON DELETE SET NULL,
session_id UUID, -- Auth session ID (not FK to allow historical queries)
ip_address INET,
user_agent TEXT,
-- Target (what was affected)
target_type TEXT, -- 'user', 'realm', 'scene', 'prop', etc.
target_id UUID,
-- Context
realm_id UUID REFERENCES realm.realms(id) ON DELETE SET NULL,
-- Event data
details JSONB NOT NULL DEFAULT '{}',
-- Outcome
success BOOLEAN NOT NULL DEFAULT true,
error_message TEXT,
-- Immutable timestamp
created_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
COMMENT ON TABLE audit.events IS 'Immutable audit log of significant system events';
COMMENT ON COLUMN audit.events.details IS 'JSON payload with event-specific data';
CREATE INDEX idx_audit_events_time ON audit.events (created_at DESC);
CREATE INDEX idx_audit_events_user ON audit.events (user_id, created_at DESC)
WHERE user_id IS NOT NULL;
CREATE INDEX idx_audit_events_category ON audit.events (category, created_at DESC);
CREATE INDEX idx_audit_events_target ON audit.events (target_type, target_id, created_at DESC)
WHERE target_id IS NOT NULL;
CREATE INDEX idx_audit_events_realm ON audit.events (realm_id, created_at DESC)
WHERE realm_id IS NOT NULL;
CREATE INDEX idx_audit_events_ip ON audit.events (ip_address, created_at DESC)
WHERE ip_address IS NOT NULL;
-- =============================================================================
-- Login History
-- =============================================================================
-- Dedicated table for login attempts (success and failure).
-- =============================================================================
CREATE TABLE audit.login_history (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
-- User (may be NULL for failed attempts with unknown username)
user_id UUID REFERENCES auth.users(id) ON DELETE SET NULL,
attempted_username TEXT,
-- Attempt details
success BOOLEAN NOT NULL,
failure_reason TEXT,
auth_provider auth.auth_provider,
-- Client info
ip_address INET NOT NULL,
user_agent TEXT,
created_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
COMMENT ON TABLE audit.login_history IS 'History of login attempts for security monitoring';
CREATE INDEX idx_audit_login_history_user ON audit.login_history (user_id, created_at DESC)
WHERE user_id IS NOT NULL;
CREATE INDEX idx_audit_login_history_ip ON audit.login_history (ip_address, created_at DESC);
CREATE INDEX idx_audit_login_history_failed ON audit.login_history (ip_address, created_at DESC)
WHERE success = false;
-- =============================================================================
-- Data Export Requests (GDPR compliance)
-- =============================================================================
CREATE TYPE audit.export_status AS ENUM (
'pending',
'processing',
'completed',
'failed',
'expired'
);
CREATE TABLE audit.data_exports (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
-- Request details
status audit.export_status NOT NULL DEFAULT 'pending',
requested_at TIMESTAMPTZ NOT NULL DEFAULT now(),
-- Processing
started_at TIMESTAMPTZ,
completed_at TIMESTAMPTZ,
error_message TEXT,
-- Result
download_path public.asset_path,
download_expires_at TIMESTAMPTZ,
downloaded_at TIMESTAMPTZ
);
COMMENT ON TABLE audit.data_exports IS 'User data export requests (GDPR compliance)';
CREATE INDEX idx_audit_data_exports_user ON audit.data_exports (user_id);
CREATE INDEX idx_audit_data_exports_status ON audit.data_exports (status)
WHERE status IN ('pending', 'processing');
-- =============================================================================
-- Account Deletion Requests (GDPR compliance)
-- =============================================================================
CREATE TYPE audit.deletion_status AS ENUM (
'pending',
'processing',
'completed',
'cancelled'
);
CREATE TABLE audit.deletion_requests (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
-- Request details
status audit.deletion_status NOT NULL DEFAULT 'pending',
reason TEXT,
requested_at TIMESTAMPTZ NOT NULL DEFAULT now(),
-- Grace period (user can cancel during this time)
scheduled_for TIMESTAMPTZ NOT NULL,
cancelled_at TIMESTAMPTZ,
-- Processing
completed_at TIMESTAMPTZ,
-- Confirmation
confirmed_at TIMESTAMPTZ,
confirmation_token_hash TEXT
);
COMMENT ON TABLE audit.deletion_requests IS 'Account deletion requests with grace period';
CREATE INDEX idx_audit_deletion_requests_user ON audit.deletion_requests (user_id);
CREATE INDEX idx_audit_deletion_requests_pending ON audit.deletion_requests (scheduled_for)
WHERE status = 'pending';
COMMIT;

View file

@ -0,0 +1,123 @@
-- Chattyness Updated At Triggers
-- PostgreSQL 18
--
-- Apply updated_at triggers to all tables with that column
-- Load via: psql -f schema/triggers/001_updated_at.sql
\set ON_ERROR_STOP on
BEGIN;
-- =============================================================================
-- Server Schema Triggers
-- =============================================================================
CREATE TRIGGER trg_server_config_updated_at
BEFORE UPDATE ON server.config
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
CREATE TRIGGER trg_server_staff_updated_at
BEFORE UPDATE ON server.staff
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
CREATE TRIGGER trg_server_props_updated_at
BEFORE UPDATE ON server.props
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
CREATE TRIGGER trg_server_audio_updated_at
BEFORE UPDATE ON server.audio
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
CREATE TRIGGER trg_server_bans_updated_at
BEFORE UPDATE ON server.bans
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
CREATE TRIGGER trg_server_mutes_updated_at
BEFORE UPDATE ON server.mutes
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
CREATE TRIGGER trg_server_content_filters_updated_at
BEFORE UPDATE ON server.content_filters
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
-- =============================================================================
-- Auth Schema Triggers
-- =============================================================================
CREATE TRIGGER trg_auth_users_updated_at
BEFORE UPDATE ON auth.users
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
CREATE TRIGGER trg_auth_inventory_updated_at
BEFORE UPDATE ON auth.inventory
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
CREATE TRIGGER trg_auth_avatars_updated_at
BEFORE UPDATE ON auth.avatars
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
CREATE TRIGGER trg_auth_active_avatars_updated_at
BEFORE UPDATE ON auth.active_avatars
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
-- =============================================================================
-- Realm Schema Triggers
-- =============================================================================
CREATE TRIGGER trg_realm_realms_updated_at
BEFORE UPDATE ON realm.realms
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
CREATE TRIGGER trg_realm_scenes_updated_at
BEFORE UPDATE ON realm.scenes
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
CREATE TRIGGER trg_realm_memberships_updated_at
BEFORE UPDATE ON realm.memberships
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
CREATE TRIGGER trg_realm_realm_scripts_updated_at
BEFORE UPDATE ON realm.realm_scripts
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
CREATE TRIGGER trg_realm_props_updated_at
BEFORE UPDATE ON realm.props
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
CREATE TRIGGER trg_realm_bans_updated_at
BEFORE UPDATE ON realm.bans
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
CREATE TRIGGER trg_realm_mutes_updated_at
BEFORE UPDATE ON realm.mutes
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
CREATE TRIGGER trg_realm_content_filters_updated_at
BEFORE UPDATE ON realm.content_filters
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
CREATE TRIGGER trg_realm_reports_updated_at
BEFORE UPDATE ON realm.reports
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
-- =============================================================================
-- Scene Schema Triggers
-- =============================================================================
CREATE TRIGGER trg_scene_instances_updated_at
BEFORE UPDATE ON scene.instances
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
CREATE TRIGGER trg_scene_spots_updated_at
BEFORE UPDATE ON scene.spots
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
CREATE TRIGGER trg_scene_scripts_updated_at
BEFORE UPDATE ON scene.scripts
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
CREATE TRIGGER trg_scene_decorations_updated_at
BEFORE UPDATE ON scene.decorations
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
COMMIT;

View file

@ -0,0 +1,26 @@
-- Chattyness User Initialization Trigger
-- PostgreSQL 18
--
-- Trigger to initialize new users with default props and avatar.
-- Load via: psql -f schema/triggers/002_user_init.sql
\set ON_ERROR_STOP on
BEGIN;
-- =============================================================================
-- User Registration Trigger
-- =============================================================================
-- Automatically initializes new users with default props and avatar
-- when they are inserted into auth.users.
-- =============================================================================
CREATE TRIGGER trg_auth_users_initialize
AFTER INSERT ON auth.users
FOR EACH ROW
EXECUTE FUNCTION auth.initialize_new_user_trigger();
COMMENT ON TRIGGER trg_auth_users_initialize ON auth.users IS
'Initialize new users with default props and avatar on registration';
COMMIT;

View file

@ -0,0 +1,225 @@
-- Chattyness Enumeration Types
-- PostgreSQL 18
--
-- All ENUM types used across the database
-- Load via: psql -f schema/types/001_enums.sql
\set ON_ERROR_STOP on
BEGIN;
-- =============================================================================
-- Server-Level Enums
-- =============================================================================
-- Server-wide reputation tiers (earned through time and achievements)
CREATE TYPE server.reputation_tier AS ENUM (
'guest', -- No account, temporary session
'member', -- Registered account
'established', -- 1 day + achievements
'trusted', -- 1 week + achievements
'elder' -- 1 month + achievements
);
COMMENT ON TYPE server.reputation_tier IS 'Server-wide reputation levels earned through time and activity';
-- Server-level roles
CREATE TYPE server.server_role AS ENUM (
'owner', -- Server owner, full control
'admin', -- Server administrator
'moderator' -- Cross-realm moderation
);
COMMENT ON TYPE server.server_role IS 'Administrative roles at the server level';
-- Audio category
CREATE TYPE server.audio_category AS ENUM (
'sound_effect',
'ambient',
'music',
'voice'
);
-- Reserved name type
CREATE TYPE server.reserved_name_type AS ENUM (
'username',
'realm_name',
'both'
);
-- Prop origin source (moved from props schema)
CREATE TYPE server.prop_origin AS ENUM (
'server_library', -- From server global library
'realm_library', -- From realm-specific library
'user_upload' -- User-uploaded content
);
COMMENT ON TYPE server.prop_origin IS 'Source of prop creation';
-- Prop transferability (moved from props schema)
CREATE TYPE server.transferability AS ENUM (
'transferable', -- Can be traded/given to others
'soulbound' -- Bound to original recipient
);
COMMENT ON TYPE server.transferability IS 'Whether prop can change ownership';
-- Prop portability (moved from props schema)
CREATE TYPE server.portability AS ENUM (
'portable', -- Can be used across realms
'realm_locked' -- Only usable in origin realm
);
COMMENT ON TYPE server.portability IS 'Whether prop can be used outside origin realm';
-- Avatar layer (moved from props schema)
CREATE TYPE server.avatar_layer AS ENUM (
'skin', -- Background layer (behind user, body/face)
'clothes', -- Middle layer (with user, worn items)
'accessories' -- Foreground layer (in front of user, held/attached items)
);
COMMENT ON TYPE server.avatar_layer IS 'Z-layer for avatar prop positioning: skin (behind), clothes (with), accessories (front)';
-- Emotion state for avatar overlays (moved from props schema)
CREATE TYPE server.emotion_state AS ENUM (
'neutral',
'happy',
'sad',
'angry',
'surprised',
'thinking',
'laughing',
'crying',
'love',
'confused',
'sleeping',
'wink'
);
COMMENT ON TYPE server.emotion_state IS 'Emotional expression overlay for avatars';
-- Moderation action type (moved from moderation schema)
CREATE TYPE server.action_type AS ENUM (
'warning',
'mute',
'kick',
'ban',
'unban',
'prop_removal',
'message_deletion'
);
COMMENT ON TYPE server.action_type IS 'Type of moderation action taken';
-- Report status (moved from moderation schema)
CREATE TYPE server.report_status AS ENUM (
'pending',
'investigating',
'resolved',
'dismissed'
);
COMMENT ON TYPE server.report_status IS 'Current state of a user report';
-- Ban scope (moved from moderation schema)
CREATE TYPE server.ban_scope AS ENUM (
'server', -- Banned from entire server
'realm' -- Banned from specific realm
);
COMMENT ON TYPE server.ban_scope IS 'Scope of ban enforcement';
-- Content filter action (moved from moderation schema)
CREATE TYPE server.filter_action AS ENUM (
'block', -- Prevent message from sending
'flag', -- Allow but flag for review
'replace' -- Replace matched content
);
COMMENT ON TYPE server.filter_action IS 'Action to take when content filter matches';
-- =============================================================================
-- Authentication Enums
-- =============================================================================
-- User account tags for feature gating and access control
CREATE TYPE auth.user_tag AS ENUM (
'guest',
'unvalidated',
'validated_email',
'validated_social',
'validated_oauth2',
'premium'
);
COMMENT ON TYPE auth.user_tag IS 'User account tags for feature gating and access control';
-- User account status
CREATE TYPE auth.account_status AS ENUM (
'active',
'suspended',
'banned',
'deleted'
);
COMMENT ON TYPE auth.account_status IS 'Current state of user account';
-- Authentication provider
CREATE TYPE auth.auth_provider AS ENUM (
'local', -- Username/password
'oauth_google',
'oauth_discord',
'oauth_github'
);
COMMENT ON TYPE auth.auth_provider IS 'Authentication method used for account';
-- =============================================================================
-- Realm Enums
-- =============================================================================
-- Realm privacy settings
CREATE TYPE realm.realm_privacy AS ENUM (
'public', -- Anyone can enter
'unlisted', -- Not in directory, but accessible via link
'private' -- Invite only
);
COMMENT ON TYPE realm.realm_privacy IS 'Visibility and access level for realms';
-- Realm-level roles
CREATE TYPE realm.realm_role AS ENUM (
'owner', -- Full control of realm
'moderator', -- Moderation within realm
'builder', -- Can edit scenes
'member' -- Standard member
);
COMMENT ON TYPE realm.realm_role IS 'Permission roles within a specific realm';
-- Scene dimension mode
CREATE TYPE realm.dimension_mode AS ENUM (
'fixed', -- Fixed dimensions, scrollable
'viewport' -- Scales to viewport
);
COMMENT ON TYPE realm.dimension_mode IS 'How scene dimensions are handled';
-- =============================================================================
-- Scene Enums
-- =============================================================================
-- Instance type (renamed from realm.channel_type)
CREATE TYPE scene.instance_type AS ENUM (
'public', -- Default public instance
'private' -- Invite-only instance
);
COMMENT ON TYPE scene.instance_type IS 'Instance visibility and access type';
-- Spot type (interactive regions) - moved from realm schema
CREATE TYPE scene.spot_type AS ENUM (
'normal', -- Generic interactive region
'door', -- Navigates to another scene
'trigger' -- Fires on enter/exit, no click needed
);
COMMENT ON TYPE scene.spot_type IS 'Type of interactive spot behavior';
-- =============================================================================
-- Chat Enums
-- =============================================================================
-- Message type
CREATE TYPE chat.message_type AS ENUM (
'normal', -- Standard chat message
'emote', -- Action/emote (/me)
'shout', -- Server-wide broadcast
'whisper', -- Private direct message
'system' -- System announcement
);
COMMENT ON TYPE chat.message_type IS 'Category of chat message';
COMMIT;

View file

@ -0,0 +1,74 @@
-- Chattyness Domain Types
-- PostgreSQL 18 with PostGIS
--
-- Custom domain types with constraints for data validation
-- Uses PostGIS GEOMETRY with SRID 0 for virtual 2D coordinate system
-- Load via: psql -f schema/types/002_domains.sql
\set ON_ERROR_STOP on
BEGIN;
-- =============================================================================
-- Common Domains
-- =============================================================================
-- Percentage stored as REAL (0.0 to 1.0)
CREATE DOMAIN public.percentage AS REAL
CHECK (VALUE >= 0.0 AND VALUE <= 1.0);
COMMENT ON DOMAIN public.percentage IS 'Percentage value stored as 0.0-1.0 REAL';
-- Non-empty text (prevents empty strings where we need content)
CREATE DOMAIN public.nonempty_text AS TEXT
CHECK (length(trim(VALUE)) > 0);
COMMENT ON DOMAIN public.nonempty_text IS 'Text that cannot be empty or whitespace-only';
-- Username format (lowercase alphanumeric with underscores)
CREATE DOMAIN auth.username AS TEXT
CHECK (VALUE ~ '^[a-z][a-z0-9_]{2,29}$');
COMMENT ON DOMAIN auth.username IS 'Valid username: 3-30 chars, starts with letter, alphanumeric and underscores';
-- Display name (visible name, more permissive)
CREATE DOMAIN public.display_name AS TEXT
CHECK (length(trim(VALUE)) BETWEEN 1 AND 50);
COMMENT ON DOMAIN public.display_name IS 'Visible display name, 1-50 characters';
-- Slug for URLs (realm names, scene names)
CREATE DOMAIN public.slug AS TEXT
CHECK (VALUE ~ '^[a-z0-9][a-z0-9-]{1,48}[a-z0-9]$' OR VALUE ~ '^[a-z0-9]{1,2}$');
COMMENT ON DOMAIN public.slug IS 'URL-safe slug: 1-50 chars, lowercase alphanumeric and hyphens';
-- Email address (basic validation)
CREATE DOMAIN auth.email AS TEXT
CHECK (VALUE ~ '^[^@\s]+@[^@\s]+\.[^@\s]+$');
COMMENT ON DOMAIN auth.email IS 'Basic email address format validation';
-- Color as hex string
CREATE DOMAIN public.hex_color AS TEXT
CHECK (VALUE ~ '^#[0-9a-fA-F]{6}([0-9a-fA-F]{2})?$');
COMMENT ON DOMAIN public.hex_color IS 'Hex color code (#RRGGBB or #RRGGBBAA)';
-- URL validation (basic)
CREATE DOMAIN public.url AS TEXT
CHECK (VALUE ~ '^https?://[^\s]+$');
COMMENT ON DOMAIN public.url IS 'HTTP/HTTPS URL';
-- Asset path (relative path within storage)
CREATE DOMAIN public.asset_path AS TEXT
CHECK (VALUE ~ '^[a-zA-Z0-9/_.-]+$' AND length(VALUE) <= 500);
COMMENT ON DOMAIN public.asset_path IS 'Valid asset storage path';
-- =============================================================================
-- PostGIS Spatial Domains (SRID 0 for virtual 2D world)
-- =============================================================================
-- Point in 2D virtual space (user position, prop position)
-- Using SRID 0 for non-geographic Cartesian coordinate system
CREATE DOMAIN public.virtual_point AS GEOMETRY(POINT, 0);
COMMENT ON DOMAIN public.virtual_point IS 'Point in 2D virtual space (SRID 0 Cartesian coordinates)';
-- 2D bounding box for scenes (defines playable area)
CREATE DOMAIN public.scene_bounds AS GEOMETRY(POLYGON, 0);
COMMENT ON DOMAIN public.scene_bounds IS 'Rectangular bounding box defining scene dimensions';
COMMIT;