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
197
db/schema/functions/003_admin_restore_props.sql
Normal file
197
db/schema/functions/003_admin_restore_props.sql
Normal 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;
|
||||
Loading…
Add table
Add a link
Reference in a new issue