-- LegacyWorlds Beta 6 -- PostgreSQL database scripts -- -- Preference definitions and values functions -- -- Copyright(C) 2004-2010, DeepClone Development -- -------------------------------------------------------- -- -- Preferences view -- CREATE VIEW users.preferences_view AS SELECT acc.credentials_id AS account_id , grp.name AS group_name , grpn.translated_string AS group_i18n_name , pref.name AS pref_name , prefn.translated_string AS pref_i18n_name , prefd.translated_string AS pref_i18n_description , pref.java_type AS pref_type , ( CASE ( upr.pref_value IS NULL ) WHEN TRUE THEN pref.default_value ELSE upr.pref_value END ) AS value FROM users.active_accounts acc INNER JOIN users.credentials cred ON cred.address_id = acc.credentials_id CROSS JOIN defs.preference_definitions pref INNER JOIN defs.preference_groups grp ON grp.id = pref.group_id INNER JOIN defs.translations grpn ON grpn.lang_id = cred.language_id AND grpn.string_id = grp.display_id INNER JOIN defs.translations prefn ON prefn.lang_id = cred.language_id AND prefn.string_id = pref.disp_name_id INNER JOIN defs.translations prefd ON prefd.lang_id = cred.language_id AND prefd.string_id = pref.disp_desc_id LEFT OUTER JOIN users.preferences upr ON upr.definition_id = pref.id AND upr.account_id = acc.credentials_id ORDER BY acc.credentials_id , grp.name , pref.name; GRANT SELECT ON users.preferences_view TO :dbuser; -- -- Definitions view -- CREATE VIEW defs.preferences_view AS SELECT grp.name AS group_name , gds.name AS group_display , pref.name AS name , pns.name AS d_name , pds.name AS d_desc , pref.java_type AS java_type , pref.default_value AS default_value FROM defs.preference_definitions pref INNER JOIN defs.preference_groups grp ON grp.id = pref.group_id INNER JOIN defs.strings gds ON gds.id = grp.display_id INNER JOIN defs.strings pns ON pns.id = pref.disp_name_id INNER JOIN defs.strings pds ON pds.id = pref.disp_desc_id ORDER BY grp.name , pref.name; GRANT SELECT ON defs.preferences_view TO :dbuser; -- -- Group registration -- -- Parameters: -- g_name Group name -- g_display Display name identifier -- -- Returns: -- success Whether the operation was successful or not -- CREATE OR REPLACE FUNCTION defs.uoc_preference_group( g_name TEXT , g_display TEXT , OUT success BOOLEAN ) STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE did INT; BEGIN SELECT INTO did id FROM defs.strings WHERE name = g_display; success := FOUND; IF NOT success THEN RETURN; END IF; LOOP UPDATE defs.preference_groups SET display_id = did WHERE name = g_name; EXIT WHEN FOUND; BEGIN INSERT INTO defs.preference_groups (name , display_id) VALUES (g_name , did); EXIT; EXCEPTION WHEN unique_violation THEN -- Do nothing. END; END LOOP; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION defs.uoc_preference_group( TEXT , TEXT ) TO :dbuser; -- -- Preference definition registration -- -- Parameters: -- g_name Group name -- p_name Preference name -- d_name Display name identifier -- d_desc Display description identifier -- j_type Java type name -- d_val Serialised default value -- -- Returns: -- err_code Error code -- 0 on success -- 1 if the group is missing -- 2 if one of the strings is missing -- 3 if the definition exists but has a different type -- CREATE OR REPLACE FUNCTION defs.uoc_preference( g_name TEXT , p_name TEXT , d_name TEXT , d_desc TEXT , j_type TEXT , d_val TEXT, OUT err_code INT ) STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE g_id INT; n_id INT; d_id INT; p_id INT; o_type TEXT; BEGIN -- Get group identifier SELECT INTO g_id id FROM defs.preference_groups WHERE name = g_name; IF NOT FOUND THEN err_code := 1; RETURN; END IF; -- Get strings SELECT INTO n_id id FROM defs.strings WHERE name = d_name; SELECT INTO d_id id FROM defs.strings WHERE name = d_desc; IF n_id IS NULL OR d_id IS NULL THEN err_code := 2; RETURN; END IF; LOOP -- Try updating SELECT INTO p_id , o_type id , java_type FROM defs.preference_definitions WHERE name = p_name FOR UPDATE; IF FOUND THEN -- Make sure the type didn't change IF o_type <> j_type THEN err_code := 3; ELSE err_code := 0; UPDATE defs.preference_definitions SET disp_name_id = n_id , disp_desc_id = d_id , group_id = g_id WHERE id = p_id; END IF; EXIT; END IF; -- Try inserting BEGIN INSERT INTO defs.preference_definitions (group_id , name , disp_name_id , disp_desc_id , java_type , default_value ) VALUES ( g_id , p_name , n_id , d_id , j_type , d_val ); err_code := 0; EXIT; EXCEPTION WHEN unique_violation THEN -- Do nothing END; END LOOP; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION defs.uoc_preference( TEXT , TEXT , TEXT , TEXT , TEXT , TEXT ) TO :dbuser; -- -- Set a preference's default value -- -- Parameters: -- a_id Administrator identifier -- p_name Preference name -- p_val Preference default value -- CREATE OR REPLACE FUNCTION defs.set_preference_default( a_id INT , p_name TEXT , p_val TEXT ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ BEGIN UPDATE defs.preference_definitions SET default_value = p_val WHERE name = p_name; IF FOUND THEN PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Changed default value of preference "' || p_name || '" to "' || p_val || '"' ); END IF; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION defs.set_preference_default( INT , TEXT , TEXT ) TO :dbuser; -- -- Resets an account's preferences -- -- Parameters: -- a_id Account identifier -- CREATE OR REPLACE FUNCTION users.reset_preferences( a_id INT ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ BEGIN DELETE FROM users.preferences WHERE account_id = a_id; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION users.reset_preferences( INT ) TO :dbuser; -- -- Sets a preference -- -- Parameters: -- a_id Account identifier -- p_name Preference name -- p_val New value -- CREATE OR REPLACE FUNCTION users.set_preference( a_id INT , p_name TEXT , p_val TEXT ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE p_id INT; BEGIN -- Get preference identifier SELECT INTO p_id id FROM defs.preference_definitions WHERE name = p_name; IF NOT FOUND THEN RETURN; END IF; -- Update or add preference LOOP UPDATE users.preferences SET pref_value = p_val WHERE account_id = a_id AND definition_id = p_id; EXIT WHEN FOUND; BEGIN INSERT INTO users.preferences( account_id , definition_id , pref_value ) VALUES( a_id , p_id , p_val ); EXIT; EXCEPTION WHEN unique_violation THEN -- Do nothing END; END LOOP; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION users.set_preference( INT , TEXT , TEXT ) TO :dbuser;