This repository has been archived on 2024-07-18. You can view files and clone it, but cannot push or open issues or pull requests.
lwb6/legacyworlds-server/legacyworlds-server-data/db-structure/parts/functions/020-naming-functions.sql

623 lines
No EOL
14 KiB
PL/PgSQL

-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Names management
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
--
-- Creates or returns an empire name
--
-- Parameters:
-- uid Credentials identifier
-- nnm Empire name to create or return
--
-- Returns:
-- +X the new empire name's identifier;
-- -1 if the name is banned
-- -2 if the name already exists and is "owned" by another player
--
CREATE OR REPLACE FUNCTION naming.goc_empire_name( uid INT, nnm TEXT )
RETURNS INT
STRICT
VOLATILE
SECURITY INVOKER
AS $$
DECLARE
nid INT;
BEGIN
PERFORM name FROM naming.banned_names WHERE name = lower( nnm );
IF FOUND
THEN
RETURN -1;
END IF;
BEGIN
INSERT INTO naming.empire_names ( owner_id , name )
VALUES ( uid , nnm )
RETURNING id INTO nid;
EXCEPTION
WHEN unique_violation THEN
SELECT INTO nid id , owner_id FROM naming.empire_names
WHERE lower( name ) = lower( nnm ) AND owner_id = uid;
IF NOT FOUND THEN
RETURN -2;
END IF;
END;
RETURN nid;
END;
$$ LANGUAGE plpgsql;
--
-- Generates a random name.
--
-- Parameters:
-- len Length of the random name
--
-- Returns:
-- the random name
--
CREATE OR REPLACE FUNCTION naming.randomize( len INT )
RETURNS TEXT
STRICT
VOLATILE
SECURITY INVOKER
AS $$
DECLARE
i INT;
result TEXT;
ok_chars CHAR ARRAY[16] := ARRAY['0','1','2','3','4','5','6','7','8','9','A','B','C','D','E','F'];
BEGIN
result := '';
FOR i IN 1 .. len
LOOP
result := result || ok_chars[1 + floor( random() * 16 )::int];
END LOOP;
RETURN result;
END;
$$ LANGUAGE plpgsql;
--
-- Generates a new map name
--
-- Parameters:
-- prefix Prefix of the map name
--
-- Returns:
-- the new name's identifier
--
CREATE OR REPLACE FUNCTION naming.create_map_name( prefix TEXT )
RETURNS INT
STRICT
VOLATILE
SECURITY INVOKER
AS $$
DECLARE
len INT;
nid INT;
BEGIN
len := 20 - ( length( prefix ) + 3 );
LOOP
BEGIN
INSERT INTO naming.map_names( name )
VALUES ( prefix || '-[' || naming.randomize( len ) || ']' )
RETURNING id INTO nid;
RETURN nid;
EXCEPTION
WHEN unique_violation THEN
-- Do nothing
END;
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Resets a map name to a random value
--
-- Parameters:
-- nid Identifier of the name to reset
-- prefix Prefix of the new name
--
CREATE OR REPLACE FUNCTION naming.reset_map_name( nid INT , prefix TEXT )
RETURNS TEXT
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
len INT;
n_name TEXT;
BEGIN
len := 20 - ( length( prefix ) + 3 );
LOOP
BEGIN
n_name := prefix || '-[' || naming.randomize( len ) || ']';
UPDATE naming.map_names SET name = n_name WHERE id = nid;
RETURN n_name;
EXCEPTION
WHEN unique_violation THEN
-- Do nothing
END;
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Resets an empire name
--
-- Parameters:
-- nid Identifier of the name to reset
-- prefix Prefix of the new name
--
CREATE OR REPLACE FUNCTION naming.reset_empire_name( nid INT , prefix TEXT )
RETURNS TEXT
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
len INT;
n_name TEXT;
BEGIN
len := 20 - length( prefix );
LOOP
BEGIN
n_name := prefix || naming.randomize( len );
UPDATE naming.empire_names SET name = n_name WHERE id = nid;
RETURN n_name;
EXCEPTION
WHEN unique_violation THEN
-- Do nothing
END;
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Forcibly changes a map name
--
-- Parameters:
-- nid Identifier of the name
-- uid Identifier of the user who's changing the name
-- nnm New name
--
-- Returns:
-- 0 Success
-- -1 Banned name
-- -2 Unavailable name
--
CREATE OR REPLACE FUNCTION naming.change_map_name( nid INT , uid INT , nnm TEXT )
RETURNS INT
STRICT
VOLATILE
SECURITY INVOKER
AS $$
BEGIN
-- Is the name banned?
PERFORM name FROM naming.banned_names WHERE name = lower( nnm );
IF FOUND
THEN
RETURN -1;
END IF;
-- Are we *actually* changing it?
PERFORM id FROM naming.map_names
WHERE id = nid AND name <> nnm
FOR UPDATE;
IF NOT FOUND
THEN
RETURN 0;
END IF;
-- Rename it
BEGIN
UPDATE naming.map_names SET name = nnm
WHERE id = nid;
EXCEPTION
WHEN unique_violation THEN
RETURN -2;
END;
-- Update change record
BEGIN
INSERT INTO naming.changed_map_names (name_id,named_by)
VALUES (nid , uid);
EXCEPTION
WHEN unique_violation THEN
DELETE FROM naming.validated_map_names WHERE name_id = nid;
UPDATE naming.changed_map_names
SET named_at = now( ), named_by = uid
WHERE name_id = nid;
END;
RETURN 0;
END;
$$ LANGUAGE plpgsql;
--
-- Changes a map name if enough time has elapsed
--
-- Parameters:
-- nid Identifier of the name
-- uid Identifier of the user who's changing the name
-- nnm New name
-- mtime Minimal time between renames
--
-- Returns:
-- 0 Success
-- 1 Banned name
-- 2 Unavailable name
-- 3 Too early
--
CREATE OR REPLACE FUNCTION naming.change_map_name( nid INT , uid INT , nnm TEXT , mtime INTERVAL )
RETURNS INT
STRICT
VOLATILE
SECURITY INVOKER
AS $$
DECLARE
lren TIMESTAMP WITHOUT TIME ZONE;
BEGIN
-- Is the name banned?
PERFORM name FROM naming.banned_names WHERE name = lower( nnm );
IF FOUND
THEN
RETURN 1;
END IF;
-- Are we *actually* changing it?
PERFORM id FROM naming.map_names
WHERE id = nid AND name <> nnm
FOR UPDATE;
IF NOT FOUND
THEN
RETURN 0;
END IF;
-- Check/lock change record
SELECT INTO lren named_at FROM naming.changed_map_names
WHERE name_id = nid FOR UPDATE;
IF FOUND AND lren + mtime > now()
THEN
RETURN 3;
END IF;
-- Rename it
BEGIN
UPDATE naming.map_names SET name = nnm
WHERE id = nid;
EXCEPTION
WHEN unique_violation THEN
RETURN 2;
END;
-- Update change record
BEGIN
INSERT INTO naming.changed_map_names (name_id,named_by)
VALUES (nid , uid);
EXCEPTION
WHEN unique_violation THEN
DELETE FROM naming.validated_map_names WHERE name_id = nid;
UPDATE naming.changed_map_names
SET named_at = now( ), named_by = uid
WHERE name_id = nid;
END;
RETURN 0;
END;
$$ LANGUAGE plpgsql;
--
-- Marks a map name as validated
--
-- Paramaters:
-- a_id Administrator identifier
-- n_id Name identifier
--
CREATE OR REPLACE FUNCTION naming.validate_map_name( a_id INT , n_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
nm TEXT;
BEGIN
SELECT INTO nm name
FROM naming.map_names
WHERE id = n_id;
IF NOT FOUND
THEN
RETURN;
END IF;
INSERT INTO naming.validated_map_names( name_id , validated_by )
VALUES ( n_id , a_id );
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Map name #' || n_id || ' (' || nm || ') validated' );
EXCEPTION
WHEN unique_violation OR foreign_key_violation THEN
-- Do nothing
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION naming.validate_map_name( INT , INT ) TO :dbuser;
--
-- Rejects a map name
--
-- Parameters:
-- a_id Administrator identifier
-- n_id Name identifier
-- ban_name Whether the old name should be banned
--
CREATE OR REPLACE FUNCTION naming.reject_map_name( a_id INT , n_id INT , ban_name BOOLEAN )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
c_name TEXT;
n_name TEXT;
u_id INT;
warned BOOLEAN;
n_warnings INT;
BEGIN
-- Get current name and player ID
SELECT INTO c_name , u_id n.name , cn.named_by
FROM naming.map_names n
INNER JOIN naming.changed_map_names cn ON cn.name_id = n.id
WHERE n.id = n_id
FOR UPDATE;
IF NOT FOUND
THEN
RETURN;
END IF;
-- Forcibly rename the planet
n_name := naming.reset_map_name( n_id , 'P' );
-- Update battle
PERFORM battles.rename_planet( n_id , n_name );
-- Send warning
SELECT INTO warned , n_warnings * FROM admin.give_player_warning( a_id , u_id );
-- Send internal message
PERFORM events.map_name_rejected_event( u_id , n_id , c_name , n_name , warned , n_warnings );
PERFORM msgs.deliver_internal( );
-- Add validation and log entry
DELETE FROM naming.validated_map_names WHERE name_id = n_id;
INSERT INTO naming.validated_map_names( name_id , validated_by )
VALUES ( n_id , a_id );
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Map name #' || n_id || ' (' || c_name || ') rejected' );
-- Ban old name
IF ban_name
THEN
BEGIN
INSERT INTO naming.banned_names ( name , added_by )
VALUES ( lower( c_name ) , a_id );
EXCEPTION
WHEN unique_violation THEN
-- Do nothing
END;
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Name "' || lower( c_name ) || '" banned' );
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION naming.reject_map_name( INT , INT , BOOLEAN ) TO :dbuser;
--
-- Rejects an empire's name
--
-- a_id Administrator identifier
-- n_id Name identifier
-- ban_name Whether the old name should be banned
--
CREATE OR REPLACE FUNCTION naming.reject_empire_name( a_id INT , n_id INT , ban_name BOOLEAN )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
c_name TEXT;
n_name TEXT;
u_id INT;
warned BOOLEAN;
n_warnings INT;
BEGIN
-- Get current name and player ID
SELECT INTO c_name , u_id n.name , n.owner_id
FROM naming.empire_names n WHERE n.id = n_id
FOR UPDATE;
IF NOT FOUND
THEN
RETURN;
END IF;
-- Forcibly rename the empire
n_name := naming.reset_empire_name( n_id , 'Rude Empire ' );
-- Update battles
UPDATE battles.empires SET name = n_name WHERE empire_id = n_id;
UPDATE msgs.senders SET name = n_name WHERE sender_type = 'EMP' AND empire_id = n_id;
UPDATE msgs.receivers SET name = n_name WHERE receiver_type = 'EMP' AND empire_id = n_id;
-- Send warning
SELECT INTO warned , n_warnings * FROM admin.give_player_warning( a_id , u_id );
-- Send internal message
PERFORM events.empire_name_rejected_event( n_id , c_name , n_name , warned , n_warnings );
PERFORM msgs.deliver_internal( );
-- Add log entry
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Empire name #' || n_id || ' (' || c_name || ') forcibly renamed' );
-- Ban name if requested
IF ban_name
THEN
BEGIN
INSERT INTO naming.banned_names ( name , added_by )
VALUES ( lower( c_name ) , a_id );
EXCEPTION
WHEN unique_violation THEN
-- Do nothing
END;
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Name "' || lower( c_name ) || '" banned' );
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION naming.reject_empire_name( INT , INT , BOOLEAN ) TO :dbuser;
--
-- Forcibly disbands an alliance, sending a warning to its leader
--
-- Parameters:
-- a_id Administrator identifier
-- al_id Alliance identifier
--
CREATE OR REPLACE FUNCTION naming.reject_alliance_name( a_id INT , al_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
e_id INT;
u_id INT;
c_name TEXT;
warned BOOLEAN;
n_warnings INT;
BEGIN
-- Get current name, leader ID and player ID
SELECT INTO c_name , e_id , u_id a.tag , a.leader_id , n.owner_id
FROM emp.alliances a
INNER JOIN naming.empire_names n ON n.id = a.leader_id
WHERE a.id = al_id FOR UPDATE;
IF NOT FOUND
THEN
RETURN;
END IF;
-- Disband the alliance
PERFORM emp.leave_alliance( e_id );
-- Send warning
SELECT INTO warned , n_warnings * FROM admin.give_player_warning( a_id , u_id );
-- Send internal message
PERFORM events.alliance_name_rejected_event( e_id , c_name , warned , n_warnings );
PERFORM msgs.deliver_internal( );
-- Add log entry
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Alliance ' || c_name || ' disbanded' );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION naming.reject_alliance_name( INT , INT ) TO :dbuser;
--
-- Allows a modified map name to be renamed earlier than it should
--
-- Parameters:
-- a_id Administrator identifier
-- n_id Name identifier
--
CREATE OR REPLACE FUNCTION naming.allow_map_name_change( a_id INT , n_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
nm TEXT;
mdelay BIGINT;
BEGIN
SELECT INTO nm n.name
FROM naming.map_names n
INNER JOIN naming.changed_map_names c ON c.name_id = n.id
INNER JOIN naming.validated_map_names v ON v.name_id = n.id
WHERE id = n_id
FOR UPDATE;
IF NOT FOUND
THEN
RETURN;
END IF;
mdelay := 1 + floor( sys.get_constant( 'map.names.minDelay' ) * sys.get_constant( 'map.names.minDelay.units' ) )::BIGINT;
UPDATE naming.changed_map_names
SET named_at = now() - ( mdelay::BIGINT || 's' )::INTERVAL
WHERE name_id = n_id;
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Allowed early modification of map name #' || n_id || ' (' || nm || ')' );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION naming.allow_map_name_change( INT , INT ) TO :dbuser;
--
-- Names and status
--
CREATE TYPE name_status
AS ENUM( 'MAP_PENDING' , 'MAP_VALIDATED' , 'EMPIRE' , 'ALLIANCE' );
CREATE VIEW naming.names_view
AS SELECT en.id , en.name , ( CASE WHEN e IS NULL THEN NULL ELSE '' END )::TEXT AS extra ,
en.owner_id AS account , 'EMPIRE'::name_status AS status
FROM naming.empire_names en
LEFT OUTER JOIN emp.empires e ON en.id = e.name_id
UNION ALL SELECT n.id , n.name , NULL::TEXT AS extra , c.named_by AS account ,
( CASE
WHEN v.name_id IS NULL THEN 'MAP_PENDING'
ELSE 'MAP_VALIDATED'
END )::name_status AS status
FROM naming.map_names n
INNER JOIN naming.changed_map_names c ON c.name_id = n.id
LEFT OUTER JOIN naming.validated_map_names v ON v.name_id = c.name_id
UNION ALL SELECT a.id , a.tag AS name , a.name AS extra , l.owner_id AS account ,
'ALLIANCE'::name_status AS status
FROM emp.alliances a
INNER JOIN naming.empire_names l ON l.id = a.leader_id;
GRANT SELECT ON naming.names_view TO :dbuser;
CREATE VIEW naming.names_status_view
AS SELECT status , count(*) AS count
FROM naming.names_view
GROUP BY status;
GRANT SELECT ON naming.names_status_view TO :dbuser;