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

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;