database schema adjustments to server/realm/scene
This commit is contained in:
parent
a102c96bb4
commit
09590edd95
79 changed files with 7100 additions and 100 deletions
47
db/schema/tables/010_server.sql
Normal file
47
db/schema/tables/010_server.sql
Normal 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;
|
||||
782
db/schema/tables/020_auth.sql
Normal file
782
db/schema/tables/020_auth.sql
Normal 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;
|
||||
422
db/schema/tables/030_realm.sql
Normal file
422
db/schema/tables/030_realm.sql
Normal 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;
|
||||
306
db/schema/tables/045_scene.sql
Normal file
306
db/schema/tables/045_scene.sql
Normal 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;
|
||||
174
db/schema/tables/050_chat.sql
Normal file
174
db/schema/tables/050_chat.sql
Normal 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;
|
||||
186
db/schema/tables/080_audit.sql
Normal file
186
db/schema/tables/080_audit.sql
Normal 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;
|
||||
Loading…
Add table
Add a link
Reference in a new issue