Database definition & tests organisation

* The main loader script has been updated to generate the list of files
it needs to load automatically. As a consequence, files that contained
manually-maintained lists of scripts have been removed, and definition
directories have been renamed accordingly.

* PostgreSQL extension loading and configuration has been moved to a
separate script to be loaded automatically in the main transaction.

* Data and function definition scripts that had the -data or -functions
suffix have been renamed (the suffix is unnecessary).

* Unit tests have been reorganised to follow the definition's structure.

* Documentation has been improved
This commit is contained in:
Emmanuel BENOîT 2012-01-06 11:19:19 +01:00
parent b054a379a9
commit e50775ec76
112 changed files with 78 additions and 144 deletions

View file

@ -0,0 +1,128 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Definitions management functions
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
--
-- Creates or updates a language definition
--
-- Parameters:
-- lid Language identifier
-- lnm Language name
--
CREATE OR REPLACE FUNCTION defs.uoc_language( lid TEXT , lnm TEXT )
RETURNS VOID
STRICT
VOLATILE
SECURITY DEFINER
AS $$
BEGIN
INSERT INTO defs.languages ( language , name )
VALUES ( lower( lid ) , lnm );
EXCEPTION
WHEN unique_violation THEN
UPDATE defs.languages SET name = lnm
WHERE language = lower( lid );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION defs.uoc_language( TEXT , TEXT ) TO :dbuser;
CREATE OR REPLACE FUNCTION defs.uoc_language( lid TEXT , lnm TEXT , a_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
BEGIN
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Updating language ' || lid );
PERFORM defs.uoc_language( lid , lnm );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION defs.uoc_language( TEXT, TEXT , INT ) TO :dbuser;
--
-- Creates or updates a translation
--
-- Parameters:
-- lid Language identifier
-- sid String identifier
-- txt Translation
--
CREATE OR REPLACE FUNCTION defs.uoc_translation( lid TEXT , sid TEXT , txt TEXT )
RETURNS VOID
STRICT
VOLATILE
SECURITY DEFINER
AS $$
DECLARE
isid INT;
ilid INT;
BEGIN
-- Get language
SELECT INTO ilid id FROM defs.languages
WHERE language = lid;
-- Create string, if needed
BEGIN
INSERT INTO defs.strings (name) VALUES ( sid )
RETURNING id INTO isid;
EXCEPTION
WHEN unique_violation THEN
SELECT INTO isid id FROM defs.strings
WHERE name = sid;
END;
-- Create or update translation
BEGIN
INSERT INTO defs.translations ( string_id , lang_id , translated_string )
VALUES ( isid , ilid , txt );
EXCEPTION
WHEN unique_violation THEN
UPDATE defs.translations SET translated_string = txt
WHERE string_id = isid AND lang_id = ilid;
END;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION defs.uoc_translation( TEXT , TEXT , TEXT ) TO :dbuser;
CREATE OR REPLACE FUNCTION defs.uoc_translation( lid TEXT , sid TEXT , txt TEXT , a_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
BEGIN
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Updating string ' || sid || ' in language ' || lid );
PERFORM defs.uoc_translation( lid , sid , txt );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION defs.uoc_translation( TEXT, TEXT , TEXT , INT ) TO :dbuser;
--
-- Translations view (used to load all translations)
--
CREATE VIEW defs.translations_view
AS SELECT l.language AS language_id , l.name AS language_name ,
s.name AS string_id , t.translated_string AS translation
FROM defs.translations t
INNER JOIN defs.strings s
ON s.id = t.string_id
INNER JOIN defs.languages l
ON l.id = t.lang_id;
GRANT SELECT ON defs.translations_view TO :dbuser;

View file

@ -0,0 +1,158 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- System management functions
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
--
-- Gets the next tick's identifier
--
CREATE OR REPLACE FUNCTION sys.get_tick( )
RETURNS BIGINT
STRICT STABLE
SECURITY INVOKER
AS $$
SELECT next_tick FROM sys.status;
$$ LANGUAGE SQL;
--
-- Registers a new ticker task
--
CREATE OR REPLACE FUNCTION sys.register_ticker_task( t_name TEXT )
RETURNS INT
STRICT VOLATILE
SECURITY DEFINER
AS $$
INSERT INTO sys.ticker ( task_name , status )
VALUES ( $1 , 'RUNNING' )
RETURNING id;
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION sys.register_ticker_task( TEXT ) TO :dbuser;
--
-- Indicates that a ticker task was started automatically
--
-- Parameters:
-- task_id Task identifier
--
CREATE OR REPLACE FUNCTION sys.set_task_started( task_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
t_name TEXT;
BEGIN
SELECT INTO t_name task_name FROM sys.ticker
WHERE id = task_id AND status = 'AUTO' FOR UPDATE;
IF FOUND
THEN
UPDATE sys.ticker SET status = 'RUNNING' , auto_start = NULL
WHERE id = task_id;
PERFORM sys.write_sql_log( 'Ticker' , 'INFO'::log_level , 'Scheduled task ''' || t_name
|| ''' has been enabled' );
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION sys.set_task_started( INT ) TO :dbuser;
--
-- Starts or stops a task
--
-- Parameters:
-- admin_id Administrator identifier
-- task_id Task identifier
-- running Whether the task should be started or stopped
--
CREATE OR REPLACE FUNCTION sys.set_task_running( admin_id INT , task_id INT , running BOOLEAN )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
n_stat ticker_task_status;
t_name TEXT;
BEGIN
n_stat := ( CASE WHEN running THEN 'RUNNING' ELSE 'STOPPED' END );
SELECT INTO t_name task_name FROM sys.ticker
WHERE id = task_id AND status <> n_stat FOR UPDATE;
IF FOUND
THEN
UPDATE sys.ticker SET status = n_stat , auto_start = NULL
WHERE id = task_id;
PERFORM admin.write_log( admin_id , 'INFO'::log_level , 'Ticker task ''' || t_name
|| ''' changed to status ' || n_stat );
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION sys.set_task_running( INT , INT , BOOLEAN ) TO :dbuser;
--
-- Schedules a task to start automatically at a later date
--
-- Parameters:
-- admin_id Administrator identifier
-- task_id Task identifier
-- delay Delay, in seconds, before the task starts
--
-- Returns:
-- start_at Time and date at which the task will start
--
CREATE OR REPLACE FUNCTION sys.schedule_task( admin_id INT , task_id INT , delay BIGINT , OUT start_at TIMESTAMP WITHOUT TIME ZONE )
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
t_name TEXT;
BEGIN
start_at := now() + ( delay || 's' )::INTERVAL;
SELECT INTO t_name task_name FROM sys.ticker
WHERE id = task_id FOR UPDATE;
IF NOT FOUND
THEN
RETURN;
END IF;
UPDATE sys.ticker SET status = 'AUTO' , auto_start = start_at WHERE id = task_id;
PERFORM admin.write_log( admin_id , 'INFO'::log_level , 'Ticker task ''' || t_name
|| ''' scheduled to start ' || start_at );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION sys.schedule_task( INT , INT , BIGINT ) TO :dbuser;

View file

@ -0,0 +1,286 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Logging functions and triggers
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- LOG CLEANUP --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
--
-- Remove expired entries from a log table
--
-- Parameters:
-- l_type Log table to clean up
--
CREATE OR REPLACE FUNCTION sys.clean_log_table( l_type log_type )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
expiry INT;
expiry_int INTERVAL;
BEGIN
expiry := floor( sys.get_constant( 'log.maxAge.' || lower( l_type::TEXT ) ) );
expiry_int := ( expiry || 's' )::INTERVAL;
EXECUTE 'DELETE FROM ' || l_type::TEXT || '.logs WHERE t <= $1'
USING now() - expiry_int;
END;
$$ LANGUAGE plpgsql;
--
-- Clean all log tables
--
CREATE OR REPLACE FUNCTION sys.clean_logs( )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
lt log_type;
BEGIN
FOR lt IN SELECT x FROM unnest( enum_range( NULL::log_type ) ) AS x
LOOP
PERFORM sys.clean_log_table( lt );
END LOOP;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION sys.clean_logs( ) TO :dbuser;
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- LOG APPENDERS --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
--
-- Write an user log entry
--
CREATE OR REPLACE FUNCTION users.write_log( account_id INT , lv log_level , msg TEXT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
BEGIN
INSERT INTO users.logs (credentials_id , level , message)
VALUES ( account_id , lv , msg );
END;
$$ LANGUAGE plpgsql;
--
-- Write an administrative log entry
--
CREATE OR REPLACE FUNCTION admin.write_log( adm_id INT , lv log_level , msg TEXT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
BEGIN
INSERT INTO admin.logs ( admin_id , level , message )
VALUES ( adm_id , lv , msg );
END;
$$ LANGUAGE plpgsql;
--
-- Write a system log entry
--
CREATE OR REPLACE FUNCTION sys.write_log( cmp TEXT , lv log_level , msg TEXT , OUT entry_id BIGINT )
STRICT VOLATILE
SECURITY DEFINER
AS $$
BEGIN
INSERT INTO sys.logs( component , level , message )
VALUES ( cmp , lv , msg )
RETURNING id INTO entry_id;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION sys.write_log( TEXT , log_level , TEXT ) TO :dbuser;
--
-- Remotely append a system log entry
--
-- This function is called from within transactions in order to write to the
-- system log. Unlike sys.write_log(), entries added through this function
-- will not be lost if the transaction is rolled back.
--
-- Since the function is meant to be called from SQL code, it does not return
-- anything as the identifier of the new entry is not required.
--
-- Parameters:
-- _component The component that is appending to the log
-- _level The log level
-- _message The message to write
--
CREATE OR REPLACE FUNCTION sys.write_sql_log( _component TEXT , _level log_level , _message TEXT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $write_sql_log$
BEGIN
PERFORM dblink_connect( 'cn_logging' , 'srv_logging' );
PERFORM * FROM dblink( 'cn_logging' ,
'SELECT * FROM sys.write_log( '
|| quote_literal( _component ) || ' , '''
|| _level::text || '''::log_level , '
|| quote_literal( _message ) || ' )'
) AS ( entry_id bigint );
PERFORM dblink_disconnect( 'cn_logging' );
END;
$write_sql_log$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION sys.write_sql_log( TEXT , log_level , TEXT ) TO :dbuser;
--
-- Append an exception log entry
--
CREATE OR REPLACE FUNCTION sys.append_exception( l_id BIGINT , cname TEXT , msg TEXT , OUT entry_id BIGINT )
CALLED ON NULL INPUT
VOLATILE
SECURITY DEFINER
AS $$
DECLARE
d INT;
BEGIN
SELECT INTO d max( depth ) FROM sys.exceptions
WHERE log_id = l_id;
IF d IS NULL THEN
d := 0;
END IF;
d := d + 1;
INSERT INTO sys.exceptions ( log_id , depth , exc_class , message )
VALUES ( l_id , d , cname , msg )
RETURNING id INTO entry_id;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION sys.append_exception( BIGINT , TEXT , TEXT ) TO :dbuser;
--
-- Append a stack trace entry
--
CREATE OR REPLACE FUNCTION sys.append_trace( e_id BIGINT , loc TEXT , f_name TEXT , lnb INT )
RETURNS VOID
CALLED ON NULL INPUT
VOLATILE
SECURITY DEFINER
AS $$
DECLARE
d INT;
BEGIN
SELECT INTO d max( depth ) FROM sys.stack_traces
WHERE exception_id = e_id;
IF d IS NULL THEN
d := 0;
END IF;
d := d + 1;
INSERT INTO sys.stack_traces ( exception_id , depth , location , file_name , line_number )
VALUES ( e_id , d , loc , f_name , lnb );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION sys.append_trace( BIGINT , TEXT , TEXT , INT ) TO :dbuser;
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- LOGS VIEW FOR EASY SELECTION --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
CREATE VIEW sys.system_logs_view
AS SELECT l.id , l.t , l.component , l.level , l.message ,
( CASE WHEN e.id IS NOT NULL THEN l.id ELSE NULL END )::BIGINT AS exception_id
FROM sys.logs l
LEFT OUTER JOIN sys.exceptions e ON e.log_id = l.id AND e.depth = 1;
GRANT SELECT ON sys.system_logs_view TO :dbuser;
CREATE VIEW sys.admin_logs_view
AS SELECT NULL::BIGINT AS id , l.t , a.appear_as AS component , l.level ,
l.message , NULL::BIGINT AS exception_id
FROM admin.logs l
INNER JOIN admin.administrators a ON a.id = l.admin_id;
GRANT SELECT ON sys.admin_logs_view TO :dbuser;
CREATE VIEW sys.player_logs_view
AS SELECT NULL::BIGINT AS id , l.t , a.address AS component , l.level ,
l.message , NULL::BIGINT AS exception_id
FROM users.logs l
INNER JOIN users.addresses a ON a.id = l.credentials_id;
GRANT SELECT ON sys.player_logs_view TO :dbuser;
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- ADMIN ERROR REPORT FUNCTION --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
CREATE OR REPLACE FUNCTION admin.get_error_entries( )
RETURNS SETOF BIGINT
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
last_report TIMESTAMP WITHOUT TIME ZONE;
new_report TIMESTAMP WITHOUT TIME ZONE;
e_id BIGINT;
BEGIN
new_report := now( );
SELECT INTO last_report last_error_recap FROM sys.status FOR UPDATE;
UPDATE sys.status SET last_error_recap = new_report;
RETURN QUERY SELECT id FROM sys.system_logs_view
WHERE t >= last_report AND t < new_report AND exception_id IS NOT NULL
ORDER BY t DESC;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION admin.get_error_entries( ) TO :dbuser;

View file

@ -0,0 +1,318 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Functions that access system constants
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
--
-- Creates or gets a constant category
--
-- Parameters:
-- ccnm Constant category name
--
-- Returns:
-- the category's identifier
--
CREATE OR REPLACE FUNCTION sys.cog_constant_category( ccnm TEXT )
RETURNS INT
STRICT
VOLATILE
SECURITY INVOKER
AS $$
DECLARE
ccid INT;
BEGIN
BEGIN
INSERT INTO sys.constant_categories (name)
VALUES (ccnm)
RETURNING id INTO ccid;
EXCEPTION
WHEN unique_violation THEN
SELECT INTO ccid id FROM sys.constant_categories
WHERE name = ccnm
FOR UPDATE;
END;
RETURN ccid;
END;
$$ LANGUAGE plpgsql;
--
-- Creates or updates a constant with no boundaries
--
-- Parameters:
-- cnm Constant name
-- cdesc Constant description
-- ccnm Constant category name
-- dval Default value
--
-- Returns:
-- the constant's actual value
--
CREATE OR REPLACE FUNCTION sys.uoc_constant( cnm TEXT , cdesc TEXT , ccnm TEXT , dval REAL )
RETURNS REAL
STRICT
VOLATILE
SECURITY DEFINER
AS $$
DECLARE
ccid INT;
occid INT;
cval REAL;
BEGIN
ccid := sys.cog_constant_category( ccnm );
BEGIN
INSERT INTO sys.constant_definitions( name , category_id , description , c_value )
VALUES ( cnm , ccid , cdesc , dval );
cval := dval;
EXCEPTION
WHEN unique_violation THEN
SELECT INTO occid , cval category_id , c_value FROM sys.constant_definitions
WHERE name = cnm
FOR UPDATE;
UPDATE sys.constant_definitions SET category_id = ccid , description = cdesc ,
min_value = NULL , max_value = NULL
WHERE name = cnm;
IF occid <> ccid THEN
BEGIN
DELETE FROM sys.constant_categories WHERE id = occid;
EXCEPTION
WHEN foreign_key_violation THEN
-- Do nothing
END; END IF;
END;
RETURN cval;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION sys.uoc_constant( TEXT , TEXT , TEXT , REAL ) TO :dbuser;
--
-- Creates or updates a constant with a single boundary
--
-- Parameters:
-- cnm Constant name
-- cdesc Constant description
-- ccnm Constant category name
-- dval Default value
-- bval Bound value
-- ismin Whether the bound value is the minimal or maximal value for the constant
--
-- Returns:
-- the constant's actual value
--
CREATE OR REPLACE FUNCTION sys.uoc_constant( cnm TEXT , cdesc TEXT , ccnm TEXT , dval REAL , bval REAL , ismin BOOLEAN )
RETURNS REAL
STRICT
VOLATILE
SECURITY DEFINER
AS $$
DECLARE
ccid INT;
occid INT;
cval REAL;
mival REAL;
maval REAL;
BEGIN
IF ismin THEN
mival := bval;
maval := NULL;
ELSE
maval := bval;
mival := NULL;
END IF;
ccid := sys.cog_constant_category( ccnm );
BEGIN
INSERT INTO sys.constant_definitions( name , category_id , description , c_value , min_value , max_value )
VALUES ( cnm , ccid , cdesc , dval , mival , maval );
cval := dval;
EXCEPTION
WHEN unique_violation THEN
SELECT INTO occid , cval category_id , c_value FROM sys.constant_definitions
WHERE name = cnm
FOR UPDATE;
BEGIN
UPDATE sys.constant_definitions SET category_id = ccid , description = cdesc ,
min_value = mival , max_value = maval
WHERE name = cnm;
EXCEPTION
WHEN check_violation THEN
UPDATE sys.constant_definitions SET category_id = ccid , description = cdesc ,
min_value = mival , max_value = maval , c_value = dval
WHERE name = cnm;
cval := dval;
END;
IF occid <> ccid THEN
BEGIN
DELETE FROM sys.constant_categories WHERE id = occid;
EXCEPTION
WHEN foreign_key_violation THEN
-- Do nothing
END; END IF;
END;
RETURN cval;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION sys.uoc_constant( TEXT , TEXT , TEXT , REAL , REAL , BOOLEAN ) TO :dbuser;
--
-- Creates or updates a constant with both boundaries
--
-- Parameters:
-- cnm Constant name
-- cdesc Constant description
-- ccnm Constant category name
-- dval Default value
-- mival Minimal value
-- maval Maximal value
--
-- Returns:
-- the constant's actual value
--
CREATE OR REPLACE FUNCTION sys.uoc_constant( cnm TEXT , cdesc TEXT , ccnm TEXT , dval REAL , mival REAL , maval REAL )
RETURNS REAL
STRICT
VOLATILE
SECURITY DEFINER
AS $$
DECLARE
ccid INT;
occid INT;
cval REAL;
BEGIN
ccid := sys.cog_constant_category( ccnm );
BEGIN
INSERT INTO sys.constant_definitions( name , category_id , description , c_value , min_value , max_value )
VALUES ( cnm , ccid , cdesc , dval , mival , maval );
cval := dval;
EXCEPTION
WHEN unique_violation THEN
SELECT INTO occid , cval category_id , c_value FROM sys.constant_definitions
WHERE name = cnm
FOR UPDATE;
BEGIN
UPDATE sys.constant_definitions SET category_id = ccid , description = cdesc ,
min_value = mival , max_value = maval
WHERE name = cnm;
EXCEPTION
WHEN check_violation THEN
UPDATE sys.constant_definitions SET category_id = ccid , description = cdesc ,
min_value = mival , max_value = maval , c_value = dval
WHERE name = cnm;
cval := dval;
END;
IF occid <> ccid THEN
BEGIN
DELETE FROM sys.constant_categories WHERE id = occid;
EXCEPTION
WHEN foreign_key_violation THEN
-- Do nothing
END; END IF;
END;
RETURN cval;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION sys.uoc_constant( TEXT , TEXT , TEXT , REAL , REAL , REAL ) TO :dbuser;
--
-- Updates a constant's value
--
-- Parameters:
-- cnm Constant name
-- nval New value
-- aid Administrator attempting to update the constant
--
-- Returns:
-- TRUE on success, FALSE on failure
--
CREATE OR REPLACE FUNCTION sys.set_constant( cnm TEXT , nval REAL , aid INT )
RETURNS BOOLEAN
STRICT
VOLATILE
SECURITY DEFINER
AS $$
DECLARE
success BOOLEAN;
BEGIN
BEGIN
UPDATE sys.constant_definitions SET c_value = nval
WHERE name = cnm;
success := FOUND;
EXCEPTION
WHEN check_violation THEN
success := FALSE;
END;
PERFORM admin.write_log( aid , 'INFO'::log_level , 'Constant "' || cnm || '" changed to ' || nval );
RETURN success;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION sys.set_constant( TEXT , REAL , INT ) TO :dbuser;
--
-- Gets a constant's value
--
-- Parameters:
-- cnm Constant name
--
CREATE OR REPLACE FUNCTION sys.get_constant( cnm TEXT )
RETURNS REAL
STRICT STABLE
SECURITY DEFINER
AS $$
SELECT c_value FROM sys.constant_definitions WHERE name = $1;
$$ LANGUAGE SQL;
--
-- Constants view
--
CREATE VIEW sys.constants_view
AS SELECT cat.name AS category , cns.name AS name , cns.description AS description ,
cns.c_value AS value , cns.min_value AS min , cns.max_value AS max
FROM sys.constant_definitions cns
INNER JOIN sys.constant_categories cat
ON cat.id = cns.category_id
ORDER BY cat.name , cns.name;
GRANT SELECT ON sys.constants_view TO :dbuser;

View file

@ -0,0 +1,623 @@
-- 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;

View file

@ -0,0 +1,467 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Resource definitions management functions
--
-- Copyright(C) 2004-2011, DeepClone Development
-- --------------------------------------------------------
/*
* Return codes for resource creation or update functions.
*/
DROP TYPE IF EXISTS defs.resource_update_result CASCADE;
CREATE TYPE defs.resource_update_result
AS ENUM(
/* The resource definition was created */
'CREATED' ,
/* The resource definition was updated */
'UPDATED' ,
/* The resource definition already existed, and was either a basic
* resource definition while the update required a natural resource,
* or a natural resource definition when the update required a basic
* resource.
*/
'BAD_TYPE' ,
/* The name, description or category string identifiers were not valid
* string identifiers.
*/
'BAD_STRINGS' ,
/* One (or more) of the numeric parameters is invalid */
'BAD_VALUE' ,
/* The specified description was in use by another resource */
'DUP_DESCR'
);
/*
* Create or update a basic resource
*
* /!\ INTERNAL FUNCTION /!\
*
* This function is called by the variants of defs.uoc_resource() to actually
* update or create the resource. It will make sure that all string
* identifiers exist, then try to insert the resource. If that fails because
* the resource already exists, make sure it's a basic resource then update
* it.
*
* Parameters:
* _name the identifier of the resource's name
* _description the identifier of the resource's description
* _category the identifier of the resource's category, or NULL if
* the resource does not belong to a category
* _weight the resource's ordering weight
*
* Returns:
* ? the result code for the operation
*/
CREATE OR REPLACE FUNCTION defs.uoc_resource_internal(
_name TEXT ,
_description TEXT ,
_category TEXT ,
_weight INT )
RETURNS defs.resource_update_result
CALLED ON NULL INPUT
VOLATILE
SECURITY INVOKER
AS $$
DECLARE
_ret defs.resource_update_result;
_name_id INT;
_desc_id INT;
_cat_id INT;
BEGIN
-- Get all string identifiers
SELECT INTO _name_id id FROM defs.strings WHERE name = _name;
IF NOT FOUND THEN
RETURN 'BAD_STRINGS';
END IF;
SELECT INTO _desc_id id FROM defs.strings WHERE name = _description;
IF NOT FOUND THEN
RETURN 'BAD_STRINGS';
END IF;
IF _category IS NULL THEN
_cat_id := NULL;
ELSE
SELECT INTO _cat_id id FROM defs.strings WHERE name = _category;
IF NOT FOUND THEN
RETURN 'BAD_STRINGS';
END IF;
END IF;
-- Try inserting the record
BEGIN
INSERT INTO defs.resources (
resource_name_id , resource_description_id ,
resource_category_id , resource_weight
) VALUES (
_name_id , _desc_id , _cat_id , _weight
);
RETURN 'CREATED';
EXCEPTION
WHEN unique_violation THEN
IF SQLERRM LIKE '%_description_%' THEN
RETURN 'DUP_DESCR';
END IF;
END;
-- Insertion failed, make sure the resource is a basic resource
PERFORM *
FROM defs.resources basic_res
LEFT OUTER JOIN defs.natural_resources nat_res
USING ( resource_name_id )
WHERE basic_res.resource_name_id = _name_id
AND nat_res.resource_name_id IS NULL
FOR UPDATE OF basic_res;
IF NOT FOUND THEN
RETURN 'BAD_TYPE';
END IF;
-- Update the resource
BEGIN
UPDATE defs.resources
SET resource_description_id = _desc_id ,
resource_category_id = _cat_id ,
resource_weight = _weight
WHERE resource_name_id = _name_id;
RETURN 'UPDATED';
EXCEPTION
WHEN unique_violation THEN
RETURN 'DUP_DESCR';
END;
EXCEPTION
WHEN check_violation THEN
RETURN 'BAD_VALUE';
END;
$$ LANGUAGE PLPGSQL;
REVOKE EXECUTE
ON FUNCTION defs.uoc_resource_internal( TEXT , TEXT , TEXT , INT )
FROM PUBLIC;
/*
* Update or create a basic resource definition with no category
*
* Parameters:
* _name the identifier of the resource's name
* _description the identifier of the resource's description
* _weight the resource's ordering weight
*
* Returns:
* ? the result code for the operation
*/
CREATE OR REPLACE FUNCTION defs.uoc_resource(
_name TEXT ,
_description TEXT ,
_weight INT )
RETURNS defs.resource_update_result
STRICT
VOLATILE
SECURITY DEFINER
AS $$
SELECT defs.uoc_resource_internal( $1 , $2 , NULL , $3 );
$$ LANGUAGE SQL;
REVOKE EXECUTE
ON FUNCTION defs.uoc_resource( TEXT , TEXT , INT )
FROM PUBLIC;
GRANT EXECUTE
ON FUNCTION defs.uoc_resource( TEXT , TEXT , INT )
TO :dbuser;
/*
* Update or create a basic resource definition with a category
*
* Parameters:
* _name the identifier of the resource's name
* _description the identifier of the resource's description
* _category the identifier of the resource's category
* _weight the resource's ordering weight
*
* Returns:
* ? the result code for the operation
*/
CREATE OR REPLACE FUNCTION defs.uoc_resource(
_name TEXT ,
_description TEXT ,
_category TEXT ,
_weight INT )
RETURNS defs.resource_update_result
STRICT
VOLATILE
SECURITY DEFINER
AS $$
SELECT defs.uoc_resource_internal( $1 , $2 , $3 , $4 );
$$ LANGUAGE SQL;
REVOKE EXECUTE
ON FUNCTION defs.uoc_resource( TEXT , TEXT , TEXT , INT )
FROM PUBLIC;
GRANT EXECUTE
ON FUNCTION defs.uoc_resource( TEXT , TEXT , TEXT , INT )
TO :dbuser;
/*
* Create or update a natural resource
*
* /!\ INTERNAL FUNCTION /!\
*
* This function is called by the variants of defs.uoc_natural_resource() to
* actually update or create the resource. It will make sure that all string
* identifiers exist, then try to insert the resource. If that fails because
* the resource already exists, make sure it's a natural resource then update
* it.
*
* Parameters:
* _name the identifier of the resource's name
* _description the identifier of the resource's description
* _category the identifier of the resource's category, or NULL if
* the resource does not belong to a category
* _weight the resource's ordering weight
* _presence the presence probability
* _quantity_avg the average quantity
* _quantity_dev the deviation from the average quantity
* _difficulty_avg the average extraction difficulty
* _difficulty_dev the deviation from the average extraction difficulty
* _recovery_avg the average recovery rate
* _recovery_dev the deviation from the average recovery rate
*
* Returns:
* ? the result code for the operation
*/
CREATE OR REPLACE FUNCTION defs.uoc_natres_internal(
_name TEXT ,
_description TEXT ,
_category TEXT ,
_weight INT ,
_presence DOUBLE PRECISION ,
_quantity_avg DOUBLE PRECISION ,
_quantity_dev DOUBLE PRECISION ,
_difficulty_avg DOUBLE PRECISION ,
_difficulty_dev DOUBLE PRECISION ,
_recovery_avg DOUBLE PRECISION ,
_recovery_dev DOUBLE PRECISION )
RETURNS defs.resource_update_result
CALLED ON NULL INPUT
VOLATILE
SECURITY INVOKER
AS $$
DECLARE
_ret defs.resource_update_result;
_name_id INT;
_desc_id INT;
_cat_id INT;
_inserted BOOLEAN;
BEGIN
-- Get all string identifiers
SELECT INTO _name_id id FROM defs.strings WHERE name = _name;
IF NOT FOUND THEN
RETURN 'BAD_STRINGS';
END IF;
SELECT INTO _desc_id id FROM defs.strings WHERE name = _description;
IF NOT FOUND THEN
RETURN 'BAD_STRINGS';
END IF;
IF _category IS NULL THEN
_cat_id := NULL;
ELSE
SELECT INTO _cat_id id FROM defs.strings WHERE name = _category;
IF NOT FOUND THEN
RETURN 'BAD_STRINGS';
END IF;
END IF;
-- Try inserting the basic record
BEGIN
INSERT INTO defs.resources (
resource_name_id , resource_description_id ,
resource_category_id , resource_weight
) VALUES (
_name_id , _desc_id , _cat_id , _weight
);
_inserted := TRUE;
EXCEPTION
WHEN unique_violation THEN
IF SQLERRM LIKE '%_description_%' THEN
RETURN 'DUP_DESCR';
END IF;
_inserted := FALSE;
END;
-- If insertion succeeded, insert the rest of the record
IF _inserted THEN
INSERT INTO defs.natural_resources(
resource_name_id , natres_p_presence ,
natres_quantity_avg , natres_quantity_dev ,
natres_difficulty_avg , natres_difficulty_dev ,
natres_recovery_avg , natres_recovery_dev
) VALUES (
_name_id , _presence ,
_quantity_avg , _quantity_dev ,
_difficulty_avg , _difficulty_dev ,
_recovery_avg , _recovery_dev
);
RETURN 'CREATED';
END IF;
-- Insertion failed, make sure it is a natural resource
PERFORM *
FROM defs.resources basic_res
INNER JOIN defs.natural_resources nat_res
USING ( resource_name_id )
WHERE basic_res.resource_name_id = _name_id
FOR UPDATE;
IF NOT FOUND THEN
RETURN 'BAD_TYPE';
END IF;
-- Update the resource
BEGIN
UPDATE defs.resources
SET resource_description_id = _desc_id ,
resource_category_id = _cat_id ,
resource_weight = _weight
WHERE resource_name_id = _name_id;
UPDATE defs.natural_resources
SET natres_p_presence = _presence ,
natres_quantity_avg = _quantity_avg ,
natres_quantity_dev = _quantity_dev ,
natres_difficulty_avg = _difficulty_avg ,
natres_difficulty_dev = _difficulty_dev ,
natres_recovery_avg = _recovery_avg ,
natres_recovery_dev = _recovery_dev
WHERE resource_name_id = _name_id;
RETURN 'UPDATED';
EXCEPTION
WHEN unique_violation THEN
RETURN 'DUP_DESCR';
END;
EXCEPTION
WHEN check_violation THEN
RETURN 'BAD_VALUE';
END;
$$ LANGUAGE PLPGSQL;
REVOKE EXECUTE
ON FUNCTION defs.uoc_natres_internal( TEXT , TEXT , TEXT , INT ,
DOUBLE PRECISION , DOUBLE PRECISION , DOUBLE PRECISION ,
DOUBLE PRECISION , DOUBLE PRECISION , DOUBLE PRECISION ,
DOUBLE PRECISION )
FROM PUBLIC;
/*
* Create or update a natural resource with no category
*
* Parameters:
* _name the identifier of the resource's name
* _description the identifier of the resource's description
* _weight the resource's ordering weight
* _presence the presence probability
* _quantity_avg the average quantity
* _quantity_dev the deviation from the average quantity
* _difficulty_avg the average extraction difficulty
* _difficulty_dev the deviation from the average extraction difficulty
* _recovery_avg the average recovery rate
* _recovery_dev the deviation from the average recovery rate
*
* Returns:
* ? the result code for the operation
*/
CREATE OR REPLACE FUNCTION defs.uoc_natural_resource(
_name TEXT ,
_description TEXT ,
_weight INT ,
_presence DOUBLE PRECISION ,
_quantity_avg DOUBLE PRECISION ,
_quantity_dev DOUBLE PRECISION ,
_difficulty_avg DOUBLE PRECISION ,
_difficulty_dev DOUBLE PRECISION ,
_recovery_avg DOUBLE PRECISION ,
_recovery_dev DOUBLE PRECISION )
RETURNS defs.resource_update_result
STRICT VOLATILE
SECURITY DEFINER
AS $$
SELECT defs.uoc_natres_internal( $1 , $2 , NULL , $3 , $4 , $5 , $6 , $7 ,
$8 , $9 , $10 );
$$ LANGUAGE SQL;
REVOKE EXECUTE
ON FUNCTION defs.uoc_natural_resource( TEXT , TEXT , INT ,
DOUBLE PRECISION , DOUBLE PRECISION , DOUBLE PRECISION ,
DOUBLE PRECISION , DOUBLE PRECISION , DOUBLE PRECISION ,
DOUBLE PRECISION )
FROM PUBLIC;
GRANT EXECUTE
ON FUNCTION defs.uoc_natural_resource( TEXT , TEXT , INT ,
DOUBLE PRECISION , DOUBLE PRECISION , DOUBLE PRECISION ,
DOUBLE PRECISION , DOUBLE PRECISION , DOUBLE PRECISION ,
DOUBLE PRECISION )
TO :dbuser;
/*
* Create or update a natural resource with a category
*
* Parameters:
* _name the identifier of the resource's name
* _description the identifier of the resource's description
* _category the identifier of the resource's category
* _weight the resource's ordering weight
* _presence the presence probability
* _quantity_avg the average quantity
* _quantity_dev the deviation from the average quantity
* _difficulty_avg the average extraction difficulty
* _difficulty_dev the deviation from the average extraction difficulty
* _recovery_avg the average recovery rate
* _recovery_dev the deviation from the average recovery rate
*
* Returns:
* ? the result code for the operation
*/
CREATE OR REPLACE FUNCTION defs.uoc_natural_resource(
_name TEXT ,
_description TEXT ,
_category TEXT ,
_weight INT ,
_presence DOUBLE PRECISION ,
_quantity_avg DOUBLE PRECISION ,
_quantity_dev DOUBLE PRECISION ,
_difficulty_avg DOUBLE PRECISION ,
_difficulty_dev DOUBLE PRECISION ,
_recovery_avg DOUBLE PRECISION ,
_recovery_dev DOUBLE PRECISION )
RETURNS defs.resource_update_result
STRICT VOLATILE
SECURITY DEFINER
AS $$
SELECT defs.uoc_natres_internal( $1 , $2 , $3 , $4 , $5 , $6 , $7 , $8 ,
$9 , $10 , $11 );
$$ LANGUAGE SQL;
REVOKE EXECUTE
ON FUNCTION defs.uoc_natural_resource( TEXT , TEXT , TEXT , INT ,
DOUBLE PRECISION , DOUBLE PRECISION , DOUBLE PRECISION ,
DOUBLE PRECISION , DOUBLE PRECISION , DOUBLE PRECISION ,
DOUBLE PRECISION )
FROM PUBLIC;
GRANT EXECUTE
ON FUNCTION defs.uoc_natural_resource( TEXT , TEXT , TEXT , INT ,
DOUBLE PRECISION , DOUBLE PRECISION , DOUBLE PRECISION ,
DOUBLE PRECISION , DOUBLE PRECISION , DOUBLE PRECISION ,
DOUBLE PRECISION )
TO :dbuser;

View file

@ -0,0 +1,379 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Functions and views for technologies and buildables
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
--
-- "Basic" buildables view (buildables that do not depend on any technology)
--
CREATE VIEW tech.basic_buildables
AS SELECT b.* FROM tech.buildables b
LEFT OUTER JOIN tech.buildable_requirements r
ON r.buildable_id = b.name_id
WHERE r.buildable_id IS NULL;
--
-- Buildings view
--
CREATE VIEW tech.buildings_view
AS SELECT b.name_id , b.description_id , b.cost , b.work , b.upkeep ,
bld.workers , bld.output_type , bld.output
FROM tech.buildables b
INNER JOIN tech.buildings bld
ON b.name_id = bld.buildable_id;
--
-- Ships view
--
CREATE VIEW tech.ships_view
AS SELECT b.name_id , b.description_id , b.cost , b.work , b.upkeep ,
s.flight_time , s.power
FROM tech.buildables b
INNER JOIN tech.ships s
ON b.name_id = s.buildable_id;
--
-- Creates or updates a technology line
--
-- Parameters:
-- tln Tech line name
-- tld Tech line description
--
CREATE OR REPLACE FUNCTION tech.uoc_line( tln TEXT , tld TEXT )
RETURNS VOID
STRICT
VOLATILE
SECURITY DEFINER
AS $$
DECLARE
nid INT;
did INT;
BEGIN
-- Get string identifiers
SELECT INTO nid id FROM defs.strings WHERE name = tln;
SELECT INTO did id FROM defs.strings WHERE name = tld;
-- Try creating / updating
BEGIN
INSERT INTO tech.lines ( name_id , description_id )
VALUES ( nid , did );
EXCEPTION
WHEN unique_violation THEN
UPDATE tech.lines SET description_id = did
WHERE name_id = nid;
END;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION tech.uoc_line( TEXT , TEXT ) TO :dbuser;
--
-- Creates or updates a technology level
--
-- Parameters:
-- tln Tech line name
-- lv Level
-- lvn Level name
-- lvd Level description
-- lvp Points
-- lvc Cost
--
CREATE OR REPLACE FUNCTION tech.uoc_level( tln TEXT , lv INT , lvn TEXT , lvd TEXT , lvp INT , lvc INT )
RETURNS VOID
STRICT
VOLATILE
SECURITY DEFINER
AS $$
DECLARE
lid INT;
nid INT;
did INT;
BEGIN
-- Get tech line
SELECT INTO lid t.name_id
FROM tech.lines t
INNER JOIN defs.strings s
ON s.id = t.name_id
WHERE s.name = tln;
-- Get name / description IDs
SELECT INTO nid id FROM defs.strings WHERE name = lvn;
SELECT INTO did id FROM defs.strings WHERE name = lvd;
-- Create or update the level
BEGIN
INSERT INTO tech.levels ( line_id , level , name_id , description_id , points , cost )
VALUES ( lid , lv , nid , did , lvp , lvc );
EXCEPTION
WHEN unique_violation THEN
UPDATE tech.levels SET name_id = nid , description_id = did , points = lvp , cost = lvc
WHERE line_id = lid AND level = lv;
END;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION tech.uoc_level( TEXT , INT , TEXT , TEXT , INT , INT ) to :dbuser;
--
-- Creates or updates a buildable definition
--
-- Parameters:
-- bdn Buildable name
-- bdd Buildable description
-- bdc Cost
-- bdw Work
-- bdu Upkeep
-- bdtn Dependency (name)
-- bdtl Dependency (level)
--
-- Returns:
-- the buildable's identifier
--
CREATE OR REPLACE FUNCTION tech.uoc_buildable( bdn TEXT , bdd TEXT , bdc INT , bdw INT , bdu INT , bdtn TEXT , bdtl INT )
RETURNS INT
STRICT
VOLATILE
SECURITY INVOKER
AS $$
DECLARE
nid INT;
did INT;
tdid INT;
BEGIN
-- Get the various translations
SELECT INTO nid id FROM defs.strings WHERE name = bdn;
SELECT INTO did id FROM defs.strings WHERE name = bdd;
IF bdtn <> '' THEN
SELECT INTO tdid tl.id FROM tech.levels tl
INNER JOIN defs.strings s
ON s.id = tl.line_id
WHERE s.name = bdtn AND tl.level = bdtl;
END IF;
-- Create or update the definition
BEGIN
INSERT INTO tech.buildables ( name_id , description_id , cost , work , upkeep )
VALUES ( nid , did , bdc , bdw , bdu );
EXCEPTION
WHEN unique_violation THEN
UPDATE tech.buildables SET description_id = did , cost = bdc , work = bdw , upkeep = bdu
WHERE name_id = nid;
END;
-- Set dependencies
DELETE FROM tech.buildable_requirements WHERE buildable_id = nid;
IF bdtn <> '' THEN
INSERT INTO tech.buildable_requirements ( buildable_id , level_id )
VALUES ( nid , tdid );
END IF;
RETURN nid;
END;
$$ LANGUAGE plpgsql;
--
-- Update or create a building definition (no tech dependency)
--
-- Parameters:
-- bdn Buildable name
-- bdd Buildable description
-- bdc Cost
-- bdw Work
-- bdu Upkeep
-- bdwk Workers
-- bdot Output type
-- bdo Output
--
CREATE OR REPLACE FUNCTION tech.uoc_building( bdn TEXT , bdd TEXT , bdc INT , bdw INT ,
bdu INT , bdwk INT , bdot building_output_type , bdo INT )
RETURNS VOID
STRICT
VOLATILE
SECURITY DEFINER
AS $$
DECLARE
bdid INT;
BEGIN
bdid := tech.uoc_buildable( bdn , bdd , bdc , bdw , bdu , '' , 0 );
PERFORM buildable_id FROM tech.ships WHERE buildable_id = bdid;
IF FOUND THEN
RAISE EXCEPTION 'Trying to transform a ship into a building';
END IF;
BEGIN
INSERT INTO tech.buildings (buildable_id, workers, output_type, output)
VALUES (bdid , bdwk , bdot , bdo);
EXCEPTION
WHEN unique_violation THEN
UPDATE tech.buildings SET workers = bdwk , output_type = bdot , output = bdo
WHERE buildable_id = bdid;
END;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION tech.uoc_building( TEXT , TEXT , INT , INT , INT , INT , building_output_type , INT ) TO :dbuser;
--
-- Update or create a building definition (with tech dependency)
--
-- Parameters:
-- bdn Buildable name
-- bdd Buildable description
-- bdc Cost
-- bdw Work
-- bdu Upkeep
-- bdwk Workers
-- bdot Output type
-- bdo Output
-- bdtn Dependency (name)
-- bdtl Dependency (level)
--
CREATE OR REPLACE FUNCTION tech.uoc_building( bdn TEXT , bdd TEXT , bdc INT , bdw INT ,
bdu INT , bdwk INT , bdot building_output_type , bdo INT ,
bdtn TEXT , bdtl INT )
RETURNS VOID
STRICT
VOLATILE
SECURITY DEFINER
AS $$
DECLARE
bdid INT;
BEGIN
bdid := tech.uoc_buildable( bdn , bdd , bdc , bdw , bdu , bdtn , bdtl );
PERFORM buildable_id FROM tech.ships WHERE buildable_id = bdid;
IF FOUND THEN
RAISE EXCEPTION 'Trying to transform a ship into a building';
END IF;
BEGIN
INSERT INTO tech.buildings (buildable_id, workers, output_type, output)
VALUES (bdid , bdwk , bdot , bdo);
EXCEPTION
WHEN unique_violation THEN
UPDATE tech.buildings SET workers = bdwk , output_type = bdot , output = bdo
WHERE buildable_id = bdid;
END;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION tech.uoc_building( TEXT , TEXT , INT , INT , INT , INT , building_output_type , INT , TEXT , INT ) TO :dbuser;
--
-- Update or create a ship definition (no tech dependency)
--
-- Parameters:
-- sn Buildable name
-- sd Buildable description
-- sc Cost
-- sw Work
-- su Upkeep
-- sp Power
-- sft Orbital flight time
--
CREATE OR REPLACE FUNCTION tech.uoc_ship( sn TEXT , sd TEXT , sc INT , sw INT ,
su INT , sp INT , sft INT )
RETURNS VOID
STRICT
VOLATILE
SECURITY DEFINER
AS $$
DECLARE
bdid INT;
BEGIN
bdid := tech.uoc_buildable( sn , sd , sc , sw , su , '' , 0 );
PERFORM buildable_id FROM tech.buildings WHERE buildable_id = bdid;
IF FOUND THEN
RAISE EXCEPTION 'Trying to transform a building into a ship';
END IF;
BEGIN
INSERT INTO tech.ships (buildable_id, flight_time, power)
VALUES (bdid , sft , sp);
EXCEPTION
WHEN unique_violation THEN
UPDATE tech.ships SET flight_time = sft , power = sp
WHERE buildable_id = bdid;
END;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION tech.uoc_ship( TEXT , TEXT , INT , INT , INT , INT , INT ) TO :dbuser;
--
-- Update or create a ship definition
--
-- Parameters:
-- sn Buildable name
-- sd Buildable description
-- sc Cost
-- sw Work
-- su Upkeep
-- sp Power
-- sft Orbital flight time
-- stdn Tech line name
-- stdl Tech level
--
CREATE OR REPLACE FUNCTION tech.uoc_ship( sn TEXT , sd TEXT , sc INT , sw INT ,
su INT , sp INT , sft INT , stdn TEXT , stdl INT )
RETURNS VOID
STRICT
VOLATILE
SECURITY DEFINER
AS $$
DECLARE
bdid INT;
BEGIN
bdid := tech.uoc_buildable( sn , sd , sc , sw , su , stdn , stdl );
PERFORM buildable_id FROM tech.buildings WHERE buildable_id = bdid;
IF FOUND THEN
RAISE EXCEPTION 'Trying to transform a building into a ship';
END IF;
BEGIN
INSERT INTO tech.ships (buildable_id, flight_time, power)
VALUES (bdid , sft , sp);
EXCEPTION
WHEN unique_violation THEN
UPDATE tech.ships SET flight_time = sft , power = sp
WHERE buildable_id = bdid;
END;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION tech.uoc_ship( TEXT , TEXT , INT , INT , INT , INT , INT , TEXT , INT ) TO :dbuser;

View file

@ -0,0 +1,85 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- General account view
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
--
-- General account view
--
-- Allows most account-related data to be loooked up, and computes account statuses.
--
CREATE VIEW users.accounts_view
AS SELECT addr.id AS id , addr.address AS address , lang.language AS language ,
cred.pass_md5 AS pass_md5 , cred.pass_sha1 AS pass_sha1 , cred.credits AS game_credits ,
( CASE ( ban.account_id IS NULL )
WHEN TRUE THEN
( CASE ( iacc.credentials_id IS NULL )
WHEN TRUE THEN
( CASE ( aacc.credentials_id IS NULL )
WHEN TRUE THEN
'UNCONFIRMED'
ELSE
( CASE ( vac.status IS NULL )
WHEN TRUE THEN
'ACTIVE'
ELSE
( CASE vac.status
WHEN 'PROCESSED' THEN
'VACATION'
ELSE
'START_VACATION'
END )
END )
END )
ELSE
( CASE ( aacc.credentials_id IS NULL )
WHEN TRUE THEN
( CASE ( vkey.credentials_id IS NULL )
WHEN TRUE THEN
'DISABLED'
ELSE
'REACTIVATING'
END )
ELSE
'QUITTING'
END )
END )
ELSE
'BANNED'
END ) AS status ,
vkey.token AS validation_token , prr.token AS pwd_recovery_token ,
acr.token AS address_change_token , naddr.address AS new_address ,
aacc.vacation_credits AS vacation_credits ,
floor( aacc.vacation_credits / sys.get_constant( 'vacation.cost' ) ) AS vacation_time,
vac.since AS vacation_start ,
iacc.since AS inactivity_begin , ires.reason AS inactivity_reason ,
ban.ban_id AS ban_request_id
FROM users.addresses addr
INNER JOIN users.credentials cred
ON cred.address_id = addr.id
INNER JOIN defs.languages lang
ON lang.id = cred.language_id
LEFT OUTER JOIN users.validation_keys vkey
ON vkey.credentials_id = cred.address_id
LEFT OUTER JOIN users.pwd_recovery_requests prr
ON prr.credentials_id = cred.address_id AND NOT prr.used
LEFT OUTER JOIN users.address_change_requests acr
ON acr.credentials_id = cred.address_id AND NOT acr.used
LEFT OUTER JOIN users.addresses naddr
ON naddr.id = acr.address_id
LEFT OUTER JOIN users.active_accounts aacc
ON aacc.credentials_id = cred.address_id
LEFT OUTER JOIN users.vacations AS vac
ON vac.account_id = aacc.credentials_id
LEFT OUTER JOIN users.inactive_accounts AS iacc
ON iacc.credentials_id = cred.address_id
LEFT OUTER JOIN users.reasons AS ires
ON ires.account_id = iacc.credentials_id
LEFT OUTER JOIN users.bans AS ban
ON ban.account_id = iacc.credentials_id;
GRANT SELECT ON users.accounts_view TO :dbuser;

View file

@ -0,0 +1,662 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Empire management functions and views
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
--
-- Empire creation
--
-- Parameters:
-- nid Empire name identifier
-- pid Planet identifier
-- icash Initial cash
--
CREATE OR REPLACE FUNCTION emp.create_empire( nid INT , pid INT , icash REAL )
RETURNS VOID
STRICT
VOLATILE
SECURITY INVOKER
AS $$
DECLARE
uid BIGINT;
utp update_type;
BEGIN
-- Add empire and give initial planet
INSERT INTO emp.empires ( name_id , cash )
VALUES ( nid , icash );
INSERT INTO emp.planets ( planet_id , empire_id )
VALUES ( pid , nid );
-- Add empire update records
FOR utp IN SELECT x FROM unnest( enum_range( NULL::update_type ) ) AS x
WHERE x::text LIKE 'EMPIRE_%'
LOOP
INSERT INTO sys.updates( gu_type )
VALUES ( utp )
RETURNING id INTO uid;
INSERT INTO emp.updates ( update_id , empire_id )
VALUES ( uid , nid );
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Returns a planet owner's empire size
--
CREATE OR REPLACE FUNCTION emp.get_size( pid INT )
RETURNS INT
STRICT STABLE
SECURITY INVOKER
AS $$
SELECT count( aep.* )::INT
FROM emp.planets ep
INNER JOIN emp.planets aep
ON ep.empire_id = aep.empire_id
WHERE ep.planet_id = $1;
$$ LANGUAGE SQL;
--
-- Returns the empire associated with an account
--
CREATE OR REPLACE FUNCTION emp.get_current( a_id INT , OUT empire_id INT )
STRICT STABLE
SECURITY DEFINER
AS $$
SELECT e.name_id AS empire_id
FROM users.credentials c
INNER JOIN naming.empire_names en ON en.owner_id = c.address_id
INNER JOIN emp.empires e ON e.name_id = en.id
WHERE c.address_id = $1;
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION emp.get_current( INT ) TO :dbuser;
--
-- Implements a technology
--
CREATE OR REPLACE FUNCTION emp.implement_tech( e_id INT , l_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
e_cash REAL;
lev INT;
cost REAL;
BEGIN
SELECT INTO e_cash , lev , cost e.cash , et.level , tl.cost
FROM emp.empires e
INNER JOIN emp.technologies et
ON et.line_id = l_id AND et.empire_id = e.name_id
INNER JOIN tech.levels tl
ON tl.line_id = l_id AND tl.level = et.level
AND tl.points = floor( et.accumulated )
AND tl.cost <= e.cash
WHERE e.name_id = e_id
FOR UPDATE OF e , et;
IF NOT FOUND THEN
RETURN;
END IF;
UPDATE emp.empires
SET cash = e_cash - cost
WHERE name_id = e_id;
UPDATE emp.technologies
SET level = lev + 1 , accumulated = 0
WHERE empire_id = e_id AND line_id = l_id;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION emp.implement_tech( INT , INT ) TO :dbuser;
--
-- Add an enemy empire
--
-- Parameters:
-- e_id Empire identifier
-- e_name New enemy name
--
-- Returns:
-- err_code Error code:
-- 0 on success
-- 1 if the specified empire does not exist
-- 2 if the player is being schizophrenic
-- 3 if the enemy list already contains the specified empire
--
CREATE OR REPLACE FUNCTION emp.add_enemy_empire( e_id INT , e_name TEXT , OUT err_code INT )
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
en_id INT;
BEGIN
SELECT INTO en_id e.name_id
FROM emp.empires e
INNER JOIN naming.empire_names en ON e.name_id = en.id
WHERE lower( en.name ) = lower( e_name );
IF NOT FOUND THEN
err_code := 1;
ELSEIF en_id = e_id THEN
err_code := 2;
ELSE
BEGIN
INSERT INTO emp.enemy_empires (empire_id , enemy_id)
VALUES (e_id , en_id);
err_code := 0;
EXCEPTION
WHEN unique_violation THEN
err_code := 3;
END;
END IF;
IF err_code = 0 THEN
PERFORM emp.switch_enemies( e_id );
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION emp.add_enemy_empire( INT , TEXT ) TO :dbuser;
--
-- Add an enemy alliance
--
-- Parameters:
-- e_id Empire identifier
-- e_name Alliance tag
--
-- Returns:
-- err_code Error code:
-- 0 on success
-- 1 if the specified alliance does not exist
-- 2 if the player is adding his/her own alliance
-- 3 if the enemy list already contains the specified alliance
--
CREATE OR REPLACE FUNCTION emp.add_enemy_alliance( e_id INT , e_name TEXT , OUT err_code INT )
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
en_id INT;
e_ca_id INT;
BEGIN
SELECT INTO en_id a.id
FROM emp.alliances a
WHERE lower( a.tag ) = lower( e_name );
IF NOT FOUND THEN
err_code := 1;
ELSE
SELECT INTO e_ca_id ea.alliance_id
FROM emp.alliance_members ea
WHERE ea.empire_id = e_id;
IF FOUND AND en_id = e_ca_id THEN
err_code := 2;
ELSE
BEGIN
INSERT INTO emp.enemy_alliances (empire_id , alliance_id)
VALUES (e_id , en_id);
err_code := 0;
EXCEPTION
WHEN unique_violation THEN
err_code := 3;
END;
END IF;
END IF;
IF err_code = 0 THEN
PERFORM emp.switch_enemies( e_id );
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION emp.add_enemy_alliance( INT , TEXT ) TO :dbuser;
--
-- Remove enemy empires
--
-- Parameters:
-- e_id Empire identifier
-- rem_ids Identifiers of enemy empires to remove
--
CREATE OR REPLACE FUNCTION emp.remove_enemy_empires( e_id INT , rem_ids INT[])
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
BEGIN
DELETE FROM emp.enemy_empires
WHERE empire_id = e_id AND enemy_id IN ( SELECT unnest( rem_ids ) AS id );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION emp.remove_enemy_empires( INT , INT[] ) TO :dbuser;
--
-- Remove enemy alliances
--
-- Parameters:
-- e_id Empire identifier
-- rem_ids Identifiers of enemy alliances to remove
--
CREATE OR REPLACE FUNCTION emp.remove_enemy_alliances( e_id INT , rem_ids INT[])
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
BEGIN
DELETE FROM emp.enemy_alliances
WHERE empire_id = e_id AND alliance_id IN ( SELECT unnest( rem_ids ) AS id );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION emp.remove_enemy_alliances( INT , INT[] ) TO :dbuser;
--
-- Switch enemies to attack
--
-- Parameters:
-- e_id Empire identifier
--
CREATE OR REPLACE FUNCTION emp.switch_enemies( e_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
rec RECORD;
BEGIN
CREATE TEMPORARY TABLE fleet_switches(
loc_id INT ,
loc_name VARCHAR(20) ,
own_id INT ,
own_name VARCHAR(20) ,
name VARCHAR(64) ,
power BIGINT ,
mode BOOLEAN
) ON COMMIT DROP;
INSERT INTO fleet_switches
SELECT f.location_id , ln.name , f.owner_id , fon.name ,
f.name , fs.power , TRUE
FROM fleets.fleets f
INNER JOIN emp.planets ep ON f.location_id = ep.planet_id
INNER JOIN verse.planets p ON p.name_id = ep.planet_id
INNER JOIN emp.enemies el ON el.enemy = f.owner_id
INNER JOIN fleets.stats_view fs ON fs.id = f.id
INNER JOIN naming.map_names ln ON ln.id = f.location_id
INNER JOIN naming.empire_names fon ON fon.id = f.owner_id
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id
WHERE ep.empire_id = e_id AND el.empire = e_id AND m.fleet_id IS NULL
AND NOT f.attacking;
PERFORM events.commit_fleet_switches( TRUE );
FOR rec IN SELECT DISTINCT f.location_id AS location , f.owner_id AS owner , b.id AS battle
FROM fleets.fleets f
INNER JOIN emp.planets ep ON f.location_id = ep.planet_id
INNER JOIN verse.planets p ON p.name_id = ep.planet_id
INNER JOIN emp.enemies el ON el.enemy = f.owner_id
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id
LEFT OUTER JOIN battles.battles b
ON b.location_id = ep.planet_id AND b.last_tick IS NULL
WHERE ep.empire_id = e_id AND el.empire = e_id AND m.fleet_id IS NULL
AND NOT f.attacking
LOOP
-- Set fleets mode
UPDATE fleets.fleets f
SET attacking = TRUE ,
status = 'REDEPLOYING' ,
penalty = ( CASE
WHEN f2.penalty > ( 1 + fs.flight_time * 40 )
THEN f2.penalty
ELSE ( 1 + fs.flight_time * 40 )
END )
FROM fleets.fleets f2
INNER JOIN fleets.stats_view fs ON fs.id = f2.id
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f2.id
WHERE f2.owner_id = rec.owner AND f2.location_id = rec.location
AND m.fleet_id IS NULL AND f2.id = f.id;
-- Update battle
PERFORM battles.set_mode( rec.battle , rec.owner , TRUE );
END LOOP;
PERFORM msgs.deliver_internal( );
END;
$$ LANGUAGE plpgsql;
--
-- Deletes an empire
--
CREATE OR REPLACE FUNCTION emp.delete_empire( e_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
p_id INT;
f_id BIGINT;
fleets BIGINT[];
BEGIN
-- Lock empire
PERFORM * FROM emp.empires WHERE name_id = e_id FOR UPDATE;
-- Disband fleets
fleets := '{}'::BIGINT[];
FOR f_id IN SELECT id FROM fleets.fleets WHERE owner_id = e_id FOR UPDATE
LOOP
fleets := array_append( fleets , f_id );
END LOOP;
PERFORM fleets.disband( e_id , fleets );
-- Abandon planets
FOR p_id IN SELECT planet_id FROM emp.planets WHERE empire_id = e_id
LOOP
PERFORM emp.leave_planet( p_id );
END LOOP;
-- Leave alliance
PERFORM emp.leave_alliance( e_id );
-- Delete empire
DELETE FROM emp.empires WHERE name_id = e_id;
END;
$$ LANGUAGE plpgsql;
--
-- Obtains a new planet
--
-- Parameters:
-- e_id Empire identifier
-- p_name Planet name
--
-- Returns:
-- err_code Error code:
-- 0 success
-- 1 banned name
-- 2 name unavailable
-- 3 empire has planets
--
CREATE OR REPLACE FUNCTION emp.get_new_planet( e_id INT , p_name TEXT , OUT err_code INT )
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
plid INT;
accid INT;
ccash REAL;
f_id BIGINT;
fleets BIGINT[];
BEGIN
-- Lock empire and check for existing planets
SELECT INTO ccash cash FROM emp.empires WHERE name_id = e_id FOR UPDATE;
PERFORM * FROM emp.planets WHERE empire_id = e_id LIMIT 1;
IF FOUND
THEN
err_code := 3;
RETURN;
END IF;
SELECT INTO accid owner_id FROM naming.empire_names WHERE id = e_id;
-- Get random planet and rename it
plid := verse.get_random_planet( );
IF plid IS NULL THEN
err_code := 2;
ELSE
err_code := - naming.change_map_name( plid , accid , p_name );
END IF;
IF err_code <> 0
THEN
RETURN;
END IF;
INSERT INTO emp.planets ( planet_id , empire_id )
VALUES ( plid , e_id );
-- Disband fleets
fleets := '{}'::BIGINT[];
FOR f_id IN SELECT id FROM fleets.fleets WHERE owner_id = e_id FOR UPDATE
LOOP
fleets := array_append( fleets , f_id );
END LOOP;
PERFORM fleets.disband( e_id , fleets );
-- Reset to initial cash if below
IF ccash < sys.get_constant( 'game.initialCash' )
THEN
UPDATE emp.empires
SET cash = sys.get_constant( 'game.initialCash' )
WHERE name_id = e_id;
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION emp.get_new_planet( INT , TEXT ) TO :dbuser;
--
-- Enemies view
--
CREATE VIEW emp.enemies
AS SELECT iq.empire AS empire , iq.enemy AS enemy FROM
( SELECT ee.empire_id AS empire , ee.enemy_id AS enemy
FROM emp.enemy_empires ee
UNION SELECT ea.empire_id AS empire , am.empire_id AS enemy
FROM emp.enemy_alliances ea
INNER JOIN emp.alliance_members am
ON am.alliance_id = ea.alliance_id AND NOT am.is_pending ) AS iq
ORDER BY iq.empire , iq.enemy;
--
-- General information view
--
CREATE VIEW emp.general_information
AS SELECT e.name_id AS id , en.name AS name ,
( CASE
WHEN av.status = 'QUITTING' THEN 'q'
WHEN av.status = 'VACATION' THEN 'v'
WHEN av.status = 'START_VACATION' THEN 's'
ELSE NULL
END ) AS status ,
e.cash AS cash , a.tag AS alliance ,
st.next_tick AS game_time ,
av.id AS account_id
FROM emp.empires e
INNER JOIN naming.empire_names en ON en.id = e.name_id
INNER JOIN users.accounts_view av ON av.id = en.owner_id
LEFT OUTER JOIN emp.alliance_members am
ON am.empire_id = e.name_id AND NOT am.is_pending
LEFT OUTER JOIN emp.alliances a ON a.id = am.alliance_id
CROSS JOIN sys.status st;
GRANT SELECT ON emp.general_information TO :dbuser;
--
-- Empire planets view
--
CREATE VIEW emp.planets_view
AS SELECT e.empire_id AS empire , n.id AS id , n.name AS name
FROM emp.planets e
INNER JOIN verse.planets p ON p.name_id = e.planet_id
INNER JOIN verse.systems s ON s.id = p.system_id
INNER JOIN naming.map_names n ON n.id = e.planet_id
ORDER BY e.empire_id , s.x , s.y , p.orbit;
GRANT SELECT ON emp.planets_view TO :dbuser;
--
-- Empire overviews
--
CREATE VIEW emp.planets_overview
AS SELECT e.name_id AS empire , count( p.* ) AS planets ,
sum( floor( p.population) ) AS population ,
floor( avg( 100.0 * ph.current / p.population ) ) AS avg_happiness ,
floor( sum( pm.income ) ) AS planet_income ,
floor( sum( pm.upkeep ) ) AS planet_upkeep
FROM emp.empires e
LEFT OUTER JOIN emp.planets ep ON ep.empire_id = e.name_id
LEFT OUTER JOIN verse.planets p ON p.name_id = ep.planet_id
LEFT OUTER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id
LEFT OUTER JOIN verse.planet_money pm ON pm.planet_id = p.name_id
GROUP BY e.name_id;
CREATE VIEW emp.civ_invest_acc_totals
AS SELECT e.name_id AS empire , sum( cq.money ) AS acc_total
FROM emp.empires e
LEFT OUTER JOIN emp.planets ep ON ep.empire_id = e.name_id
LEFT OUTER JOIN verse.bld_queues cq ON cq.planet_id = ep.planet_id
GROUP BY e.name_id;
CREATE VIEW emp.civ_investment_view
AS SELECT e.name_id AS empire ,
( sum( bqi.amount * bqid.cost ) - ( CASE WHEN ciat.acc_total IS NULL THEN 0 ELSE ciat.acc_total END ) )::BIGINT AS civ_investment
FROM emp.empires e
LEFT OUTER JOIN emp.planets ep ON ep.empire_id = e.name_id
LEFT OUTER JOIN emp.civ_invest_acc_totals ciat ON ciat.empire = e.name_id
LEFT OUTER JOIN verse.bld_items bqi ON bqi.queue_id = ep.planet_id AND NOT bqi.destroy
LEFT OUTER JOIN tech.buildables bqid ON bqid.name_id = bqi.building_id
GROUP BY e.name_id, ciat.acc_total;
CREATE VIEW emp.mil_invest_acc_totals
AS SELECT e.name_id AS empire , sum( mq.money ) AS acc_total
FROM emp.empires e
LEFT OUTER JOIN emp.planets ep ON ep.empire_id = e.name_id
LEFT OUTER JOIN verse.mil_queues mq ON mq.planet_id = ep.planet_id
GROUP BY e.name_id;
CREATE VIEW emp.mil_investment_view
AS SELECT e.name_id AS empire ,
( sum( mqi.amount * mqid.cost ) - ( CASE WHEN miat.acc_total IS NULL THEN 0 ELSE miat.acc_total END ) )::BIGINT AS mil_investment
FROM emp.empires e
LEFT OUTER JOIN emp.planets ep ON ep.empire_id = e.name_id
LEFT OUTER JOIN emp.mil_invest_acc_totals miat ON miat.empire = e.name_id
LEFT OUTER JOIN verse.mil_items mqi ON mqi.queue_id = ep.planet_id
LEFT OUTER JOIN tech.buildables mqid ON mqid.name_id = mqi.ship_id
GROUP BY e.name_id, miat.acc_total;
CREATE VIEW emp.fleets_overview
AS SELECT e.name_id AS empire ,
sum( sd.power * s.amount ) AS fleet_power ,
sum( sbd.upkeep * s.amount ) AS fleet_upkeep
FROM emp.empires e
LEFT OUTER JOIN fleets.fleets f ON f.owner_id = e.name_id
LEFT OUTER JOIN fleets.ships s ON s.fleet_id = f.id
LEFT OUTER JOIN tech.ships sd ON sd.buildable_id = s.ship_id
LEFT OUTER JOIN tech.buildables sbd ON sbd.name_id = sd.buildable_id
GROUP BY e.name_id;
CREATE VIEW emp.new_messages
AS SELECT e.name_id AS empire , count( m.* ) AS new_messages
FROM emp.empires e
LEFT OUTER JOIN msgs.empire_delivery m
ON m.empire_id = e.name_id AND m.in_inbox AND m.status = 'UNREAD'
GROUP BY e.name_id;
CREATE VIEW emp.overview
AS SELECT * FROM emp.planets_overview
INNER JOIN emp.fleets_overview USING (empire)
INNER JOIN emp.civ_investment_view USING (empire)
INNER JOIN emp.mil_investment_view USING (empire)
INNER JOIN emp.new_messages USING (empire);
GRANT SELECT ON emp.overview TO :dbuser;
--
-- Empire tech lines
--
CREATE VIEW emp.tech_lines_view
AS SELECT e.name_id AS empire , tl.name_id AS tech_line ,
t1.translated_string AS name ,
t2.translated_string AS description
FROM emp.empires e
INNER JOIN emp.technologies et ON et.empire_id = e.name_id
INNER JOIN tech.lines tl ON tl.name_id = et.line_id
INNER JOIN naming.empire_names en ON en.id = e.name_id
INNER JOIN users.credentials c ON c.address_id = en.owner_id
INNER JOIN defs.translations t1 ON t1.string_id = tl.name_id AND t1.lang_id = c.language_id
INNER JOIN defs.translations t2 ON t2.string_id = tl.description_id AND t2.lang_id = c.language_id
ORDER BY t1.translated_string;
GRANT SELECT ON emp.tech_lines_view TO :dbuser;
--
-- Empire technologies
--
CREATE VIEW emp.technologies_view
AS SELECT e.name_id AS empire , tl.name_id AS tech_line ,
t1.translated_string AS name ,
t2.translated_string AS description ,
( et.level > tlv.level ) AS implemented ,
floor( 100 * et.accumulated / tlv.points ) AS progress ,
tlv.cost AS cost
FROM emp.empires e
INNER JOIN emp.technologies et ON et.empire_id = e.name_id
INNER JOIN tech.lines tl ON tl.name_id = et.line_id
INNER JOIN tech.levels tlv ON tlv.line_id = tl.name_id AND tlv.level <= et.level
INNER JOIN naming.empire_names en ON en.id = e.name_id
INNER JOIN users.credentials c ON c.address_id = en.owner_id
INNER JOIN defs.translations t1 ON t1.string_id = tlv.name_id AND t1.lang_id = c.language_id
INNER JOIN defs.translations t2 ON t2.string_id = tlv.description_id AND t2.lang_id = c.language_id
ORDER BY tl.name_id , tlv.level;
GRANT SELECT ON emp.technologies_view TO :dbuser;
--
-- Enemy lists
--
CREATE VIEW emp.enemy_lists
AS SELECT x.empire AS empire , x.id AS id , x.name AS name , x.alliance AS alliance
FROM (
SELECT el.empire_id AS empire , el.enemy_id AS id , n.name AS name , FALSE AS alliance
FROM emp.enemy_empires el
INNER JOIN naming.empire_names n ON n.id = el.enemy_id
UNION SELECT el.empire_id AS empire , el.alliance_id AS id , a.tag AS name , TRUE AS alliance
FROM emp.enemy_alliances el
INNER JOIN emp.alliances a ON a.id = el.alliance_id
) AS x;
GRANT SELECT ON emp.enemy_lists TO :dbuser;

View file

@ -0,0 +1,341 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Various functions for in-game computations
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
/*
* Random value with deviation
*
* Parameters:
* _mean the mean value
* _deviation the deviation
*
* Returns:
* ? a random value between _mean - _deviation and
* _mean + _deviation, with a higher probability
* of a value that is close to _mean
*/
DROP FUNCTION IF EXISTS verse.random_deviation( DOUBLE PRECISION , DOUBLE PRECISION );
CREATE FUNCTION verse.random_deviation( _mean DOUBLE PRECISION , _deviation DOUBLE PRECISION )
RETURNS DOUBLE PRECISION
STRICT VOLATILE
SECURITY INVOKER
AS $random_deviation$
DECLARE
_result DOUBLE PRECISION;
BEGIN
_result := _deviation * RANDOM( ) ^ 2.5;
IF RANDOM() < 0.5 THEN
_result := -_result;
END IF;
RETURN _result + _mean;
END;
$random_deviation$ LANGUAGE PLPGSQL;
REVOKE EXECUTE
ON FUNCTION verse.random_deviation( DOUBLE PRECISION , DOUBLE PRECISION )
FROM PUBLIC;
/*
* Randomly distribute some part of a total value
*
* This function can be used when a total value must be distributed between
* various items. It will compute the minimal and maximal values that may be
* attributed, enforcing the fact that the whole value needs to be consumed
* in the end, and that values must conform to a specific range expressed as
* a mean value and a deviation.
*
* The total value is assumed to be valid with regards to the mean and
* deviation. That is:
*
* _parts * ( _mean - _deviation ) <= _quantity
* _parts * ( _mean + _deviation ) >= _quantity
*
* Parameters:
* _quantity the total quantity left to distribute
* _parts the amount of items left
* _mean the result's mean value
* _deviation the result's deviation
*
* Returns:
* ? the value to attribute to the nex item
*/
DROP FUNCTION IF EXISTS verse.get_random_part( DOUBLE PRECISION , INT , DOUBLE PRECISION , DOUBLE PRECISION );
CREATE FUNCTION verse.get_random_part(
_quantity DOUBLE PRECISION ,
_parts INT ,
_mean DOUBLE PRECISION ,
_deviation DOUBLE PRECISION )
RETURNS DOUBLE PRECISION
STRICT VOLATILE
SECURITY INVOKER
AS $get_random_part$
DECLARE
_min DOUBLE PRECISION;
_max DOUBLE PRECISION;
_n_mean DOUBLE PRECISION;
BEGIN
IF _parts = 1 THEN
RETURN _quantity;
END IF;
_min := _quantity - ( _mean + _deviation ) * ( _parts - 1 );
IF _min < _mean - _deviation THEN
_min := _mean - _deviation;
END IF;
_max := _quantity - ( _mean - _deviation ) * ( _parts - 1 );
IF _max > _mean + _deviation THEN
_max := _mean + _deviation;
END IF;
IF _min = _max THEN
RETURN _min;
END IF;
_n_mean := ( _min + _max ) * 0.5;
RETURN verse.random_deviation( _n_mean , _n_mean - _min );
END;
$get_random_part$ LANGUAGE PLPGSQL;
REVOKE EXECUTE
ON FUNCTION verse.get_random_part( DOUBLE PRECISION , INT , DOUBLE PRECISION , DOUBLE PRECISION )
FROM PUBLIC;
--
-- sigma( x ) = exp( x ) / ( 1 + exp( x ) )
--
CREATE OR REPLACE FUNCTION verse.sigma( x REAL )
RETURNS REAL
STRICT IMMUTABLE SECURITY INVOKER
AS $$
SELECT ( CASE
WHEN $1 < -100 THEN 0
WHEN $1 > 100 THEN 1
ELSE ( exp( $1 ) / ( 1 + exp( $1 ) ) )::REAL
END );
$$ LANGUAGE SQL;
--
-- poly( x , a , b , c ) = ( a * x + b ) * x + c
--
CREATE OR REPLACE FUNCTION verse.poly( x REAL , a REAL , b REAL , c REAL )
RETURNS REAL
STRICT IMMUTABLE SECURITY INVOKER
AS $$
SELECT ( $2 * $1 + $3 ) * $1 + $4;
$$ LANGUAGE SQL;
--
-- Happiness curve, K1 constant
--
CREATE OR REPLACE FUNCTION verse.hcc_const_k1( xmax REAL , ymax REAL , xlimit REAL , ylimit REAL )
RETURNS REAL
STRICT IMMUTABLE SECURITY INVOKER
AS $$
SELECT ( ( $4 - $2 ) / ( ( $3 - $1 ) ^ 2 ) )::REAL;
$$ LANGUAGE SQL;
--
-- Happiness curve, K2 constant
--
CREATE OR REPLACE FUNCTION verse.hcc_const_k2( ylimit REAL , yasymptote REAL )
RETURNS REAL
STRICT IMMUTABLE SECURITY INVOKER
AS $$
SELECT ( 2 * ( $1 - $2 ) )::REAL;
$$ LANGUAGE SQL;
--
-- Happiness curve, K3 constant
--
CREATE OR REPLACE FUNCTION verse.hcc_const_k3( xmax REAL , ymax REAL , xlimit REAL , ylimit REAL , yasymptote REAL )
RETURNS REAL
STRICT IMMUTABLE SECURITY INVOKER
AS $$
SELECT ( verse.hcc_const_k1( $1 , $2 , $3 , $4 ) * 4 * ( $3 - $1 ) / ( $5 - $4 ) ) ::REAL;
$$ LANGUAGE SQL;
--
-- Happiness curve, first part
--
CREATE OR REPLACE FUNCTION verse.hcc_part_1( x REAL , ymin REAL , ymax REAL , xmax REAL )
RETURNS REAL
STRICT IMMUTABLE SECURITY INVOKER
AS $$
DECLARE
v REAL;
BEGIN
v := ( ymin - ymax ) / xmax;
RETURN verse.poly( x , ( v / xmax )::REAL , ( -2 * v )::REAL , ymin );
END;
$$ LANGUAGE plpgsql;
--
-- Happiness curve, second part
--
CREATE OR REPLACE FUNCTION verse.hcc_part_2( x REAL , xmax REAL , ymax REAL , xlimit REAL , ylimit REAL )
RETURNS REAL
STRICT IMMUTABLE SECURITY INVOKER
AS $$
DECLARE
k1 REAL;
BEGIN
k1 := verse.hcc_const_k1( xmax , ymax , xlimit , ylimit );
RETURN verse.poly( x , k1 , ( -2 * xmax * k1 )::REAL , ( ymax + k1 * xmax * xmax )::REAL );
END;
$$ LANGUAGE plpgsql;
--
-- Happiness curve, third part
--
CREATE OR REPLACE FUNCTION verse.hcc_part_3( x REAL , xmax REAL , ymax REAL , xlimit REAL , ylimit REAL , yasymptote REAL )
RETURNS REAL
STRICT IMMUTABLE SECURITY INVOKER
AS $$
DECLARE
k2 REAL;
k3 REAL;
BEGIN
k2 := verse.hcc_const_k2( ylimit , yasymptote );
k3 := verse.hcc_const_k3( xmax , ymax , xlimit , ylimit , yasymptote );
RETURN yasymptote + k2 * ( 1 - verse.sigma( ( k3 * ( x - xlimit ) ) )::REAL );
END;
$$ LANGUAGE plpgsql;
--
-- Happiness curve
--
CREATE OR REPLACE FUNCTION verse.happiness_curve( x REAL , ymin REAL , xmax REAL , ymax REAL , xlimit REAL , ylimit REAL , yasymptote REAL )
RETURNS REAL
STRICT IMMUTABLE SECURITY INVOKER
AS $$
SELECT (CASE
WHEN $1 < $3 THEN
verse.hcc_part_1( $1 , $2 , $4 , $3 )
WHEN $1 < $5 THEN
verse.hcc_part_2( $1 , $3 , $4 , $5 , $6 )
ELSE
verse.hcc_part_3( $1 , $3 , $4 , $5 , $6 , $7 )
END)
$$ LANGUAGE SQL;
--
-- Happiness computation
--
CREATE OR REPLACE FUNCTION verse.compute_happiness( population REAL , workers REAL , defence REAL , empsize INT )
RETURNS REAL
STRICT STABLE SECURITY INVOKER
AS $$
DECLARE
whappiness REAL;
dhappiness REAL;
shappiness REAL;
BEGIN
-- Work-related happiness
whappiness := verse.happiness_curve(
( workers / population )::REAL ,
sys.get_constant( 'game.happiness.noEmployment' ) , 1.0 , 1.0 ,
sys.get_constant( 'game.happiness.employmentLimit' ) , 0.5 , 0
);
-- Defence-related happiness
dhappiness := verse.happiness_curve(
( sys.get_constant( 'game.happiness.popPerDefencePoint' ) * defence / population )::REAL ,
sys.get_constant( 'game.happiness.noDefence' ) , 1.0 , 1.0 ,
sys.get_constant( 'game.happiness.defenceLimit' ) , 0.5 , 0
);
-- Influence of empire size
shappiness := verse.happiness_curve(
( empsize::REAL / sys.get_constant( 'game.happiness.idealEmpireSize' ) )::REAL ,
sys.get_constant( 'game.happiness.smallEmpire' ) , 1.0 , 1.0 ,
sys.get_constant( 'game.happiness.eSizeLimit' ) , 0.5 , 0
);
RETURN ( shappiness * ( whappiness + dhappiness ) / 2.0 )::REAL;
END;
$$ LANGUAGE plpgsql;
--
-- Production adjustment
--
CREATE OR REPLACE FUNCTION verse.adjust_production( prod REAL , happiness REAL )
RETURNS REAL
STRICT IMMUTABLE
SECURITY INVOKER
AS $$
SELECT ( CASE
WHEN $2 < sys.get_constant( 'game.happiness.strike' ) THEN
( $1 * ( 1 - ( $2 / sys.get_constant( 'game.happiness.strike' ) ) ) )::REAL
ELSE
$1
END );
$$ LANGUAGE SQL;
--
-- Income computation
--
CREATE OR REPLACE FUNCTION verse.compute_income( population REAL , happiness REAL , cashprod REAL )
RETURNS REAL
STRICT STABLE
SECURITY INVOKER
AS $$
DECLARE
base REAL;
badj REAL;
cprod REAL;
BEGIN
badj := ( 1 - verse.adjust_production( 1.0 , happiness ) ) * sys.get_constant( 'game.work.strikeEffect' );
base := floor( population ) * sys.get_constant( 'game.work.population' ) * ( 1 - badj );
cprod := verse.adjust_production( cashprod , happiness ) * sys.get_constant( 'game.work.factory' );
RETURN cprod + base;
END;
$$ LANGUAGE plpgsql;

View file

@ -0,0 +1,51 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- A few types and internal functions used in most parts
-- of the universe generator.
--
-- Copyright(C) 2004-2012, DeepClone Development
-- --------------------------------------------------------
/* The coordinates of the area being generated. */
DROP TYPE IF EXISTS verse.generator_area_type CASCADE;
CREATE TYPE verse.generator_area_type AS (
x0 INT , y0 INT ,
x1 INT , y1 INT
);
/*
* List some quantity of random planets from an area of the universe
*
* This function returns a set of planet identifiers chosen at random from the
* specified area of the universe.
*
* Parameters:
* _area The area to select planets from
* _count The maximal amount of planets to return
*/
DROP FUNCTION IF EXISTS verse.list_random_planets_in( verse.generator_area_type , INT );
CREATE FUNCTION verse.list_random_planets_in( _area verse.generator_area_type , _count INT )
RETURNS SETOF INT
STRICT VOLATILE
SECURITY INVOKER
AS $list_random_planets_in$
SELECT _planets.name_id
FROM verse.planets _planets
INNER JOIN verse.systems _systems
ON _planets.system_id = _systems.id
WHERE _systems.x BETWEEN $1.x0 AND $1.x1
AND _systems.y BETWEEN $1.y0 AND $1.y1
ORDER BY RANDOM( )
LIMIT $2;
$list_random_planets_in$ LANGUAGE SQL;
REVOKE EXECUTE
ON FUNCTION verse.list_random_planets_in( verse.generator_area_type ,
INT )
FROM PUBLIC;

View file

@ -0,0 +1,384 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Functions for the resource provider generator
--
-- Copyright(C) 2004-2012, DeepClone Development
-- --------------------------------------------------------
/*
* Resource provider generator data
*
* This data type is used to store statistics about the existing resource
* providers. A single item of the type represents both statistics and
* parameters for a given resource type.
*/
DROP TYPE IF EXISTS verse.resprov_generator_type CASCADE;
CREATE TYPE verse.resprov_generator_type AS (
/* Type of natural resource */
resource_name_id INT ,
/* Planets in the universe */
planets DOUBLE PRECISION ,
/* Providers of this type in the universe */
providers DOUBLE PRECISION ,
/* Presence probability (from the resource's definition) */
presence DOUBLE PRECISION ,
/* Total maximal quantity of this type of resource in the whole
* universe.
*/
quantity DOUBLE PRECISION ,
/* Average quantity (from the resource's definition) */
quantity_avg DOUBLE PRECISION ,
/* Maximal deviation from the average quantity (from the resource's
* definition)
*/
quantity_dev DOUBLE PRECISION ,
/* Total extraction difficulty for this type of resource in the whole
* universe.
*/
difficulty DOUBLE PRECISION ,
/* Average difficulty (from the resource's definition) */
difficulty_avg DOUBLE PRECISION ,
/* Maximal deviation from the average difficulty (from the resource's
* definition)
*/
difficulty_dev DOUBLE PRECISION ,
/* Total recovery rate for this type of resource in the whole
* universe.
*/
recovery DOUBLE PRECISION ,
/* Average recovery rate (from the resource's definition) */
recovery_avg DOUBLE PRECISION ,
/* Maximal deviation from the average recovery rate (from the
*/
recovery_dev DOUBLE PRECISION
);
/*
* Collect resource provider statistics
*
* This procedure collects statistics about resource providers into a
* temporary table named resource_statistics, using the resprov_generator_type
* as the table's structure. The table will be dropped on commit.
*
* This function is necessary because the statistics must be collected before
* new planets are generated.
*/
DROP FUNCTION IF EXISTS verse.collect_resprov_statistics( );
CREATE FUNCTION verse.collect_resprov_statistics( )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $collect_resprov_statistics$
BEGIN
CREATE TEMP TABLE rp_stats
OF verse.resprov_generator_type
ON COMMIT DROP;
INSERT INTO rp_stats
SELECT resource_name_id ,
_pcount.planets AS planets ,
( CASE
WHEN _rp_stats.providers IS NULL THEN 0
ELSE _rp_stats.providers
END ) AS providers ,
natres_p_presence AS presence ,
( CASE
WHEN _rp_stats.tot_quantity IS NULL THEN 0
ELSE _rp_stats.tot_quantity
END ) AS quantity ,
natres_quantity_avg AS quantity_avg ,
natres_quantity_dev AS quantity_dev ,
( CASE
WHEN _rp_stats.tot_difficulty IS NULL THEN 0
ELSE _rp_stats.tot_difficulty
END ) AS difficulty ,
natres_difficulty_avg AS difficulty_avg ,
natres_difficulty_dev AS difficulty_dev ,
( CASE
WHEN _rp_stats.tot_recovery IS NULL THEN 0
ELSE _rp_stats.tot_recovery
END ) AS recovery ,
natres_recovery_avg AS recovery_avg ,
natres_recovery_dev AS recovery_dev
FROM defs.natural_resources
LEFT OUTER JOIN (
SELECT resource_name_id ,
COUNT(*) AS providers ,
SUM( resprov_quantity_max ) AS tot_quantity ,
SUM( resprov_difficulty ) AS tot_difficulty ,
SUM( resprov_recovery ) AS tot_recovery
FROM verse.resource_providers
GROUP BY resource_name_id
) AS _rp_stats USING ( resource_name_id )
CROSS JOIN (
SELECT COUNT(*) AS planets
FROM verse.planets
) AS _pcount;
END;
$collect_resprov_statistics$ LANGUAGE PLPGSQL;
REVOKE EXECUTE
ON FUNCTION verse.collect_resprov_statistics( )
FROM PUBLIC;
/* Compute a random delta for one of the resource provider parameters
*
* This function computes the total change on one of the resource provider
* parameters. The resulting value can then be split amongst resource
* providers as they are created.
*
* Parameters:
* _existing Amount of existing resource providers
* _new Amount of resource providers being created
* _total Current total value for the parameter
* _p_average Average parameter value (from the definition)
* _p_deviation Parameter value deviation (from the definition)
*
* Returns:
* ? The total value to distribute amongst new resource
* providers
*/
DROP FUNCTION IF EXISTS verse.compute_rpp_delta( DOUBLE PRECISION , DOUBLE PRECISION ,
DOUBLE PRECISION , DOUBLE PRECISION , DOUBLE PRECISION );
CREATE FUNCTION verse.compute_rpp_delta(
_existing DOUBLE PRECISION ,
_new DOUBLE PRECISION ,
_total DOUBLE PRECISION ,
_p_average DOUBLE PRECISION ,
_p_deviation DOUBLE PRECISION )
RETURNS DOUBLE PRECISION
STRICT VOLATILE
SECURITY INVOKER
AS $compute_rpp_delta$
DECLARE
_result DOUBLE PRECISION;
BEGIN
_result := verse.random_deviation( _p_average , _p_deviation )
* ( _existing + _new ) - _total;
IF _result < ( _p_average - _p_deviation ) * _new THEN
_result := ( _p_average - _p_deviation ) * _new;
ELSIF _result > ( _p_average + _p_deviation ) * _new THEN
_result := ( _p_average + _p_deviation ) * _new;
END IF;
RETURN _result;
END;
$compute_rpp_delta$ LANGUAGE PLPGSQL;
REVOKE EXECUTE
ON FUNCTION verse.compute_rpp_delta( DOUBLE PRECISION , DOUBLE PRECISION ,
DOUBLE PRECISION , DOUBLE PRECISION , DOUBLE PRECISION )
FROM PUBLIC;
/*
* Create a single resource provider
*
* This function creates a single resource provider on some planet. It will
* return the updated values for the amount of providers left to handle and
* the totals.
*
* Parameters:
* _planet The identifier of the planet to create a provider on
* _data The statistics and parameters for the type of resource
* _providers_left The amount of resource providers that still need to be
* generated (including the current provider)
* _tot_quantity The total value left to distribute for the providers'
* maximal quantity
* _tot_difficulty The total value left to distribute for the providers'
* extraction difficulty
* _tot_recovery The total value left to distribute for the providers'
* recovery rate
*
* Returns:
* _providers_left The updated value for the amount of providers left
* _tot_quantity The updated value for the total maximal quantity to
* distribute
* _tot_difficulty The updated value for the total extraction difficulty
* to distribute
* _tot_recovery The updated value for the total recovery rate to
* distribute
*/
DROP FUNCTION IF EXISTS verse.create_resource_provider(
INT , verse.resprov_generator_type , INT , DOUBLE PRECISION ,
DOUBLE PRECISION , DOUBLE PRECISION );
CREATE FUNCTION verse.create_resource_provider(
_planet INT ,
_data verse.resprov_generator_type ,
INOUT _providers_left INT ,
INOUT _tot_quantity DOUBLE PRECISION ,
INOUT _tot_difficulty DOUBLE PRECISION ,
INOUT _tot_recovery DOUBLE PRECISION )
STRICT VOLATILE
SECURITY INVOKER
AS $create_resource_provider$
DECLARE
_quantity DOUBLE PRECISION;
_difficulty DOUBLE PRECISION;
_recovery DOUBLE PRECISION;
BEGIN
_quantity := verse.get_random_part( _tot_quantity , _providers_left ,
_data.quantity_avg , _data.quantity_dev );
_difficulty := verse.get_random_part( _tot_difficulty , _providers_left ,
_data.difficulty_avg , _data.difficulty_dev );
_recovery := verse.get_random_part( _tot_recovery , _providers_left ,
_data.recovery_avg , _data.recovery_dev );
RAISE NOTICE 'Resource #% planet #%: quantity: % difficulty: % recovery: %',
_data.resource_name_id , _planet ,
_quantity , _difficulty , _recovery;
INSERT INTO verse.resource_providers (
planet_id , resource_name_id , resprov_quantity_max ,
resprov_quantity , resprov_difficulty , resprov_recovery
) VALUES (
_planet , _data.resource_name_id , _quantity ,
_quantity , _difficulty , _recovery
);
_tot_quantity := _tot_quantity - _quantity;
_tot_difficulty := _tot_difficulty - _difficulty;
_tot_recovery := _tot_recovery - _recovery;
_providers_left := _providers_left - 1;
END;
$create_resource_provider$ LANGUAGE PLPGSQL;
REVOKE EXECUTE
ON FUNCTION verse.create_resource_provider( INT ,
verse.resprov_generator_type , INT , DOUBLE PRECISION ,
DOUBLE PRECISION , DOUBLE PRECISION )
FROM PUBLIC;
/*
* Create resource providers for a given type of resource
*
* This function will create resource providers for some specified type of
* resource in an area of the universe. It tries to balance the generated
* values according to the resource's definition.
*
* Parameters:
* _area The area to generate resource providers in
* _data The identifier, definition and statistics for the type of
* resource
*/
DROP FUNCTION IF EXISTS verse.create_resource_providers(
verse.generator_area_type , verse.resprov_generator_type );
CREATE FUNCTION verse.create_resource_providers(
_area verse.generator_area_type ,
_data verse.resprov_generator_type )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $create_resource_providers$
DECLARE
_ncount INT;
_create INT;
_tot_quantity DOUBLE PRECISION;
_tot_difficulty DOUBLE PRECISION;
_tot_recovery DOUBLE PRECISION;
_planet INT;
BEGIN
_ncount := ( _area.x1 - _area.x0 + 1 ) * ( _area.y1 - _area.y0 + 1 ) * 5;
-- Determine the amount of providers to create
_create := FLOOR( ( _data.planets + _ncount ) * _data.presence - _data.providers )::INT;
IF _create <= 0 THEN
RETURN;
ELSIF _create > _ncount THEN
_create := _ncount;
END IF;
-- Compute the total delta for quantity, difficulty and recovery rate
_tot_quantity := verse.compute_rpp_delta( _data.providers , _create ,
_data.quantity , _data.quantity_avg , _data.quantity_dev );
_tot_difficulty := verse.compute_rpp_delta( _data.providers , _create ,
_data.difficulty , _data.difficulty_avg , _data.difficulty_dev );
_tot_recovery := verse.compute_rpp_delta( _data.providers , _create ,
_data.recovery , _data.recovery_avg , _data.recovery_dev );
RAISE NOTICE 'Resource #%: % new provider(s), quantity: % (avg. %) , difficulty: % (avg. %), recovery: % (avg. %)',
_data.resource_name_id , _create ,
_tot_quantity , _tot_quantity / _create ,
_tot_difficulty , _tot_difficulty / _create ,
_tot_recovery , _tot_recovery / _create;
-- Select random planets to add resource providers to
FOR _planet IN SELECT * FROM verse.list_random_planets_in( _area , _create )
LOOP
SELECT INTO _create , _tot_quantity , _tot_difficulty , _tot_recovery
* FROM verse.create_resource_provider( _planet , _data , _create ,
_tot_quantity , _tot_difficulty , _tot_recovery );
END LOOP;
END;
$create_resource_providers$ LANGUAGE PLPGSQL;
REVOKE EXECUTE
ON FUNCTION verse.create_resource_providers( verse.generator_area_type ,
verse.resprov_generator_type )
FROM PUBLIC;
/*
* Create resource providers in some area of the universe
*
* This function creates resource providers in the specified area using the
* statistics collected before the area was created to balance the resource
* providers' parameters.
*
* Parameters:
* _area The area to generate resource providers in
*/
DROP FUNCTION IF EXISTS verse.create_resource_providers( verse.generator_area_type );
CREATE FUNCTION verse.create_resource_providers( _area verse.generator_area_type )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $create_resource_providers$
DECLARE
_rp_data verse.resprov_generator_type;
BEGIN
FOR _rp_data IN SELECT * FROM rp_stats
LOOP
PERFORM verse.create_resource_providers( _area , _rp_data );
END LOOP;
END;
$create_resource_providers$ LANGUAGE PLPGSQL;
REVOKE EXECUTE
ON FUNCTION verse.create_resource_providers( verse.generator_area_type )
FROM PUBLIC;

View file

@ -0,0 +1,404 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Universe management functions and views
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
--
-- Obtains a planet's raw production
--
-- Parameters:
-- pid Planet identifier
-- pt Production type
--
-- Returns:
-- the planet's raw production of the specified type
--
CREATE OR REPLACE FUNCTION verse.get_raw_production( pid INT , pt building_output_type )
RETURNS REAL
STRICT STABLE
SECURITY DEFINER
AS $$
DECLARE
rv REAL;
BEGIN
SELECT INTO rv SUM( b.amount * d.output )::REAL
FROM verse.planet_buildings b
INNER JOIN tech.buildings d
ON d.buildable_id = b.building_id AND d.output_type = pt
WHERE b.planet_id = pid;
IF rv IS NULL THEN
rv := 0;
END IF;
RETURN rv;
END;
$$ LANGUAGE plpgsql;
--
-- Map view
--
CREATE VIEW verse.map_view
AS SELECT s.x AS x , s.y AS y , p.orbit AS orbit ,
n.id AS id , p.picture AS picture , n.name AS name ,
ep.empire_id AS owner ,
a.id AS alliance_id , a.tag AS tag
FROM verse.planets p
INNER JOIN verse.systems s
ON s.id = p.system_id
INNER JOIN naming.map_names n
ON n.id = p.name_id
LEFT OUTER JOIN emp.planets ep
ON ep.planet_id = p.name_id
LEFT OUTER JOIN emp.alliance_members am
ON ep.empire_id = am.empire_id AND NOT am.is_pending
LEFT OUTER JOIN emp.alliances a
ON a.id = am.alliance_id
ORDER BY s.x , s.y , p.orbit;
--
-- View of planets that can be assigned to players
--
CREATE VIEW verse.available_planets
AS SELECT p.name_id AS name_id
FROM verse.planets p
INNER JOIN verse.planet_happiness ph
ON ph.planet_id = p.name_id
LEFT OUTER JOIN emp.planets ep
ON ep.planet_id = p.name_id
LEFT OUTER JOIN fleets.fleets f
ON f.location_id = p.name_id
WHERE ep.empire_id IS NULL AND ph.target > 0.5
AND verse.get_raw_production( p.name_id , 'DEF'::building_output_type ) > 0
AND verse.get_raw_production( p.name_id , 'WORK'::building_output_type ) > 0
AND ph.current / p.population > sys.get_constant( 'game.happiness.strike' )
GROUP BY p.name_id HAVING count(f.*) = 0;
--
-- Returns a random free planet, locked for update
--
CREATE OR REPLACE FUNCTION verse.get_random_planet( )
RETURNS INT
STRICT VOLATILE
SECURITY INVOKER
AS $$
SELECT name_id
FROM verse.planets p
INNER JOIN verse.available_planets
USING ( name_id )
ORDER BY random() LIMIT 1
FOR UPDATE OF p;
$$ LANGUAGE SQL;
--
-- Obtains a planet's upkeep
--
-- Parameters:
-- pid Planet identifier
--
-- Returns:
-- the planet's current upkeep
--
CREATE OR REPLACE FUNCTION verse.get_planet_upkeep( pid INT )
RETURNS REAL
STRICT STABLE
SECURITY INVOKER
AS $$
DECLARE
rv REAL;
BEGIN
SELECT INTO rv SUM( b.amount * d.upkeep )::REAL
FROM verse.planet_buildings b
INNER JOIN tech.buildables d
ON d.name_id = b.building_id
WHERE b.planet_id = pid;
IF rv IS NULL THEN
rv := 0;
END IF;
RETURN rv;
END;
$$ LANGUAGE plpgsql;
--
-- Creates a planet
--
-- Parameters:
-- sid Stellar system ID
-- o Orbit number
-- ipop Initial population
-- npics Amount of planet pictures
--
CREATE OR REPLACE FUNCTION verse.create_planet( sid INT , o INT , ipop REAL , npics INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
pnid INT;
bworkers INT;
bpp INT;
uid BIGINT;
utp update_type;
happiness REAL;
BEGIN
-- Planet name and planet
pnid := naming.create_map_name( 'P' );
INSERT INTO verse.planets ( name_id , system_id , orbit , picture , population )
VALUES ( pnid , sid , o , 1 + floor( random() * npics ) , ipop );
-- Create build queues
INSERT INTO verse.bld_queues( planet_id , money , work )
VALUES ( pnid , 0 , 0 );
INSERT INTO verse.mil_queues( planet_id , money , work )
VALUES ( pnid , 0 , 0 );
-- Insert initial buildings
SELECT INTO bworkers SUM( d.workers ) FROM tech.buildings_view d
INNER JOIN tech.basic_buildables b USING( name_id );
bpp := floor( 0.5 * ipop / bworkers );
INSERT INTO verse.planet_buildings ( planet_id , building_id , amount , damage )
SELECT pnid , d.name_id , bpp , 0.0 FROM tech.buildings_view d
INNER JOIN tech.basic_buildables b USING( name_id );
-- Compute initial happiness
happiness := verse.compute_happiness(
ipop , bpp * bworkers ,
verse.get_raw_production( pnid , 'DEF'::building_output_type ) ,
0
);
INSERT INTO verse.planet_happiness ( planet_id , current , target )
VALUES ( pnid , ipop * happiness , happiness );
-- Compute initial income and upkeep
INSERT INTO verse.planet_money ( planet_id , income , upkeep )
VALUES ( pnid , verse.compute_income(
ipop , happiness ,
verse.get_raw_production( pnid , 'CASH'::building_output_type )
) , verse.get_planet_upkeep( pnid ) );
-- Add planet update records
FOR utp IN SELECT x FROM unnest( enum_range( NULL::update_type ) ) AS x
WHERE x::text LIKE 'PLANET_%'
LOOP
INSERT INTO sys.updates( gu_type )
VALUES ( utp )
RETURNING id INTO uid;
INSERT INTO verse.updates ( update_id , planet_id )
VALUES ( uid , pnid );
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Creates a stellar system
--
-- Parameters:
-- sx, sy Coordinates
-- ipop Initial population of planets
-- npics Amount of planet pictures
--
CREATE OR REPLACE FUNCTION verse.create_system( sx INT , sy INT , ipop REAL , npics INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
sid INT;
orbit INT;
BEGIN
-- Create system
INSERT INTO verse.systems ( x , y )
VALUES ( sx , sy )
RETURNING id INTO sid;
-- Create planets
FOR orbit IN 1 .. 5
LOOP
PERFORM verse.create_planet( sid , orbit , ipop , npics );
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Generate multiple systems at the specified coordinates
--
-- Parameters:
-- _area Area to generate
-- ipop Initial population
--
DROP FUNCTION IF EXISTS verse.create_systems( verse.generator_area_type , REAL );
CREATE FUNCTION verse.create_systems( _area verse.generator_area_type , ipop REAL )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
x INT;
y INT;
npics INT;
BEGIN
PERFORM verse.collect_resource_statistics( );
npics := floor( sys.get_constant( 'game.universe.pictures' ) );
FOR x IN _area.x0 .. area.x1
LOOP
FOR y IN area.y0 .. area.y1
LOOP
PERFORM verse.create_system( x , y , ipop , npics );
END LOOP;
END LOOP;
PERFORM verse.create_resource_providers( _area );
END;
$$ LANGUAGE plpgsql;
REVOKE EXECUTE
ON FUNCTION verse.create_systems( _area verse.generator_area_type , REAL )
FROM PUBLIC;
--
-- Generate the initial universe
--
CREATE OR REPLACE FUNCTION verse.generate_initial_universe( )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
sz INT;
pop REAL;
npics INT;
BEGIN
sz := floor( sys.get_constant( 'game.universe.initialSize' ) );
pop := sys.get_constant( 'game.universe.initialPopulation' );
PERFORM verse.create_systems( -sz , -sz , sz , sz , pop );
END;
$$ LANGUAGE plpgsql;
--
-- Expand the universe
--
CREATE OR REPLACE FUNCTION verse.expand_universe( )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
min_x INT;
max_x INT;
min_y INT;
max_y INT;
x_size INT;
y_size INT;
x_axis BOOLEAN;
posit BOOLEAN;
x0 INT;
y0 INT;
x1 INT;
y1 INT;
pop REAL;
BEGIN
-- Get current bounds
SELECT INTO min_x , max_x , min_y , max_y
MIN(x) , MAX(x) , MIN(y) , MAX(y)
FROM verse.systems;
x_size := 1 + max_x - min_x;
y_size := 1 + max_y - min_y;
-- Find out which axis/direction to use
x_axis := ( x_size = y_size );
IF x_axis THEN
posit := ( max_x = -min_x );
ELSE
posit := ( max_y = -min_y );
END IF;
-- Compute area coordinates
IF x_axis THEN
x0 := ( CASE posit WHEN TRUE THEN max_x + 1 ELSE min_x - 1 END );
x1 := x0;
y0 := min_y;
y1 := max_y;
ELSE
y0 := ( CASE posit WHEN TRUE THEN max_y + 1 ELSE min_y - 1 END );
y1 := y0;
x0 := min_x;
x1 := max_x;
END IF;
-- Get average population and generate new systems
SELECT INTO pop AVG( population ) FROM verse.planets;
PERFORM verse.create_systems( ROW( x0 , y0 , x1 , y1 ) , pop );
END;
$$ LANGUAGE plpgsql;
--
-- Universe generator function
--
-- Called by the game engine; generate the initial universe if it is empty, or expand it
-- if the ratio of available planets is too low.
--
CREATE OR REPLACE FUNCTION verse.generate( )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
p_count INT;
f_ratio REAL;
BEGIN
-- Get total planet count
SELECT INTO p_count 5 * count(*)
FROM verse.systems;
-- Empty universe -> initialise
IF p_count = 0 THEN
PERFORM verse.generate_initial_universe( );
RETURN;
END IF;
-- Get available planets ratio
SELECT INTO f_ratio count(*)::REAL / p_count::REAL
FROM verse.available_planets;
-- Expand universe if required
IF f_ratio < sys.get_constant( 'game.universe.minFreeRatio' ) THEN
PERFORM verse.expand_universe( );
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION verse.generate() TO :dbuser;

File diff suppressed because it is too large Load diff

View file

@ -0,0 +1,313 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- User sessions functions
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- MAIN SESSION VIEW --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
CREATE VIEW users.sessions
AS SELECT s.* , e.ended , e.end_type , c.name AS client_name , c.exclusive
FROM users.session_starts s
INNER JOIN defs.session_clients c ON c.id = s.client_id
LEFT OUTER JOIN users.session_ends e ON s.id = e.id
ORDER BY e.ended DESC NULLS FIRST , s.started DESC;
GRANT SELECT ON users.sessions TO :dbuser;
CREATE VIEW users.last_session
AS SELECT credentials_id , max( id ) AS session_id
FROM users.session_starts
GROUP BY credentials_id;
CREATE VIEW users.last_online
AS SELECT ls.credentials_id , ( CASE WHEN se.id IS NULL THEN now() ELSE se.ended END ) AS t
FROM users.last_session ls
LEFT OUTER JOIN users.session_ends se ON se.id = ls.session_id;
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- SESSION MANAGEMENT FUNCTIONS --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
--
-- Marks all active sessions as terminated due to server restart
--
CREATE OR REPLACE FUNCTION users.sessions_server_restart( )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
INSERT INTO users.session_ends( id , end_type )
SELECT s.id , 'SERVER'::session_termination_type
FROM users.session_starts s
LEFT OUTER JOIN users.session_ends e USING ( id )
WHERE e.id IS NULL;
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION users.sessions_server_restart( ) TO :dbuser;
--
-- Registers a session's initialisation
--
-- Parameters:
-- c_id Credentials identifier
-- s_name Session name
-- c_type Client type name
-- s_addr Session address
--
-- Returns:
-- s_id Session identifier
--
CREATE OR REPLACE FUNCTION users.sessions_login( c_id INT , s_name TEXT , c_type TEXT , s_addr TEXT , OUT s_id BIGINT )
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
cl_id INT;
excl BOOLEAN;
as_id BIGINT;
as_nm TEXT;
BEGIN
-- Get client type parameters
SELECT INTO cl_id , excl id , exclusive
FROM defs.session_clients
WHERE name = c_type;
IF NOT FOUND
THEN
RAISE EXCEPTION 'Client session type "%" not found' , c_type;
END IF;
-- Close all active, exclusive sessions from the same user if the new session is exclusive
IF excl
THEN
FOR as_id , as_nm IN SELECT s.id , s.session
FROM users.session_starts s
INNER JOIN defs.session_clients c
ON s.client_id = c.id AND c.exclusive
LEFT OUTER JOIN users.session_ends e ON s.id = e.id
WHERE s.credentials_id = c_id AND e.id IS NULL
FOR UPDATE OF s
LOOP
PERFORM users.write_log( c_id , 'WARNING'::log_level , 'Terminating exclusive session "' || as_nm
|| '" due to new exlusive session' );
INSERT INTO users.session_ends ( id , end_type )
VALUES ( as_id , 'EXCLUSIVE'::session_termination_type );
END LOOP;
END IF;
-- Add new session
INSERT INTO users.session_starts ( credentials_id , client_id , session , from_address )
VALUES ( c_id , cl_id , s_name , s_addr )
RETURNING id INTO s_id;
PERFORM users.write_log( c_id , 'DEBUG'::log_level , 'Logged in from ' || s_addr
|| ' with client ' || c_type || '; session #' || s_id );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION users.sessions_login( INT , TEXT , TEXT , TEXT ) TO :dbuser;
--
-- Terminates a session
--
-- Parameters:
-- s_id Session identifier
-- e_type Session end type
--
CREATE OR REPLACE FUNCTION users.sessions_terminate( s_id BIGINT , e_type session_termination_type )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
c_id INT;
BEGIN
-- Get user identifier
SELECT INTO c_id s.credentials_id
FROM users.session_starts s
LEFT OUTER JOIN users.session_ends e USING ( id )
WHERE s.id = s_id AND e.id IS NULL
FOR UPDATE OF s;
IF NOT FOUND
THEN
RETURN;
END IF;
-- Terminate session
INSERT INTO users.session_ends ( id , end_type )
VALUES ( s_id , e_type );
PERFORM users.write_log( c_id , 'DEBUG'::log_level , 'Session #' || s_id
|| ' ended, termination type: ' || e_type );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION users.sessions_terminate( BIGINT , session_termination_type ) TO :dbuser;
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- INACTIVITY CHECKS AND SESSION CLEAN-UP --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
--
-- User account record, used to send e-mails
--
CREATE TYPE inactive_account_record AS (
id INT ,
address TEXT ,
language TEXT
);
--
-- Checks for accounts that should receive an inactivity warning e-mail
--
-- Returns:
-- A set of user account records
--
CREATE OR REPLACE FUNCTION users.check_inactivity_emails()
RETURNS SETOF inactive_account_record
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
in_units BIGINT;
in_mail BIGINT;
in_time INTERVAL;
a_rec inactive_account_record;
BEGIN
in_units := floor( sys.get_constant( 'accounts.inactivity.units' ) );
in_mail := floor( sys.get_constant( 'accounts.inactivity.warningMail' ) );
in_time := ( (in_units * in_mail ) || 's' )::INTERVAL;
FOR a_rec IN SELECT cr.address_id AS id , ad.address , lg.language
FROM users.last_online lo
INNER JOIN users.credentials cr ON lo.credentials_id = cr.address_id
INNER JOIN users.addresses ad ON ad.id = cr.address_id
INNER JOIN defs.languages lg ON lg.id = cr.language_id
INNER JOIN users.active_accounts aa ON aa.credentials_id = lo.credentials_id
LEFT OUTER JOIN users.vacations vac ON vac.account_id = lo.credentials_id
LEFT OUTER JOIN users.inactivity_emails im ON im.account_id = lo.credentials_id
WHERE vac IS NULL AND im IS NULL AND now() - lo.t > in_time
FOR UPDATE OF cr , aa , ad
LOOP
INSERT INTO users.inactivity_emails ( account_id ) VALUES ( a_rec.id );
PERFORM users.write_log( a_rec.id , 'INFO'::log_level , 'Sending inactivity warning e-mail' );
RETURN NEXT a_rec;
END LOOP;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION users.check_inactivity_emails() TO :dbuser;
--
-- Removes inactivity e-mail records when users have logged on *after* the e-mail was sent
-- Disables inactive accounts, and lists them
--
CREATE OR REPLACE FUNCTION users.check_inactivity( )
RETURNS SETOF inactive_account_record
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
in_units BIGINT;
in_drop BIGINT;
in_time INTERVAL;
a_rec RECORD;
r_rec inactive_account_record;
BEGIN
in_units := floor( sys.get_constant( 'accounts.inactivity.units' ) );
in_drop := floor( sys.get_constant( 'accounts.inactivity.deletion' ) );
in_time := ( (in_units * in_drop ) || 's' )::INTERVAL;
-- Delete inactivity email records for players who've logged in since the mail was sent
DELETE FROM users.inactivity_emails WHERE account_id IN (
SELECT lo.credentials_id
FROM users.last_online lo
INNER JOIN users.inactivity_emails im
ON im.account_id = lo.credentials_id AND im.mail_sent <= lo.t
);
-- Disable inactive user accounts
FOR a_rec IN SELECT cr.address_id AS id , ad.address , lg.language , e.name_id AS e_id
FROM users.inactivity_emails im
INNER JOIN users.credentials cr ON im.account_id = cr.address_id
INNER JOIN users.active_accounts aa ON aa.credentials_id = im.account_id
INNER JOIN users.addresses ad ON ad.id = cr.address_id
INNER JOIN defs.languages lg ON lg.id = cr.language_id
INNER JOIN naming.empire_names en ON en.owner_id = cr.address_id
INNER JOIN emp.empires e ON e.name_id = en.id
WHERE now() - im.mail_sent > in_time
FOR UPDATE OF cr , aa , ad , lg , en , e
LOOP
PERFORM users.write_log( a_rec.id , 'INFO'::log_level , 'Disabling account due to inactivity' );
PERFORM emp.delete_empire( a_rec.e_id );
DELETE FROM users.active_accounts WHERE credentials_id = a_rec.id;
INSERT INTO users.inactive_accounts ( credentials_id , since , status )
VALUES ( a_rec.id , now() - '1s'::INTERVAL , 'PROCESSED' );
r_rec := ( a_rec.id , a_rec.address, a_rec.language );
RETURN NEXT r_rec;
END LOOP;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION users.check_inactivity() TO :dbuser;
--
-- Destroys old, inactive accounts
--
CREATE OR REPLACE FUNCTION users.delete_old_accounts( )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DELETE FROM users.addresses WHERE id IN (
SELECT ia.credentials_id
FROM users.inactive_accounts ia
LEFT OUTER JOIN admin.admin_credentials ac USING ( credentials_id )
LEFT OUTER JOIN admin.administrators ad ON ad.id = ac.administrator_id
WHERE now() - since >= '6 months'::INTERVAL AND ( ad IS NULL OR ad.privileges = 0 )
);
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION users.delete_old_accounts() TO :dbuser;

View file

@ -0,0 +1,84 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Buildings views and management functions
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
--
-- Construct buildings on a planet
--
-- Parameters:
-- pid Planet identifier
-- bid Building type
-- bcnt Amount of buildings
--
CREATE OR REPLACE FUNCTION verse.do_construct_buildings( pid INT , bid INT , bcnt INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
BEGIN
LOOP
UPDATE verse.planet_buildings
SET amount = amount + bcnt
WHERE planet_id = pid AND building_id = bid;
EXIT WHEN FOUND;
BEGIN
INSERT INTO verse.planet_buildings( planet_id , building_id , amount , damage )
VALUES( pid , bid , bcnt , 0 );
EXIT;
EXCEPTION
WHEN unique_violation THEN
-- Do nothing, try updating again.
END;
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Destroy buildings on a planet
--
-- Parameters:
-- pid Planet identifier
-- bid Building type
-- bcnt Amount of buildings
--
-- Returns:
-- amount of buildings that were destroyed
--
CREATE OR REPLACE FUNCTION verse.do_destroy_buildings( pid INT , bid INT , bcnt INT )
RETURNS INT
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
tmp INT;
BEGIN
UPDATE verse.planet_buildings
SET amount = amount - bcnt
WHERE planet_id = pid AND building_id = bid;
IF FOUND THEN
RETURN bcnt;
END IF;
RETURN 0;
EXCEPTION
WHEN check_violation THEN
SELECT INTO tmp amount FROM verse.planet_buildings
WHERE planet_id = pid AND building_id = bid
FOR UPDATE;
UPDATE verse.planet_buildings
SET amount = 0
WHERE planet_id = pid AND building_id = bid;
RETURN tmp;
END;
$$ LANGUAGE plpgsql;

View file

@ -0,0 +1,107 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- System status functions
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
--
-- Enter maintenance mode
--
-- Parameters:
-- a_id Administrator identifier
-- reason_txt Maintenance reason
-- duration Expected duration (minutes)
--
-- Returns:
-- success TRUE on success, FALSE if the system was already in maintenance mode
--
CREATE OR REPLACE FUNCTION sys.enter_maintenance_mode( IN a_id INT , IN reason_txt TEXT , IN duration INT , OUT success BOOLEAN )
STRICT VOLATILE
SECURITY DEFINER
AS $$
BEGIN
UPDATE sys.status
SET maintenance_start = NOW( ) ,
maintenance_end = NOW( ) + ( duration || 'm' )::INTERVAL ,
maintenance_text = reason_txt
WHERE maintenance_start IS NULL;
success := FOUND;
IF success
THEN
PERFORM admin.write_log( a_id , 'WARNING'::log_level , 'enabled maintenance mode for ' ||
duration || ' minutes; reason: ' || reason_txt );
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION sys.enter_maintenance_mode( INT , TEXT , INT ) TO :dbuser;
--
-- Extend maintenance mode duration
--
-- Parameters:
-- a_id Administrator identifier
-- ext_duration Expected extended duration (minutes)
--
-- Returns:
-- success TRUE on success, FALSE if the system was not in maintenance mode
--
CREATE OR REPLACE FUNCTION sys.extend_maintenance_mode( IN a_id INT , IN ext_duration INT , OUT success BOOLEAN )
STRICT VOLATILE
SECURITY DEFINER
AS $$
BEGIN
UPDATE sys.status
SET maintenance_end = NOW( ) + ( ext_duration || 'm' )::INTERVAL
WHERE maintenance_start IS NOT NULL;
success := FOUND;
IF success
THEN
PERFORM admin.write_log( a_id , 'WARNING'::log_level , 'extended maintenance mode duration by ' ||
ext_duration || ' minutes' );
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION sys.extend_maintenance_mode( INT , INT ) TO :dbuser;
--
-- Exit maintenance mode
--
-- Parameters:
-- a_id Administrator identifier
--
-- Returns:
-- success TRUE on success, FALSE if the system was not in maintenance mode
--
CREATE OR REPLACE FUNCTION sys.exit_maintenance_mode( IN a_id INT , OUT success BOOLEAN )
STRICT VOLATILE
SECURITY DEFINER
AS $$
BEGIN
UPDATE sys.status
SET maintenance_start = NULL ,
maintenance_end = NULL ,
maintenance_text = NULL
WHERE maintenance_start IS NOT NULL;
success := FOUND;
IF success
THEN
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'terminated maintenance mode' );
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION sys.exit_maintenance_mode( INT ) TO :dbuser;

View file

@ -0,0 +1,283 @@
-- 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;

View file

@ -0,0 +1,58 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Map display functions and related types
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
-- Map entry
CREATE TYPE map_entry_type AS (
x INT ,
y INT ,
orbit INT ,
id INT ,
picture INT ,
name TEXT ,
tag TEXT ,
display empire_relation_type
);
--
-- Generates the map from an empire's point of view
--
-- Parameters:
-- e_id the empire viewing the map
-- min_x minimal X coordinate
-- min_y minimal Y coordinate
-- max_x maximal X coordinate
-- max_y maximal Y coordinate
--
-- Returns:
-- a set of map entries
--
CREATE OR REPLACE FUNCTION verse.get_map( e_id INT , min_x INT , min_y INT , max_x INT , max_y INT )
RETURNS SETOF map_entry_type
STRICT STABLE
SECURITY DEFINER
AS $$
SELECT mv.x AS x , mv.y AS y , mv.orbit AS orbit , mv.id AS id , mv.picture AS picture ,
mv.name AS name , mv.tag AS tag ,
(CASE
WHEN mv.owner = $1 THEN 'OWN'
WHEN mv.alliance_id IS NOT NULL AND mv.alliance_id = ea.alliance_id THEN 'ALLIED'
WHEN en.alliance_id IS NOT NULL THEN 'ENEMY'
ELSE NULL
END )::empire_relation_type AS display
FROM verse.map_view mv
LEFT OUTER JOIN emp.alliance_members ea
ON ea.empire_id = $1 AND NOT is_pending
LEFT OUTER JOIN emp.enemy_alliances en
ON en.empire_id = $1 AND en.alliance_id = mv.alliance_id
WHERE x BETWEEN $2 AND $4 AND y BETWEEN $3 AND $5;
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION verse.get_map( INT , INT , INT , INT , INT ) TO :dbuser;

File diff suppressed because it is too large Load diff

View file

@ -0,0 +1,61 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Resource providers functions
--
-- Copyright(C) 2004-2012, DeepClone Development
-- --------------------------------------------------------
/*
* Compute resource provider regeneration
*
* This function computes the quantity in a resource provider after it has
* been regenerated.
*
* Parameters:
* _quantity The current quantity of resources in the provider
* _max The maximal amount of resources supported by the
* provider
* _recovery_rate The provider's recovery rate
*
* Returns:
* ? The new quantity of resources.
*/
CREATE OR REPLACE FUNCTION verse.compute_provider_regeneration(
_quantity DOUBLE PRECISION ,
_max DOUBLE PRECISION ,
_recovery_rate DOUBLE PRECISION )
RETURNS DOUBLE PRECISION
STRICT IMMUTABLE
SECURITY INVOKER
AS $compute_provider_regeneration$
DECLARE
_uc_recovery DOUBLE PRECISION;
_uc_dampening DOUBLE PRECISION;
_uc_ticks DOUBLE PRECISION;
_result DOUBLE PRECISION;
BEGIN
_uc_recovery := sys.get_constant( 'game.resources.recovery' );
_uc_dampening := sys.get_constant( 'game.resources.recoveryDampening' );
_uc_ticks := 1440; -- FIXME: this should be a constant
_result := ( 1 - _quantity / _max ) ^ _uc_dampening;
_result := _quantity + _result * _recovery_rate * _uc_recovery / _uc_ticks;
IF _result > _max THEN
_result := _max;
END IF;
RETURN _result;
END;
$compute_provider_regeneration$ LANGUAGE PLPGSQL;
REVOKE EXECUTE
ON FUNCTION verse.compute_provider_regeneration(
DOUBLE PRECISION , DOUBLE PRECISION ,
DOUBLE PRECISION )
FROM PUBLIC;

View file

@ -0,0 +1,839 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Battle functions and utility views
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
--
-- Checks if a battle needs to start at a given location
--
-- Parameters:
-- l_id Location to check
--
-- Returns:
-- Whether or not a new battle is to be added
--
CREATE OR REPLACE FUNCTION battles.check_start( l_id INT )
RETURNS BOOLEAN
STRICT STABLE
SECURITY INVOKER
AS $$
BEGIN
PERFORM p.name_id
FROM verse.planets p
INNER JOIN fleets.fleets f ON f.location_id = p.name_id AND f.attacking
LEFT OUTER JOIN fleets.movements m
ON m.fleet_id = f.id
LEFT OUTER JOIN battles.battles b
ON b.location_id = p.name_id AND last_tick IS NULL
WHERE p.name_id = l_id AND m.fleet_id IS NULL and b.id IS NULL;
RETURN FOUND;
END;
$$ LANGUAGE plpgsql;
--
-- Creates or returns an empire's battle record
--
-- Parameters:
-- e_id Empire identifier
--
-- Returns:
-- the empire battle record's identifier
--
CREATE OR REPLACE FUNCTION battles.goc_empire( e_id INT )
RETURNS BIGINT
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
r_id BIGINT;
BEGIN
LOOP
SELECT INTO r_id id FROM battles.empires
WHERE empire_id = e_id;
EXIT WHEN FOUND;
INSERT INTO battles.empires ( name , empire_id )
SELECT name , id FROM naming.empire_names
WHERE id = e_id
RETURNING id INTO r_id;
PERFORM * FROM battles.empires
WHERE empire_id = e_id AND id <> r_id;
EXIT WHEN NOT FOUND;
DELETE FROM battles.empires WHERE id = r_id;
END LOOP;
RETURN r_id;
END;
$$ LANGUAGE plpgsql;
--
-- Creates or returns a protagonist's record
--
-- Parameters:
-- b_id Battle identifier
-- e_id Empire identifier
-- mode Protagonist mode
-- tick Current tick
--
CREATE OR REPLACE FUNCTION battles.goc_protagonist( b_id BIGINT , e_id INT , mode BOOLEAN , tick BIGINT )
RETURNS BIGINT
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
be_id BIGINT;
p_id BIGINT;
lmode BOOLEAN;
BEGIN
be_id := battles.goc_empire( e_id );
LOOP
SELECT INTO p_id id FROM battles.protagonists
WHERE battle_id = b_id AND empire_id = be_id;
EXIT WHEN FOUND;
BEGIN
INSERT INTO battles.protagonists ( battle_id , empire_id )
VALUES ( b_id , be_id )
RETURNING id INTO p_id;
EXIT;
EXCEPTION
WHEN unique_violation THEN
-- Do nothing
END;
END LOOP;
SELECT INTO lmode attacking
FROM battles.status_changes WHERE protagonist_id = p_id
ORDER BY tick_identifier DESC LIMIT 1;
IF NOT FOUND OR lmode <> mode
THEN
INSERT INTO battles.status_changes ( protagonist_id , tick_identifier , attacking )
VALUES ( p_id , tick , mode );
END IF;
RETURN p_id;
END;
$$ LANGUAGE plpgsql;
--
-- Initialises a battle record
--
-- Parameters:
-- l_id Location
-- tick The current tick's identifier
--
-- Returns:
-- the battle's identifier
--
CREATE OR REPLACE FUNCTION battles.initialise( l_id INT , tick BIGINT )
RETURNS BIGINT
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
-- Battle ID
b_id BIGINT;
-- Battle planet ID
bp_id BIGINT;
-- Record for list operations
rec RECORD;
-- Protagonist ID
prot_id BIGINT;
-- Fleet status record ID
bf_id BIGINT;
-- Planet owner
po_id INT;
BEGIN
-- Create main battle record
INSERT INTO battles.battles ( location_id , first_tick )
VALUES ( l_id , tick )
RETURNING id INTO b_id;
-- Create planet record
INSERT INTO battles.planets( battle_id , tick_identifier , change_type , name )
SELECT b_id , tick , 'INIT'::battle_planet_change , n.name
FROM naming.map_names n WHERE n.id = l_id
RETURNING id INTO bp_id;
-- Insert list of initial buildings
INSERT INTO battles.buildings ( planet_id , building_id , change )
SELECT bp_id , b.building_id , b.amount
FROM verse.planet_buildings b
INNER JOIN tech.buildings bd ON bd.buildable_id = b.building_id
WHERE b.planet_id = l_id AND bd.output_type = 'DEF' AND b.amount > 0;
-- Insert defensive power
INSERT INTO battles.defences ( battle_id , tick_identifier , power )
SELECT b_id , tick , floor( verse.adjust_production(
verse.get_raw_production( p.name_id , 'DEF' ) , ph.current / p.population ) )
FROM verse.planets p
INNER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id
WHERE p.name_id = l_id;
-- Add protagonists and initial status
SELECT INTO po_id empire_id FROM emp.planets ep WHERE ep.planet_id = l_id;
FOR rec IN SELECT f.owner_id AS id , f.attacking AS mode
FROM fleets.fleets f
INNER JOIN naming.empire_names n ON n.id = f.owner_id
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id
WHERE f.location_id = l_id AND m.fleet_id IS NULL
UNION SELECT ep.empire_id AS id , FALSE AS mode
FROM emp.planets ep
WHERE ep.planet_id = l_id
LOOP
prot_id := battles.goc_protagonist( b_id , rec.id , rec.mode , tick );
IF po_id = rec.id THEN
INSERT INTO battles.planet_ownership ( protagonist_id )
VALUES ( prot_id );
END IF;
-- Insert fleets
INSERT INTO battles.fleets ( protagonist_id , tick_identifier , change_type )
VALUES ( prot_id , tick , 'INIT'::battle_fleet_change )
RETURNING id INTO bf_id;
INSERT INTO battles.ships ( fleet_id , ship_id , change )
SELECT bf_id , s.ship_id , sum( s.amount )
FROM fleets.fleets f
INNER JOIN fleets.ships s ON s.fleet_id = f.id
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id
WHERE f.owner_id = rec.id AND f.location_id = l_id
AND m.fleet_id IS NULL AND f.status <> 'DEPLOYING'
GROUP BY s.ship_id;
END LOOP;
RETURN b_id;
END;
$$ LANGUAGE plpgsql;
--
-- Adds fleet ship changes
--
CREATE OR REPLACE FUNCTION battles.add_fleet_change( f_id BIGINT , s_id INT , l_change INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
BEGIN
LOOP
UPDATE battles.ships SET change = change + l_change
WHERE fleet_id = f_id AND ship_id = s_id;
EXIT WHEN FOUND;
BEGIN
INSERT INTO battles.ships ( fleet_id , ship_id , change )
VALUES ( f_id , s_id , l_change );
EXIT;
EXCEPTION
WHEN unique_violation THEN
-- Do nothing
END;
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Gets or create a planet's change record
--
-- Parameters:
-- b_id Battle identifier
-- ctype Change type
-- tick Tick identifier
--
-- Returns:
-- the planet's change record
--
CREATE OR REPLACE FUNCTION battles.goc_planet( b_id BIGINT , ctype battle_planet_change , tick BIGINT )
RETURNS BIGINT
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
pr_id BIGINT;
BEGIN
LOOP
SELECT INTO pr_id id FROM battles.planets
WHERE battle_id = b_id AND change_type = ctype
AND tick_identifier = tick;
EXIT WHEN FOUND;
BEGIN
INSERT INTO battles.planets( battle_id , tick_identifier , change_type )
VALUES ( b_id , tick , ctype )
RETURNING id INTO pr_id;
EXIT;
EXCEPTION
WHEN unique_violation THEN
-- Do nothing
END;
END LOOP;
RETURN pr_id;
END;
$$ LANGUAGE plpgsql;
--
-- Records building changes
--
-- Parameters:
-- pcr_id Planet change record
-- bt_id Building type
-- amount Amount
--
CREATE OR REPLACE FUNCTION battles.record_building_change( pcr_id BIGINT , bt_id INT , amount INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
BEGIN
LOOP
UPDATE battles.buildings
SET change = change + amount
WHERE planet_id = pcr_id AND building_id = bt_id;
EXIT WHEN FOUND;
BEGIN
INSERT INTO battles.buildings ( planet_id , building_id , change )
VALUES ( pcr_id , bt_id , amount );
EXIT;
EXCEPTION
WHEN unique_violation THEN
-- Do nothing
END;
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Adds buildings to a planet's buildings list
--
-- Parameters:
-- p_id Planet identifier
-- bt_id Building type
-- amount Amount of buildings to add
-- tick Current tick identifier
--
CREATE OR REPLACE FUNCTION battles.add_buildings( p_id INT , bt_id INT , amount INT , tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
b_id BIGINT;
pcr_id BIGINT;
BEGIN
-- Check building type
PERFORM buildable_id FROM tech.buildings WHERE buildable_id = bt_id AND output_type = 'DEF';
IF NOT FOUND THEN
RETURN;
END IF;
-- Get battle identifier
SELECT INTO b_id id FROM battles.battles
WHERE location_id = p_id AND last_tick IS NULL;
IF NOT FOUND THEN
RETURN;
END IF;
-- Record changes
pcr_id := battles.goc_planet( b_id , 'BUILD' , tick );
PERFORM battles.record_building_change( pcr_id , bt_id , amount );
END;
$$ LANGUAGE plpgsql;
--
-- Removes buildings to a planet's buildings list
--
-- Parameters:
-- p_id Planet identifier
-- bt_id Building type
-- amount Amount of buildings to remove
-- bdmg Whether the losses have been caused by battle damage
-- tick Current tick identifier
--
CREATE OR REPLACE FUNCTION battles.remove_buildings( p_id INT , bt_id INT , amount INT , bdmg BOOLEAN , tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
b_id BIGINT;
pcr_id BIGINT;
BEGIN
-- Check building type
PERFORM buildable_id FROM tech.buildings WHERE buildable_id = bt_id AND output_type = 'DEF';
IF NOT FOUND THEN
RETURN;
END IF;
-- Get battle identifier
SELECT INTO b_id id FROM battles.battles
WHERE location_id = p_id AND last_tick IS NULL;
IF NOT FOUND THEN
RETURN;
END IF;
-- Record changes
pcr_id := battles.goc_planet( b_id , ( CASE WHEN bdmg THEN 'BATTLE' ELSE 'DESTROY' END )::battle_planet_change , tick );
PERFORM battles.record_building_change( pcr_id , bt_id , -amount );
END;
$$ LANGUAGE plpgsql;
--
-- Adds a record when the planet is renamed
--
-- Parameters:
-- p_id Planet identifier
-- nnm New name
--
CREATE OR REPLACE FUNCTION battles.rename_planet( p_id INT , nnm TEXT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
b_id BIGINT;
pcr_id BIGINT;
BEGIN
-- Get battle identifier
SELECT INTO b_id id FROM battles.battles
WHERE location_id = p_id AND last_tick IS NULL;
IF NOT FOUND THEN
RETURN;
END IF;
-- Record change
pcr_id := battles.goc_planet( b_id , 'RENAME' , sys.get_tick() );
UPDATE battles.planets
SET name = nnm
WHERE id = pcr_id;
END;
$$ LANGUAGE plpgsql;
--
-- Gets or creates a fleet change record
--
-- Parameters:
-- bp_id Protagonist identifier
-- tick Tick identifier
-- ctype Change type
--
CREATE OR REPLACE FUNCTION battles.goc_fleet_change( bp_id BIGINT , tick BIGINT , ctype battle_fleet_change )
RETURNS BIGINT
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
bf_id BIGINT;
BEGIN
LOOP
SELECT INTO bf_id id FROM battles.fleets
WHERE protagonist_id = bp_id AND tick_identifier = tick AND change_type = ctype;
EXIT WHEN FOUND;
BEGIN
INSERT INTO battles.fleets ( protagonist_id , tick_identifier , change_type )
VALUES ( bp_id , tick , ctype )
RETURNING id INTO bf_id;
EXIT;
EXCEPTION
WHEN unique_violation THEN
-- Do nothing
END;
END LOOP;
RETURN bf_id;
END;
$$ LANGUAGE plpgsql;
--
-- Adds a fleet to the battle
--
-- Parameters:
-- b_id Battle identifier
-- f_id Fleet identifier
-- dep Whether the fleet was added at the end of its deployment phase
-- tick Current tick
--
CREATE OR REPLACE FUNCTION battles.add_fleet( b_id BIGINT , f_id BIGINT , dep BOOLEAN , tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
e_id INT;
f_att BOOLEAN;
bp_id BIGINT;
bf_id BIGINT;
ctype battle_fleet_change;
rec RECORD;
BEGIN
-- Get owner's protagonist record
SELECT INTO e_id , f_att owner_id , attacking
FROM fleets.fleets
WHERE id = f_id;
bp_id := battles.goc_protagonist( b_id , e_id , f_att , tick );
-- Try getting or creating the fleet's record
ctype := ( CASE WHEN dep THEN 'BUILD' ELSE 'ARRIVE' END );
bf_id := battles.goc_fleet_change( bp_id , tick , ctype );
-- Insert or update fleet ships
FOR rec IN SELECT ship_id , amount FROM fleets.ships WHERE fleet_id = f_id
LOOP
PERFORM battles.add_fleet_change( bf_id , rec.ship_id , rec.amount );
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Removes a fleet from the battle
--
-- Parameters:
-- b_id Battle identifier
-- f_id Fleet identifier
-- ctype Change type
-- tick Current tick
--
CREATE OR REPLACE FUNCTION battles.remove_fleet( b_id BIGINT , f_id BIGINT , ctype battle_fleet_change , tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
e_id INT;
f_att BOOLEAN;
bp_id BIGINT;
bf_id BIGINT;
rec RECORD;
BEGIN
-- Get owner's protagonist record
SELECT INTO e_id , f_att owner_id , attacking
FROM fleets.fleets
WHERE id = f_id;
bp_id := battles.goc_protagonist( b_id , e_id , f_att , tick );
-- Try getting or creating the fleet's record
bf_id := battles.goc_fleet_change( bp_id , tick , ctype );
-- Insert or update fleet ships
FOR rec IN SELECT ship_id , amount FROM fleets.ships WHERE fleet_id = f_id
LOOP
PERFORM battles.add_fleet_change( bf_id , rec.ship_id , - rec.amount );
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Sets an empire's mode
--
-- Parameters:
-- b_id Battle identifier
-- e_id Empire identifier
-- att Whether the empire is attacking or defending
--
CREATE OR REPLACE FUNCTION battles.set_mode( b_id BIGINT , e_id INT , att BOOLEAN )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
tick BIGINT;
p_id BIGINT;
BEGIN
SELECT INTO p_id p.id
FROM battles.empires e
INNER JOIN battles.protagonists p ON p.empire_id = e.id
WHERE e.empire_id = e_id AND p.battle_id = b_id;
IF NOT FOUND THEN
RETURN;
END IF;
tick := sys.get_tick( );
LOOP
DELETE FROM battles.status_changes
WHERE protagonist_id = p_id AND tick_identifier = tick AND attacking = ( NOT att );
EXIT WHEN FOUND;
BEGIN
INSERT INTO battles.status_changes ( protagonist_id , tick_identifier , attacking )
VALUES ( p_id , tick , att );
EXIT;
EXCEPTION
WHEN unique_violation THEN
-- Do nothing
END;
PERFORM * FROM battles.status_changes
WHERE protagonist_id = p_id AND tick_identifier = tick AND attacking = att;
EXIT WHEN FOUND;
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Inflicts damage to one side of the engagement
--
-- Parameters:
-- b_id Battle identifer
-- dmg Amount of damage to inflict
-- att Whether damage is being inflicted to attacking fleets
-- tick Current tick identifier
--
CREATE OR REPLACE FUNCTION battles.inflict_damage( b_id BIGINT , dmg REAL , att BOOLEAN , tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
planet INT;
tot_power BIGINT;
st_power BIGINT;
rec RECORD;
BEGIN
-- Get total power from fleets
SELECT INTO tot_power sum( fs.power )
FROM battles.battles b
LEFT OUTER JOIN fleets.fleets f ON f.location_id = b.location_id AND f.attacking = att
LEFT OUTER JOIN fleets.stats_view fs ON fs.id = f.id
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id
WHERE b.id = b_id AND m.fleet_id IS NULL;
IF tot_power IS NULL THEN
tot_power := 0;
END IF;
SELECT INTO planet location_id FROM battles.battles WHERE id = b_id;
-- If damage is being inflicted to defence forces, handle defence buildings
IF NOT att THEN
st_power := battles.get_defence_power( b_id , tick );
tot_power := tot_power + st_power;
PERFORM sys.write_sql_log( 'BattleUpdate' , 'TRACE'::log_level , 'About to inflict planet damage; total power: ' || tot_power
|| '; planet power: ' || st_power || '; computed damage: ' || ( dmg * st_power / tot_power )::REAL );
IF st_power <> 0 THEN
PERFORM verse.inflict_battle_damage( planet , st_power , ( dmg * st_power / tot_power )::REAL , b_id , tick );
END IF;
END IF;
-- Inflict damage to fleets
FOR rec IN SELECT f.id , fs.power
FROM battles.battles b
INNER JOIN fleets.fleets f ON f.location_id = b.location_id
INNER JOIN fleets.stats_view fs ON fs.id = f.id
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id
WHERE b.id = b_id AND m.fleet_id IS NULL AND f.attacking = att
LOOP
PERFORM fleets.inflict_battle_damage( rec.id , ( dmg * rec.power / tot_power )::REAL , b_id , tick );
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Computes the size/power of a planet's defences at a given tick
--
CREATE TYPE planet_defence_size AS (
item_id INT ,
amount INT
);
CREATE OR REPLACE FUNCTION battles.get_defence_size( b_id BIGINT , tick BIGINT )
RETURNS SETOF planet_defence_size
STRICT STABLE
SECURITY INVOKER
AS $$
SELECT bb.building_id AS item_id , sum( bb.change )::INT AS amount
FROM battles.planets bp
INNER JOIN battles.buildings bb ON bb.planet_id = bp.id
WHERE bp.battle_id = $1 AND bp.tick_identifier <= $2
GROUP BY bb.building_id;
$$ LANGUAGE SQL;
CREATE OR REPLACE FUNCTION battles.set_defence_power( b_id BIGINT , tick BIGINT , pw BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
BEGIN
IF battles.get_defence_power( b_id , tick ) <> pw
THEN
LOOP
UPDATE battles.defences SET power = pw
WHERE battle_id = b_id AND tick_identifier = tick;
EXIT WHEN FOUND;
BEGIN
INSERT INTO battles.defences ( battle_id , tick_identifier , power )
VALUES ( b_id , tick , pw );
EXIT;
EXCEPTION
WHEN unique_violation THEN
-- EMPTY
END;
END LOOP;
END IF;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION battles.get_defence_power( b_id BIGINT , tick BIGINT )
RETURNS BIGINT
STRICT STABLE
SECURITY DEFINER
AS $$
SELECT power FROM battles.defences
WHERE battle_id = $1 AND tick_identifier = (
SELECT max( tick_identifier ) FROM battles.defences
WHERE battle_id = $1 AND tick_identifier <= $2
);
$$ LANGUAGE SQL;
--
-- Lists battle protagonists in a specific mode at a given tick
--
CREATE OR REPLACE FUNCTION battles.get_protagonists_with_mode( b_id BIGINT , tick BIGINT , mode BOOLEAN )
RETURNS SETOF BIGINT
STRICT STABLE
SECURITY INVOKER
AS $$
SELECT protagonist_id
FROM battles.status_changes c
INNER JOIN (
SELECT sc.protagonist_id , max( sc.tick_identifier ) AS tick_identifier
FROM battles.status_changes sc
INNER JOIN battles.protagonists p ON p.id = sc.protagonist_id
WHERE sc.tick_identifier <= $2 AND p.battle_id = $1
GROUP BY protagonist_id
) x USING ( protagonist_id , tick_identifier )
WHERE c.attacking = $3;
$$ LANGUAGE SQL;
--
-- Computes the size/power of fleets in a specific mode at a given tick
--
CREATE TYPE battle_fleet_size AS (
protagonist_id BIGINT ,
ship_id INT ,
amount INT
);
CREATE OR REPLACE FUNCTION battles.get_fleets_composition( b_id BIGINT , tick BIGINT )
RETURNS SETOF battle_fleet_size
STRICT STABLE
SECURITY INVOKER
AS $$
SELECT bp.id AS protagonist_id , bs.ship_id AS item_id , sum( bs.change )::INT AS amount
FROM battles.fleets bf
INNER JOIN battles.protagonists bp ON bp.id = bf.protagonist_id
INNER JOIN battles.ships bs ON bs.fleet_id = bf.id
WHERE bp.battle_id = $1 AND bf.tick_identifier <= $2
GROUP BY bp.id , bs.ship_id;
$$ LANGUAGE SQL;
CREATE TYPE battle_fleet_power AS (
protagonist_id BIGINT ,
power BIGINT
);
CREATE OR REPLACE FUNCTION battles.get_fleets_power( b_id BIGINT , tick BIGINT )
RETURNS SETOF battle_fleet_power
STRICT STABLE
SECURITY INVOKER
AS $$
SELECT ds.protagonist_id , ( CASE
WHEN sum( ds.amount * s.power ) IS NULL THEN
0
ELSE
sum( ds.amount * s.power )
END ) AS power
FROM battles.get_fleets_composition( $1 , $2 ) ds
INNER JOIN tech.ships s ON s.buildable_id = ds.ship_id
GROUP BY ds.protagonist_id;
$$ LANGUAGE SQL;
CREATE OR REPLACE FUNCTION battles.get_biggest_fleet_owner( b_id BIGINT , tick BIGINT )
RETURNS INT
STRICT STABLE
SECURITY INVOKER
AS $$
SELECT e.empire_id
FROM battles.get_fleets_power( $1 , $2 ) fp
INNER JOIN battles.protagonists bp ON bp.id = fp.protagonist_id
INNER JOIN battles.empires e ON e.id = bp.empire_id
ORDER BY fp.power DESC
LIMIT 1;
$$ LANGUAGE SQL;
CREATE OR REPLACE FUNCTION battles.get_fleets_power( b_id BIGINT , tick BIGINT , mode BOOLEAN )
RETURNS BIGINT
STRICT STABLE
SECURITY DEFINER
AS $$
SELECT ( CASE
WHEN sum( fp.power ) IS NULL THEN
0
ELSE
sum( fp.power )
END )::BIGINT
FROM battles.get_fleets_power( $1 , $2 ) fp
INNER JOIN battles.get_protagonists_with_mode( $1 , $2 , $3 ) pm
ON fp.protagonist_id = pm;
$$ LANGUAGE SQL;

View file

@ -0,0 +1,483 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Views that are used to display battles
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
--
-- Battle status view
--
CREATE VIEW battles.current_status
AS SELECT location_id AS location , id , ( battles.get_defence_power( id , sys.get_tick() ) + battles.get_fleets_power( id , sys.get_tick() , FALSE ) ) AS defence ,
battles.get_fleets_power( id , sys.get_tick() , TRUE ) AS attack
FROM battles.battles WHERE last_tick IS NULL;
GRANT SELECT ON battles.current_status TO :dbuser;
--
-- Viewable battles, by empire
--
CREATE VIEW battles.empire_list_view
AS SELECT be.empire_id AS empire , b.id AS battle ,
bpt.id AS protagonist ,
b.first_tick , b.last_tick ,
p.name_id AS planet ,
s.x , s.y , p.orbit ,
bpl.name
FROM battles.empires be
INNER JOIN battles.protagonists bpt ON bpt.empire_id = be.id
INNER JOIN battles.battles b ON b.id = bpt.battle_id
INNER JOIN verse.planets p ON p.name_id = b.location_id
INNER JOIN verse.systems s ON s.id = p.system_id
INNER JOIN battles.planets bpl ON bpl.battle_id = b.id AND bpl.change_type = 'INIT'
WHERE be.empire_id IS NOT NULL;
GRANT SELECT ON battles.empire_list_view TO :dbuser;
--
-- Ticks to include in a battle display
--
CREATE VIEW battles.battle_ticks_view
AS SELECT x.battle , x.tick FROM (
SELECT battle_id AS battle , tick_identifier AS tick
FROM battles.planets
UNION SELECT battle_id AS battle , tick_identifier AS tick
FROM battles.defences
UNION SELECT bp.battle_id AS battle , bsc.tick_identifier AS tick
FROM battles.status_changes bsc
INNER JOIN battles.protagonists bp ON bp.id = bsc.protagonist_id
UNION SELECT bp.battle_id AS battle , bf.tick_identifier AS tick
FROM battles.fleets bf
INNER JOIN battles.protagonists bp ON bp.id = bf.protagonist_id
UNION SELECT id AS battle , last_tick AS tick
FROM battles.battles
WHERE last_tick IS NOT NULL
) x
ORDER BY x.tick;
GRANT SELECT ON battles.battle_ticks_view TO :dbuser;
--
-- Mode history view
--
CREATE OR REPLACE FUNCTION battles.get_protagonist_status_at( bp_id BIGINT , tick_id BIGINT )
RETURNS BOOLEAN
STRICT IMMUTABLE
SECURITY DEFINER
AS $$
SELECT attacking FROM battles.status_changes
WHERE protagonist_id = $1 AND tick_identifier <= $2
ORDER BY tick_identifier DESC LIMIT 1;
$$ LANGUAGE SQL;
CREATE VIEW battles.mode_history_view
AS SELECT btv.battle , btv.tick , bp.id AS protagonist ,
be.id AS empire_id , be.name AS empire_name ,
battles.get_protagonist_status_at( bp.id , btv.tick ) AS attacking
FROM battles.battle_ticks_view btv
INNER JOIN battles.protagonists bp ON bp.battle_id = btv.battle
INNER JOIN battles.empires be ON be.id = bp.empire_id
ORDER BY btv.tick , be.name;
GRANT SELECT ON battles.mode_history_view TO :dbuser;
--
-- Ships history
--
CREATE VIEW battles.protagonist_ships
AS SELECT DISTINCT bf.protagonist_id , bs.ship_id
FROM battles.fleets bf
INNER JOIN battles.ships bs ON bs.fleet_id = bf.id;
CREATE OR REPLACE FUNCTION battles.get_lost_ships( bp_id BIGINT , tick_id BIGINT, ship_id INT )
RETURNS BIGINT
STRICT IMMUTABLE
SECURITY DEFINER
AS $$
SELECT -sum( fs.change )
FROM battles.ships fs
INNER JOIN battles.fleets bf ON fs.fleet_id = bf.id
WHERE bf.protagonist_id = $1 AND bf.tick_identifier <= $2
AND bf.change_type = 'BATTLE' AND fs.ship_id = $3
$$ LANGUAGE SQL;
CREATE OR REPLACE FUNCTION battles.get_current_ships( bp_id BIGINT , tick_id BIGINT, ship_id INT )
RETURNS BIGINT
STRICT IMMUTABLE
SECURITY DEFINER
AS $$
SELECT sum( fs.change )
FROM battles.ships fs
INNER JOIN battles.fleets bf ON fs.fleet_id = bf.id
WHERE bf.protagonist_id = $1 AND bf.tick_identifier <= $2
AND fs.ship_id = $3
$$ LANGUAGE SQL;
CREATE VIEW battles.fleets_history
AS SELECT elv.empire , elv.battle , btv.tick ,
bpt.id AS protagonist , t.translated_string AS ship_type ,
battles.get_current_ships( bpt.id , btv.tick , bps.ship_id ) AS current ,
battles.get_lost_ships( bpt.id , btv.tick , bps.ship_id ) AS lost ,
s.power AS ship_power
FROM battles.empire_list_view elv
INNER JOIN battles.battle_ticks_view btv USING (battle)
INNER JOIN battles.protagonists bpt ON bpt.battle_id = elv.battle
INNER JOIN battles.protagonist_ships bps ON bps.protagonist_id = bpt.id
INNER JOIN tech.ships s ON s.buildable_id = bps.ship_id
INNER JOIN naming.empire_names en ON en.id = elv.empire
INNER JOIN users.credentials c ON c.address_id = en.owner_id
INNER JOIN defs.translations t
ON t.lang_id = c.language_id AND t.string_id = bps.ship_id
ORDER BY s.power;
GRANT SELECT ON battles.fleets_history TO :dbuser;
--
-- Protagonist presence in a battle at any given tick
--
CREATE VIEW battles.protagonist_ship_types
AS SELECT DISTINCT bp.id AS protagonist , bs.ship_id AS ship_type
FROM battles.protagonists bp
INNER JOIN battles.fleets bf ON bf.protagonist_id = bp.id
INNER JOIN battles.ships bs ON bs.fleet_id = bf.id;
CREATE VIEW battles.ships_at_tick
AS SELECT btv.battle , btv.tick , bp.id AS protagonist ,
sum( battles.get_current_ships( bp.id , btv.tick, bs.ship_type ) ) AS ships
FROM battles.battle_ticks_view btv
INNER JOIN battles.protagonists bp ON bp.battle_id = btv.battle
INNER JOIN battles.protagonist_ship_types bs ON bs.protagonist = bp.id
GROUP BY btv.battle , btv.tick , bp.id;
CREATE OR REPLACE FUNCTION battles.get_current_ships( bp_id BIGINT , tick_id BIGINT )
RETURNS BIGINT
STRICT IMMUTABLE
SECURITY DEFINER
AS $$
SELECT ( CASE WHEN sum( fs.change ) IS NULL THEN 0 ELSE sum( fs.change ) END )
FROM battles.ships fs
INNER JOIN battles.fleets bf ON fs.fleet_id = bf.id
WHERE bf.protagonist_id = $1 AND bf.tick_identifier <= $2
$$ LANGUAGE SQL;
CREATE VIEW battles.protagonist_presence
AS SELECT btv.battle , btv.tick , bp.id AS protagonist ,
( bpo.protagonist_id IS NOT NULL
OR battles.get_current_ships( bp.id , btv.tick ) > 0 ) AS present ,
( bpo.protagonist_id IS NOT NULL ) AS planet_owner
FROM battles.battle_ticks_view btv
INNER JOIN battles.protagonists bp ON bp.battle_id = btv.battle
LEFT OUTER JOIN battles.planet_ownership bpo
ON bpo.protagonist_id = bp.id AND ( bpo.abandoned_at IS NULL OR bpo.abandoned_at > btv.tick );
GRANT SELECT ON battles.protagonist_presence TO :dbuser;
--
-- Buildings history
--
CREATE VIEW battles.buildings_list
AS SELECT DISTINCT bp.battle_id AS battle , bb.building_id
FROM battles.planets bp
INNER JOIN battles.buildings bb ON bb.planet_id = bp.id;
CREATE OR REPLACE FUNCTION battles.get_current_buildings( b_id BIGINT , tick_id BIGINT , building_id INT )
RETURNS BIGINT
STRICT IMMUTABLE
SECURITY DEFINER
AS $$
SELECT sum( change )
FROM battles.buildings b
INNER JOIN battles.planets bp ON bp.id = b.planet_id
WHERE bp.battle_id = $1 AND bp.tick_identifier <= $2 AND b.building_id = $3;
$$ LANGUAGE SQL;
CREATE OR REPLACE FUNCTION battles.get_lost_buildings( b_id BIGINT , tick_id BIGINT , building_id INT )
RETURNS BIGINT
STRICT IMMUTABLE
SECURITY DEFINER
AS $$
SELECT -sum( change )
FROM battles.buildings b
INNER JOIN battles.planets bp ON bp.id = b.planet_id
WHERE bp.battle_id = $1 AND bp.tick_identifier <= $2
AND b.building_id = $3 AND bp.change_type = 'BATTLE';
$$ LANGUAGE SQL;
CREATE VIEW battles.raw_buildings_history
AS SELECT btv.battle , btv.tick , bbl.building_id ,
battles.get_current_buildings( btv.battle , btv.tick , bbl.building_id ) AS current ,
battles.get_lost_buildings( btv.battle , btv.tick , bbl.building_id ) AS lost ,
b.output AS raw_power
FROM battles.battle_ticks_view btv
INNER JOIN battles.buildings_list bbl USING (battle)
INNER JOIN tech.buildings b ON b.buildable_id = bbl.building_id;
CREATE VIEW battles.raw_buildings_power
AS SELECT rbh.battle , rbh.tick ,
sum( rbh.current * rbh.raw_power ) AS raw_power ,
battles.get_defence_power( rbh.battle , rbh.tick ) AS actual_power
FROM battles.raw_buildings_history rbh
GROUP BY rbh.battle , rbh.tick;
CREATE VIEW battles.buildings_history
AS SELECT elv.empire , rbh.battle , rbh.tick ,
t.translated_string AS building ,
( CASE WHEN rbh.current IS NULL THEN 0 ELSE rbh.current END ) AS current ,
( CASE WHEN rbh.lost IS NULL THEN 0 ELSE rbh.lost END ) AS lost ,
( CASE
WHEN rbp.raw_power = 0 THEN
rbh.raw_power
ELSE
rbh.raw_power::REAL * rbp.actual_power::REAL / rbp.raw_power::REAL
END )::REAL AS power
FROM battles.empire_list_view elv
INNER JOIN battles.raw_buildings_history rbh USING (battle)
INNER JOIN battles.raw_buildings_power rbp USING (battle,tick)
INNER JOIN naming.empire_names en ON en.id = elv.empire
INNER JOIN users.credentials c ON c.address_id = en.owner_id
INNER JOIN defs.translations t
ON t.string_id = rbh.building_id AND t.lang_id = c.language_id
ORDER BY rbp.raw_power;
GRANT SELECT ON battles.buildings_history TO :dbuser;
--
-- Events
--
CREATE VIEW battles.rename_events
AS SELECT bp.battle_id AS battle , bp.tick_identifier AS tick ,
'RENAME'::TEXT AS event_type , TRUE AS is_planet ,
NULL::BIGINT AS event_id , bp.name AS name , NULL::BOOLEAN AS attack
FROM battles.planets bp
WHERE bp.change_type = 'RENAME';
CREATE VIEW battles.switch_events
AS SELECT bp.battle_id AS battle , bsc.tick_identifier AS tick ,
'SWITCH'::TEXT AS event_type , FALSE AS is_planet ,
NULL::BIGINT AS event_id , be.name AS name , bsc.attacking AS attack
FROM battles.status_changes bsc
INNER JOIN battles.protagonists bp ON bp.id = bsc.protagonist_id
INNER JOIN battles.empires be ON be.id = bp.empire_id
INNER JOIN battles.battles b
ON b.id = bp.battle_id AND bsc.tick_identifier > b.first_tick;
CREATE VIEW battles.arrive_events
AS SELECT bp.battle_id AS battle , bf.tick_identifier AS tick ,
'ARRIVE'::TEXT AS event_type , FALSE AS is_planet ,
bf.id AS event_id , be.name AS name ,
battles.get_protagonist_status_at( bp.id , bf.tick_identifier ) AS attack
FROM battles.fleets bf
INNER JOIN battles.protagonists bp ON bp.id = bf.protagonist_id
INNER JOIN battles.empires be ON be.id = bp.empire_id
WHERE bf.change_type = 'ARRIVE';
CREATE VIEW battles.depart_events
AS SELECT bp.battle_id AS battle , bf.tick_identifier AS tick ,
'DEPART'::TEXT AS event_type , FALSE AS is_planet ,
bf.id AS event_id , be.name AS name ,
battles.get_protagonist_status_at( bp.id , bf.tick_identifier ) AS attack
FROM battles.fleets bf
INNER JOIN battles.protagonists bp ON bp.id = bf.protagonist_id
INNER JOIN battles.empires be ON be.id = bp.empire_id
WHERE bf.change_type = 'DEPART';
CREATE VIEW battles.fleet_destroy_events
AS SELECT bp.battle_id AS battle , bf.tick_identifier AS tick ,
'DESTROY'::TEXT AS event_type , FALSE AS is_planet ,
bf.id AS event_id , be.name AS name ,
battles.get_protagonist_status_at( bp.id , bf.tick_identifier ) AS attack
FROM battles.fleets bf
INNER JOIN battles.protagonists bp ON bp.id = bf.protagonist_id
INNER JOIN battles.empires be ON be.id = bp.empire_id
WHERE bf.change_type = 'DISBAND';
CREATE VIEW battles.fleet_build_events
AS SELECT bp.battle_id AS battle , bf.tick_identifier AS tick ,
'BUILD'::TEXT AS event_type , FALSE AS is_planet ,
bf.id AS event_id , be.name AS name ,
battles.get_protagonist_status_at( bp.id , bf.tick_identifier ) AS attack
FROM battles.fleets bf
INNER JOIN battles.protagonists bp ON bp.id = bf.protagonist_id
INNER JOIN battles.empires be ON be.id = bp.empire_id
WHERE bf.change_type = 'BUILD';
CREATE VIEW battles.bld_destroy_events
AS SELECT bp.battle_id AS battle , bp.tick_identifier AS tick ,
'DESTROY'::TEXT AS event_type , TRUE AS is_planet ,
bp.id AS event_id , NULL::TEXT AS name , FALSE AS attack
FROM battles.planets bp
WHERE bp.change_type = 'DESTROY';
CREATE VIEW battles.bld_build_events
AS SELECT bp.battle_id AS battle , bp.tick_identifier AS tick ,
'BUILD'::TEXT AS event_type , TRUE AS is_planet ,
bp.id AS event_id , NULL::TEXT AS name , FALSE AS attack
FROM battles.planets bp
WHERE bp.change_type = 'BUILD';
CREATE VIEW battles.events_history
AS SELECT x.* FROM (
SELECT * FROM battles.rename_events
UNION ALL SELECT * FROM battles.switch_events
UNION ALL SELECT * FROM battles.arrive_events
UNION ALL SELECT * FROM battles.depart_events
UNION ALL SELECT * FROM battles.fleet_destroy_events
UNION ALL SELECT * FROM battles.fleet_build_events
UNION ALL SELECT * FROM battles.bld_destroy_events
UNION ALL SELECT * FROM battles.bld_build_events
) x
ORDER BY x.tick DESC , x.is_planet DESC , x.event_type , x.attack , x.name;
GRANT SELECT ON battles.events_history TO :dbuser;
--
-- Ships/buildings for events
--
CREATE VIEW battles.planet_event_items
AS SELECT elv.empire AS empire , TRUE AS is_planet , bp.id AS event_id ,
bp.battle_id AS battle , bp.tick_identifier AS tick ,
t.translated_string AS nature , abs( bb.change ) AS amount ,
b.output AS power
FROM battles.empire_list_view elv
INNER JOIN battles.planets bp ON bp.battle_id = elv.battle
INNER JOIN battles.buildings bb ON bb.planet_id = bp.id
INNER JOIN naming.empire_names en ON en.id = elv.empire
INNER JOIN users.credentials c ON c.address_id = en.owner_id
INNER JOIN defs.translations t
ON t.lang_id = c.language_id AND t.string_id = bb.building_id
INNER JOIN tech.buildings b ON b.buildable_id = bb.building_id
WHERE bp.change_type NOT IN ( 'INIT', 'BATTLE' );
CREATE VIEW battles.fleet_event_items
AS SELECT elv.empire AS empire , FALSE AS is_planet , bf.id AS event_id ,
bp.battle_id AS battle , bf.tick_identifier AS tick ,
t.translated_string AS nature , abs( bs.change ) AS amount ,
s.power AS power
FROM battles.empire_list_view elv
INNER JOIN battles.protagonists bp ON bp.battle_id = elv.battle
INNER JOIN battles.fleets bf ON bf.protagonist_id = bp.id
INNER JOIN battles.ships bs ON bs.fleet_id = bf.id
INNER JOIN naming.empire_names en ON en.id = elv.empire
INNER JOIN users.credentials c ON c.address_id = en.owner_id
INNER JOIN defs.translations t
ON t.lang_id = c.language_id AND t.string_id = bs.ship_id
INNER JOIN tech.ships s ON s.buildable_id = bs.ship_id
WHERE bf.change_type NOT IN ( 'INIT', 'BATTLE' );
CREATE VIEW battles.event_items
AS SELECT x.* FROM (
SELECT * FROM battles.planet_event_items
UNION ALL SELECT * FROM battles.fleet_event_items
) x
ORDER BY x.power;
GRANT SELECT ON battles.event_items TO :dbuser;
--
-- Battles list
--
CREATE VIEW battles.last_presence
AS SELECT protagonist , max( tick ) AS last_present
FROM battles.protagonist_presence
WHERE present
GROUP BY protagonist;
CREATE VIEW battles.first_presence
AS SELECT protagonist , min( tick ) AS first_present
FROM battles.protagonist_presence
WHERE present
GROUP BY protagonist;
CREATE VIEW battles.last_update
AS SELECT p.id AS protagonist , max( u.tick ) AS last_update
FROM battles.protagonists p
INNER JOIN battles.battle_ticks_view u ON u.battle = p.battle_id
GROUP BY p.id;
CREATE VIEW battles.full_battles_list
AS SELECT elv.empire , elv.battle , elv.planet , elv.x , elv.y , elv.orbit , elv.name ,
fp.first_present AS first_tick , ( CASE
WHEN elv.last_tick IS NOT NULL THEN
lp.last_present
WHEN lp.last_present = lu.last_update THEN
NULL
ELSE
lp.last_present
END )::BIGINT AS last_tick , lu.last_update ,
( elv.last_tick IS NOT NULL ) AS finished
FROM battles.empire_list_view elv
INNER JOIN battles.first_presence fp USING (protagonist)
INNER JOIN battles.last_presence lp USING (protagonist)
INNER JOIN battles.last_update lu USING (protagonist);
CREATE TABLE battles.finished_battles_list(
empire INT NOT NULL ,
battle BIGINT NOT NULL ,
planet INT NOT NULL ,
x INT NOT NULL ,
y INT NOT NULL ,
orbit INT NOT NULL ,
name VARCHAR( 20 ) NOT NULL ,
first_tick BIGINT ,
last_tick BIGINT ,
last_update BIGINT ,
PRIMARY KEY( empire , battle )
);
CREATE VIEW battles.current_battles_list
AS SELECT elv.empire , elv.battle , elv.planet , elv.x , elv.y , elv.orbit , elv.name ,
fp.first_present AS first_tick , ( CASE
WHEN lp.last_present = lu.last_update THEN
NULL
ELSE
lp.last_present
END )::BIGINT AS last_tick , lu.last_update
FROM battles.empire_list_view elv
INNER JOIN battles.first_presence fp USING (protagonist)
INNER JOIN battles.last_presence lp USING (protagonist)
INNER JOIN battles.last_update lu USING (protagonist)
WHERE elv.last_tick IS NULL;
CREATE VIEW battles.battles_list
AS SELECT fbl.* , TRUE AS finished FROM battles.finished_battles_list fbl
UNION ALL SELECT cbl.* , FALSE AS finished FROM battles.current_battles_list cbl;
GRANT SELECT ON battles.battles_list TO :dbuser;

View file

@ -0,0 +1,354 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Alliance views and management functions
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
--
-- Alliances public information
--
CREATE VIEW emp.alliances_public
AS SELECT a.id AS id , a.tag AS tag , a.name AS name ,
a.leader_id AS leader_id , n.name AS leader_name ,
count( p.* ) AS planets
FROM emp.alliances a
INNER JOIN naming.empire_names n
ON n.id = a.leader_id
LEFT OUTER JOIN emp.alliance_members am
ON am.alliance_id = a.id AND NOT am.is_pending
LEFT OUTER JOIN emp.planets p
ON p.empire_id = am.empire_id
GROUP BY a.id , a.tag , a.name , a.leader_id , n.name;
GRANT SELECT ON emp.alliances_public TO :dbuser;
--
-- Alliance members / pending requests
--
CREATE VIEW emp.alliance_membership
AS SELECT a.alliance_id AS alliance , a.empire_id AS id ,
n.name AS name , a.is_pending AS pending
FROM emp.alliance_members a
INNER JOIN naming.empire_names n
ON n.id = a.empire_id
ORDER BY n.name;
GRANT SELECT ON emp.alliance_membership TO :dbuser;
--
-- Alliance planets
--
CREATE VIEW emp.alliance_planets
AS SELECT a.alliance_id AS alliance ,
a.empire_id AS owner_id , en.name AS owner_name ,
s.x AS x , s.y AS y , p.orbit AS orbit ,
ep.planet_id AS planet_id , pn.name AS planet_name ,
( bcs IS NOT NULL ) AS battle , bcs.defence , bcs.attack
FROM emp.alliance_members a
INNER JOIN naming.empire_names en ON en.id = a.empire_id
INNER JOIN emp.planets ep ON ep.empire_id = a.empire_id
INNER JOIN verse.planets p ON p.name_id = ep.planet_id
INNER JOIN verse.systems s ON s.id = p.system_id
INNER JOIN naming.map_names pn ON pn.id = ep.planet_id
LEFT OUTER JOIN battles.current_status bcs ON bcs.location = p.name_id
WHERE NOT a.is_pending
ORDER BY en.name , s.x , s.y , p.orbit;
GRANT SELECT ON emp.alliance_planets TO :dbuser;
--
-- Creates an alliance
--
-- Parameters:
-- e_id Empire identifier
-- a_tag Alliance tag
-- a_name Alliance name
--
-- Returns:
-- a_id Alliance identifier (NULL on failure)
--
CREATE OR REPLACE FUNCTION emp.create_alliance( e_id INT , a_tag TEXT , a_name TEXT , OUT a_id INT )
STRICT VOLATILE
SECURITY DEFINER
AS $$
BEGIN
BEGIN
INSERT INTO emp.alliances ( tag , name , leader_id )
VALUES ( a_tag , a_name , e_id )
RETURNING id INTO a_id;
EXCEPTION
WHEN unique_violation THEN
a_id := NULL;
RETURN;
END;
BEGIN
INSERT INTO emp.alliance_members ( alliance_id , empire_id , is_pending )
VALUES ( a_id , e_id , FALSE );
EXCEPTION
WHEN unique_violation THEN
DELETE FROM emp.alliances WHERE id = a_id;
a_id := NULL;
RETURN;
END;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION emp.create_alliance( INT , TEXT , TEXT ) TO :dbuser;
--
-- Requests to join an alliance
--
-- Parameters:
-- e_id Empire identifier
-- a_id Alliance identifier
--
-- Returns:
-- success Whether the operation was successful or not
--
CREATE OR REPLACE FUNCTION emp.join_alliance( e_id INT , a_id INT , OUT success BOOLEAN )
STRICT VOLATILE
SECURITY DEFINER
AS $$
BEGIN
INSERT INTO emp.alliance_members( empire_id , alliance_id )
VALUES ( e_id , a_id );
DELETE FROM emp.enemy_alliances
WHERE empire_id = e_id AND alliance_id = a_id;
PERFORM events.alliance_request_event( a_id , e_id );
PERFORM msgs.deliver_internal( );
success := TRUE;
EXCEPTION
WHEN unique_violation THEN
success := FALSE;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION emp.join_alliance( INT , INT ) TO :dbuser;
--
-- Removes an empire's pending alliance membership
--
-- Parameters:
-- e_id Empire identifier
--
CREATE OR REPLACE FUNCTION emp.cancel_join( e_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DELETE FROM emp.alliance_members WHERE empire_id = $1 AND is_pending;
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION emp.cancel_join( INT ) TO :dbuser;
--
-- Leave an alliance
--
-- Parameters:
-- e_id Empire identifier
--
CREATE OR REPLACE FUNCTION emp.leave_alliance( e_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
l_id INT;
a_id INT;
BEGIN
SELECT INTO a_id , l_id a.id , a.leader_id
FROM emp.alliance_members m
INNER JOIN emp.alliances a ON a.id = m.alliance_id
WHERE m.empire_id = e_id AND NOT m.is_pending
FOR UPDATE;
IF FOUND THEN
IF l_id = e_id THEN
PERFORM events.alliance_disband_event( a_id );
DELETE FROM emp.alliances WHERE id = a_id;
ELSE
DELETE FROM emp.alliance_members WHERE empire_id = e_id;
PERFORM events.alliance_quit_event( a_id , e_id );
END IF;
PERFORM msgs.deliver_internal( );
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION emp.leave_alliance( INT ) TO :dbuser;
--
-- Transfer alliance leadership
--
-- Parameters:
-- e_id Empire identifier of an alliance's leader
-- to_id Empire identifier of the alliance member who is being made the new leader
--
CREATE OR REPLACE FUNCTION emp.transfer_leadership( e_id INT , to_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
a_id INT;
BEGIN
SELECT INTO a_id a.id
FROM emp.alliance_members m
INNER JOIN emp.alliances a ON a.id = m.alliance_id AND a.leader_id = e_id
WHERE m.empire_id = to_id AND NOT m.is_pending
FOR UPDATE;
IF FOUND THEN
UPDATE emp.alliances SET leader_id = to_id WHERE id = a_id;
PERFORM events.alliance_lchange_event( a_id , e_id );
PERFORM msgs.deliver_internal( );
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION emp.transfer_leadership( INT , INT ) TO :dbuser;
--
-- Accept new members into an alliance
--
-- Parameters:
-- e_id Empire identifier
-- r_ids Requests to accept
--
CREATE OR REPLACE FUNCTION emp.accept_members( e_id INT , r_ids INT[] )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
a_id INT;
re_id INT;
BEGIN
SELECT INTO a_id id FROM emp.alliances WHERE leader_id = e_id FOR UPDATE;
IF NOT FOUND THEN
RETURN;
END IF;
FOR re_id IN SELECT m.empire_id FROM emp.alliance_members m
INNER JOIN unnest( r_ids ) rid ON m.empire_id = rid
WHERE m.is_pending
LOOP
PERFORM events.alliance_response_event( a_id , re_id , TRUE );
END LOOP;
PERFORM msgs.deliver_internal( );
UPDATE emp.alliance_members SET is_pending = FALSE
WHERE alliance_id = a_id AND empire_id IN ( SELECT * FROM unnest( r_ids ) );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION emp.accept_members( INT , INT[] ) TO :dbuser;
--
-- Reject membership requests
--
-- Parameters:
-- e_id Empire identifier
-- r_ids Requests to reject
--
CREATE OR REPLACE FUNCTION emp.reject_members( e_id INT , r_ids INT[] )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
a_id INT;
re_id INT;
BEGIN
SELECT INTO a_id id FROM emp.alliances WHERE leader_id = e_id FOR UPDATE;
IF NOT FOUND THEN
RETURN;
END IF;
FOR re_id IN SELECT m.empire_id FROM emp.alliance_members m
INNER JOIN unnest( r_ids ) rid ON m.empire_id = rid
WHERE m.is_pending
LOOP
PERFORM events.alliance_response_event( a_id , re_id , FALSE );
END LOOP;
PERFORM msgs.deliver_internal( );
DELETE FROM emp.alliance_members
WHERE alliance_id = a_id AND is_pending
AND empire_id IN ( SELECT * FROM unnest( r_ids ) );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION emp.reject_members( INT , INT[] ) TO :dbuser;
--
-- Kick members from an alliance
--
-- Parameters:
-- e_id Empire identifier
-- kick_ids Requests to reject
--
CREATE OR REPLACE FUNCTION emp.kick_members( e_id INT , kick_ids INT[] )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
a_id INT;
k_id INT;
BEGIN
SELECT INTO a_id id FROM emp.alliances WHERE leader_id = e_id FOR UPDATE;
IF NOT FOUND THEN
RETURN;
END IF;
FOR k_id IN SELECT m.empire_id FROM emp.alliance_members m
INNER JOIN unnest( kick_ids ) rid ON m.empire_id = rid
WHERE NOT m.is_pending
LOOP
PERFORM events.alliance_kick_event( a_id , k_id );
END LOOP;
PERFORM msgs.deliver_internal( );
DELETE FROM emp.alliance_members
WHERE alliance_id = a_id AND NOT is_pending
AND empire_id IN ( SELECT * FROM unnest( kick_ids ) )
AND empire_id <> e_id;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION emp.kick_members( INT , INT[] ) TO :dbuser;

File diff suppressed because it is too large Load diff

View file

@ -0,0 +1,150 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Views for empires' planet lists
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
--
-- Basic planet information
--
CREATE VIEW emp.planets_list_basic
AS SELECT e.name_id AS empire ,
p.name_id AS id , n.name ,
s.x , s.y , p.orbit ,
p.population , ph.current / p.population::REAL AS happiness ,
floor( pm.income )::BIGINT AS income ,
floor( pm.upkeep )::BIGINT AS upkeep
FROM emp.empires e
INNER JOIN emp.planets ep ON ep.empire_id = e.name_id
INNER JOIN verse.planets p ON p.name_id = ep.planet_id
INNER JOIN naming.map_names n ON n.id = p.name_id
INNER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id
INNER JOIN verse.planet_money pm ON pm.planet_id = p.name_id
INNER JOIN verse.systems s ON s.id = p.system_id;
--
-- Production
--
CREATE VIEW emp.planets_list_prod
AS SELECT id ,
verse.adjust_production( verse.get_raw_production( id , 'WORK') , happiness ) AS military_production ,
verse.adjust_production( verse.get_raw_production( id , 'CASH') , happiness ) AS industrial_production ,
verse.adjust_production( verse.get_raw_production( id , 'POP') , happiness ) AS growth_production ,
verse.adjust_production( verse.get_raw_production( id , 'DEF') , happiness ) AS static_defence
FROM emp.planets_list_basic;
--
-- Civilian investment
--
CREATE VIEW emp.planets_list_civ_invest
AS SELECT q.planet_id AS id , sum( CASE WHEN qi.destroy THEN 0 ELSE qi.amount * qb.cost END ) - q.money AS civ_investment
FROM verse.bld_queues q
INNER JOIN verse.bld_items qi ON qi.queue_id = q.planet_id
INNER JOIN tech.buildables qb ON qb.name_id = qi.building_id
GROUP BY q.planet_id , q.money;
--
-- Military investment
--
CREATE VIEW emp.planets_list_mil_invest
AS SELECT q.planet_id AS id , sum( qi.amount * qb.cost ) - q.money AS mil_investment
FROM verse.mil_queues q
INNER JOIN verse.mil_items qi ON qi.queue_id = q.planet_id
INNER JOIN tech.buildables qb ON qb.name_id = qi.ship_id
GROUP BY q.planet_id , q.money;
--
-- First item on civilian queues
--
CREATE VIEW emp.planets_list_civ_top
AS SELECT qi.queue_id AS id , qi.amount AS civ_amount , qi.destroy AS civ_destroy , t.translated_string AS civ_name
FROM verse.bld_items qi
INNER JOIN emp.planets ep ON ep.planet_id = qi.queue_id
INNER JOIN naming.empire_names en ON en.id = ep.empire_id
INNER JOIN users.credentials cred ON cred.address_id = en.owner_id
INNER JOIN defs.translations t ON t.lang_id = cred.language_id AND t.string_id = qi.building_id
WHERE qi.queue_order = 0;
--
-- First item on military queues
--
CREATE VIEW emp.planets_list_mil_top
AS SELECT qi.queue_id AS id , qi.amount AS mil_amount , t.translated_string AS mil_name
FROM verse.mil_items qi
INNER JOIN emp.planets ep ON ep.planet_id = qi.queue_id
INNER JOIN naming.empire_names en ON en.id = ep.empire_id
INNER JOIN users.credentials cred ON cred.address_id = en.owner_id
INNER JOIN defs.translations t ON t.lang_id = cred.language_id AND t.string_id = qi.ship_id
WHERE qi.queue_order = 0;
--
-- Fleets
--
CREATE VIEW emp.planets_list_fleets
AS SELECT f.location_id AS id , ( CASE
WHEN f.owner_id = ep.empire_id THEN 0
WHEN f.attacking THEN 2
ELSE 1
END ) AS rel_type , sum( fs.power )::BIGINT AS power
FROM fleets.fleets f
INNER JOIN emp.planets ep ON f.location_id = ep.planet_id
INNER JOIN fleets.stats_view fs ON fs.id = f.id
LEFT OUTER JOIN fleets.movements fm ON fm.fleet_id = f.id
WHERE fm IS NULL
GROUP BY f.location_id , ( CASE
WHEN f.owner_id = ep.empire_id THEN 0
WHEN f.attacking THEN 2
ELSE 1
END );
--
-- Actual planet list
--
CREATE VIEW emp.planets_list
AS SELECT e.empire , e.id , e.name , e.x , e.y , e.orbit ,
floor( e.population )::BIGINT AS population ,
floor( 100 * e.happiness )::INT AS happiness ,
e.income , e.upkeep ,
floor( p.military_production )::BIGINT AS military_production ,
floor( p.industrial_production )::BIGINT AS industrial_production ,
floor( p.growth_production )::BIGINT AS growth_production ,
( CASE WHEN ci IS NULL THEN 0 ELSE floor( ci.civ_investment ) END )::BIGINT AS civ_investment ,
ct.civ_amount , ct.civ_destroy , ct.civ_name ,
( CASE WHEN mi IS NULL THEN 0 ELSE floor( mi.mil_investment ) END )::BIGINT AS mil_investment ,
mt.mil_amount , mt.mil_name ,
floor( p.static_defence )::BIGINT AS static_defence ,
( CASE WHEN of IS NULL THEN 0 ELSE of.power END ) AS own_fleet ,
( CASE WHEN ff IS NULL THEN 0 ELSE ff.power END ) AS friendly_fleet ,
( CASE WHEN hf IS NULL THEN 0 ELSE hf.power END ) AS hostile_fleet ,
b.id AS battle
FROM emp.planets_list_basic e
INNER JOIN emp.planets_list_prod p USING ( id )
LEFT OUTER JOIN emp.planets_list_civ_invest ci USING ( id )
LEFT OUTER JOIN emp.planets_list_civ_top ct USING ( id )
LEFT OUTER JOIN emp.planets_list_mil_invest mi USING ( id )
LEFT OUTER JOIN emp.planets_list_mil_top mt USING ( id )
LEFT OUTER JOIN emp.planets_list_fleets of ON of.id = e.id AND of.rel_type = 0
LEFT OUTER JOIN emp.planets_list_fleets ff ON ff.id = e.id AND ff.rel_type = 1
LEFT OUTER JOIN emp.planets_list_fleets hf ON hf.id = e.id AND hf.rel_type = 2
LEFT OUTER JOIN battles.battles b ON b.location_id = e.id AND b.last_tick IS NULL
ORDER BY e.x , e.y , e.orbit;
GRANT SELECT ON emp.planets_list TO :dbuser;

View file

@ -0,0 +1,928 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Functions and views to create and manipulate events
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- EVENT CREATION FUNCTIONS --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
--
-- Creates a battle start event
--
-- Parameters:
-- b_id Battle identifier
--
CREATE OR REPLACE FUNCTION events.battle_start_event( b_id BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
l_id INT;
l_name TEXT;
pe_id INT;
c_tick BIGINT;
evt_id BIGINT;
BEGIN
-- Get location name and identifier
SELECT INTO l_id , l_name b.location_id , n.name
FROM battles.battles b
INNER JOIN naming.map_names n ON n.id = b.location_id
WHERE b.id = b_id;
-- Create message for all protagonists
c_tick := sys.get_tick( ) - 1;
FOR pe_id IN SELECT be.empire_id
FROM battles.battles b
INNER JOIN battles.protagonists bp ON bp.battle_id = b.id
INNER JOIN battles.empires be ON be.id = bp.empire_id
WHERE b.id = b_id
LOOP
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( pe_id , c_tick , 'PLANET' , 0 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.planet_events ( event_id , location_id , location_name , battle_id)
VALUES ( evt_id , l_id , l_name , b_id );
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Creates a battle end event
--
-- Parameters:
-- b_id Battle identifier
--
CREATE OR REPLACE FUNCTION events.battle_end_event( b_id BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
l_id INT;
l_name TEXT;
pe_id INT;
c_tick BIGINT;
evt_id BIGINT;
BEGIN
-- Get location name and identifier
SELECT INTO l_id , l_name b.location_id , n.name
FROM battles.battles b
INNER JOIN naming.map_names n ON n.id = b.location_id
WHERE b.id = b_id;
-- Create message for all protagonists
c_tick := sys.get_tick( ) - 1;
FOR pe_id IN SELECT empire FROM battles.battles_list
WHERE battle = b_id AND last_update = last_tick
LOOP
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( pe_id , c_tick , 'PLANET' , 1 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.planet_events ( event_id , location_id , location_name , battle_id)
VALUES ( evt_id , l_id , l_name , b_id );
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Creates a strike start / end event
--
-- Parameters:
-- p_id Planet identifier
-- sevt Whether to create a strike start or a strike end event
--
CREATE OR REPLACE FUNCTION events.strike_event( p_id INT , sevt BOOLEAN )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
p_name TEXT;
po_id INT;
c_tick BIGINT;
evt_id BIGINT;
BEGIN
-- Get location name and owner identifier
SELECT INTO p_name , po_id n.name , ep.empire_id
FROM naming.map_names n
INNER JOIN emp.planets ep ON ep.planet_id = n.id
WHERE n.id = p_id;
IF NOT FOUND
THEN
RETURN;
END IF;
-- Create message
c_tick := sys.get_tick( ) - 1;
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( po_id , c_tick , 'PLANET' , ( CASE WHEN sevt THEN 2 ELSE 3 END ) , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.planet_events ( event_id , location_id , location_name )
VALUES ( evt_id , p_id , p_name );
END;
$$ LANGUAGE plpgsql;
--
-- Creates events for a planet's ownership change
--
-- Parameters:
-- p_id Planet identifier
-- no_id New owner's identifier
--
CREATE OR REPLACE FUNCTION events.planet_ochange_events( p_id INT , no_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
p_name VARCHAR(20);
no_name VARCHAR(20);
oo_id INT;
oo_name VARCHAR(20);
evt_id BIGINT;
c_tick BIGINT;
BEGIN
c_tick := sys.get_tick( ) - 1;
-- Get new owner's name and the planet's name
SELECT INTO p_name name FROM naming.map_names WHERE id = p_id;
SELECT INTO no_name name FROM naming.empire_names WHERE id = no_id;
-- Get previous owner's name and identifier
SELECT INTO oo_id , oo_name ep.empire_id , n.name
FROM emp.planets ep
INNER JOIN naming.empire_names n ON n.id = ep.empire_id
WHERE ep.planet_id = p_id;
-- If there is a previous owner, add planet loss event
IF FOUND
THEN
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( oo_id , c_tick , 'PLANET' , 4 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.planet_events ( event_id , location_id , location_name , empire_id , empire_name )
VALUES ( evt_id , p_id , p_name , no_id , no_name );
END IF;
-- Add planet taking event
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( no_id , c_tick , 'PLANET' , 6 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.planet_events ( event_id , location_id , location_name , empire_id , empire_name )
VALUES ( evt_id , p_id , p_name , oo_id , oo_name );
END;
$$ LANGUAGE plpgsql;
--
-- Creates an event for planet abandon
--
-- Parameters:
-- p_id Planet identifier
--
CREATE OR REPLACE FUNCTION events.planet_abandon_event( p_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
p_name VARCHAR(20);
po_id INT;
oo_name VARCHAR(20);
evt_id BIGINT;
BEGIN
-- Get owner's ID and planet's name
SELECT INTO p_name , po_id n.name , ep.empire_id
FROM naming.map_names n
INNER JOIN emp.planets ep ON ep.planet_id = n.id
WHERE n.id = p_id;
-- Add abandon event
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( po_id , sys.get_tick( ) - 1 , 'PLANET' , 5 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.planet_events ( event_id , location_id , location_name )
VALUES ( evt_id , p_id , p_name );
END;
$$ LANGUAGE plpgsql;
--
-- Creates an event for a technology's availability
--
-- Parameters:
-- e_id Empire identifier
-- t_id Technology identifier
--
CREATE OR REPLACE FUNCTION events.tech_ready_event( e_id INT , t_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
evt_id BIGINT;
BEGIN
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( e_id , sys.get_tick( ) - 1 , 'EMPIRE' , 0 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.empire_events ( event_id , technology_id )
VALUES ( evt_id , t_id );
END;
$$ LANGUAGE plpgsql;
--
-- Creates an event for start/end of debt
--
-- Parameters:
-- e_id Empire identifier
-- sevt Whether this is the start or the end
--
CREATE OR REPLACE FUNCTION events.debt_event( e_id INT , sevt BOOLEAN )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( $1 , sys.get_tick( ) - 1 , 'EMPIRE' , ( CASE WHEN $2 THEN 1 ELSE 2 END ) , 'READY' );
$$ LANGUAGE SQL;
--
-- Creates a "pending request" event
--
-- Parameters:
-- a_id Alliance identifier
-- e_id Empire identifier
--
CREATE OR REPLACE FUNCTION events.alliance_request_event( a_id INT , e_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
a_tag TEXT;
al_id INT;
e_name TEXT;
evt_id BIGINT;
BEGIN
-- Get the alliance's name and leader ID
SELECT INTO a_tag , al_id tag , leader_id FROM emp.alliances WHERE id = a_id;
-- Get the joining player's name
SELECT INTO e_name name FROM naming.empire_names WHERE id = e_id;
-- Create the event
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( al_id , sys.get_tick( ) , 'ALLIANCE' , 0 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.alliance_events ( event_id , alliance_id , alliance_tag , empire_id , empire_name )
VALUES ( evt_id , a_id , a_tag , e_id , e_name );
END;
$$ LANGUAGE plpgsql;
--
-- Creates a request validation/rejection event
--
-- Parameters:
-- a_id Alliance identifier
-- e_id Empire identifier
-- acc Whether the request was accepted or rejected
--
CREATE OR REPLACE FUNCTION events.alliance_response_event( a_id INT , e_id INT , acc BOOLEAN )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
a_tag TEXT;
e_name TEXT;
evt_id BIGINT;
BEGIN
-- Get the alliance's name and leader ID
SELECT INTO a_tag tag FROM emp.alliances WHERE id = a_id;
-- Get the requesting player's name
SELECT INTO e_name name FROM naming.empire_names WHERE id = e_id;
-- Create the event
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( e_id , sys.get_tick( ) , 'ALLIANCE' , 1 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.alliance_events ( event_id , alliance_id , alliance_tag , req_result )
VALUES ( evt_id , a_id , a_tag , acc );
END;
$$ LANGUAGE plpgsql;
--
-- Creates a leadership change event
--
-- Parameters:
-- a_id Alliance identifier
-- ol_id Previous leader's identifier
--
CREATE OR REPLACE FUNCTION events.alliance_lchange_event( a_id INT , ol_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
a_tag TEXT;
al_id INT;
al_name TEXT;
am_id INT;
evt_id BIGINT;
BEGIN
-- Get alliance tag, leader ID and leader name
SELECT INTO a_tag , al_id , al_name a.tag , a.leader_id , n.name
FROM emp.alliances a
INNER JOIN naming.empire_names n ON n.id = a.leader_id
WHERE a.id = a_id;
-- Notify both members and pending members
FOR am_id IN SELECT empire_id FROM emp.alliance_members
WHERE alliance_id = a_id AND empire_id <> ol_id
LOOP
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( am_id , sys.get_tick( ) , 'ALLIANCE' , 2 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.alliance_events ( event_id , alliance_id , alliance_tag , empire_id , empire_name )
VALUES ( evt_id , a_id , a_tag , al_id , al_name );
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Creates an alliance kick event
--
-- Parameters:
-- a_id Alliance identifier
-- ol_id Member being kicked
--
CREATE OR REPLACE FUNCTION events.alliance_kick_event( a_id INT , k_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
a_tag TEXT;
al_id INT;
k_name TEXT;
am_id INT;
evt_id BIGINT;
BEGIN
-- Get alliance tag and leader ID
SELECT INTO a_tag , al_id a.tag , a.leader_id
FROM emp.alliances a
INNER JOIN naming.empire_names n ON n.id = a.leader_id
WHERE a.id = a_id;
SELECT INTO k_name name FROM naming.empire_names WHERE id = k_id;
-- Notify members
FOR am_id IN SELECT empire_id FROM emp.alliance_members
WHERE alliance_id = a_id AND empire_id <> al_id AND NOT is_pending
LOOP
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( am_id , sys.get_tick( ) , 'ALLIANCE' , 3 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.alliance_events ( event_id , alliance_id , alliance_tag , empire_id , empire_name )
VALUES ( evt_id , a_id , a_tag , k_id , k_name );
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Creates an alliance quit event
--
-- Parameters:
-- a_id Alliance identifier
-- q_id Member quitting the alliance
--
CREATE OR REPLACE FUNCTION events.alliance_quit_event( a_id INT , q_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
a_tag TEXT;
q_name TEXT;
am_id INT;
evt_id BIGINT;
BEGIN
-- Get alliance tag and quitter name
SELECT INTO a_tag a.tag FROM emp.alliances a WHERE a.id = a_id;
SELECT INTO q_name name FROM naming.empire_names WHERE id = q_id;
-- Notify members
FOR am_id IN SELECT empire_id FROM emp.alliance_members
WHERE alliance_id = a_id AND NOT is_pending
LOOP
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( am_id , sys.get_tick( ) , 'ALLIANCE' , 4 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.alliance_events ( event_id , alliance_id , alliance_tag , empire_id , empire_name )
VALUES ( evt_id , a_id , a_tag , q_id , q_name );
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Creates an alliance disband event
--
-- Parameters:
-- a_id Alliance identifier
-- q_id Member quitting the alliance
--
CREATE OR REPLACE FUNCTION events.alliance_disband_event( a_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
a_tag TEXT;
al_id INT;
am_id INT;
evt_id BIGINT;
BEGIN
-- Get alliance tag and quitter name
SELECT INTO a_tag , al_id a.tag , leader_id FROM emp.alliances a WHERE a.id = a_id;
-- Notify members
FOR am_id IN SELECT empire_id FROM emp.alliance_members
WHERE alliance_id = a_id AND empire_id <> al_id
LOOP
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( am_id , sys.get_tick( ) , 'ALLIANCE' , 5 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.alliance_events ( event_id , alliance_id , alliance_tag )
VALUES ( evt_id , a_id , a_tag );
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Creates empty build queue events or updates existing ones
--
-- Parameters:
-- e_id Empire identifier
-- p_id Planet identifier
-- mqueue Whether the empty queue is the military or civilian queue
-- c_tick Current tick
--
CREATE OR REPLACE FUNCTION events.empty_queue_events( e_id INT , p_id INT , mqueue BOOLEAN , c_tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
evt_st INT;
evt_id BIGINT;
p_name TEXT;
BEGIN
evt_st := ( CASE WHEN mqueue THEN 1 ELSE 0 END );
SELECT INTO evt_id event_id FROM events.events
WHERE evt_type = 'QUEUE' AND evt_subtype = evt_st
AND empire_id = e_id AND tick = c_tick;
IF NOT FOUND
THEN
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( e_id , c_tick , 'QUEUE' , evt_st , 'TICK' )
RETURNING event_id INTO evt_id;
INSERT INTO events.queue_events VALUES ( evt_id );
END IF;
SELECT INTO p_name name FROM naming.map_names WHERE id = p_id;
INSERT INTO events.bqe_locations VALUES ( evt_id , p_id , p_name );
END;
$$ LANGUAGE plpgsql;
--
-- Commits fleet arrival events from the "fleet_arrivals" temporary table
--
-- Parameters:
-- c_tick Current tick identifier
--
CREATE OR REPLACE FUNCTION events.commit_fleet_arrivals( c_tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
l_id INT;
l_name TEXT;
tg_id INT;
tg_mode BOOLEAN;
evt_id BIGINT;
BEGIN
FOR l_id , l_name , tg_id , tg_mode
IN SELECT DISTINCT a.loc_id , a.loc_name , l.empire , l.attacking
FROM fleet_arrivals a
INNER JOIN fleets.locations_list_view l ON l.location = a.loc_id
LOOP
-- Create event record
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( tg_id , c_tick , 'FLEETS' , 0 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.fleets_events( event_id , location_id , location_name )
VALUES ( evt_id , l_id , l_name );
-- List fleets
INSERT INTO events.fleet_lists ( event_id , owner_id , owner_name , fleet_name , fleet_power , status , source_id , source_name )
SELECT evt_id , a.own_id , a.own_name , a.name , a.power , ( CASE
WHEN tg_id = a.own_id
THEN tg_mode
ELSE
( tg_mode <> a.mode )
END ) , a.src_id , a.src_name
FROM fleet_arrivals a
WHERE loc_id = l_id
ORDER BY ( a.own_id = tg_id ) DESC , a.mode , own_name , name NULLS LAST;
END LOOP;
DROP TABLE fleet_arrivals;
END;
$$ LANGUAGE plpgsql;
--
-- Commits fleet departure events from the "fleet_departures" temporary table
--
CREATE OR REPLACE FUNCTION events.commit_fleet_departures( )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
l_id INT;
l_name TEXT;
tg_id INT;
tg_mode BOOLEAN;
evt_id BIGINT;
c_tick BIGINT;
BEGIN
c_tick := sys.get_tick( );
FOR l_id , l_name , tg_id , tg_mode
IN SELECT DISTINCT a.loc_id , a.loc_name , l.empire , l.attacking
FROM fleet_departures a
INNER JOIN fleets.locations_list_view l
ON l.location = a.loc_id AND l.empire <> a.own_id
LOOP
-- Create event record
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( tg_id , c_tick , 'FLEETS' , 1 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.fleets_events( event_id , location_id , location_name )
VALUES ( evt_id , l_id , l_name );
-- List fleets
INSERT INTO events.fleet_lists ( event_id , owner_id , owner_name , fleet_name , fleet_power , status )
SELECT evt_id , a.own_id , a.own_name , a.name , a.power , ( tg_mode <> a.mode )
FROM fleet_departures a
WHERE loc_id = l_id AND own_id <> tg_id
ORDER BY a.mode , own_name , name NULLS LAST;
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Commits fleet mode change events from the "fleet_switches" temporary table
--
-- Parameters:
-- els Whether the switch was caused through the enemy list
--
CREATE OR REPLACE FUNCTION events.commit_fleet_switches( els BOOLEAN )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
l_id INT;
l_name TEXT;
tg_id INT;
tg_mode BOOLEAN;
evt_id BIGINT;
c_tick BIGINT;
own_c BIGINT;
other_c BIGINT;
BEGIN
c_tick := sys.get_tick( );
FOR l_id , l_name , tg_id , tg_mode
IN SELECT DISTINCT a.loc_id , a.loc_name , l.empire , l.attacking
FROM fleet_switches a
INNER JOIN fleets.locations_list_view l
ON l.location = a.loc_id
LOOP
-- Handle other fleets
SELECT INTO other_c count(*) FROM fleet_switches WHERE loc_id = l_id AND own_id <> tg_id;
IF other_c > 0
THEN
-- Create event record
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( tg_id , c_tick , 'FLEETS' , 2 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.fleets_events( event_id , location_id , location_name )
VALUES ( evt_id , l_id , l_name );
-- List fleets
INSERT INTO events.fleet_lists ( event_id , owner_id , owner_name , fleet_name , fleet_power , status )
SELECT evt_id , a.own_id , a.own_name , a.name , a.power , a.mode
FROM fleet_switches a
WHERE loc_id = l_id AND own_id <> tg_id
ORDER BY a.mode , own_name , name NULLS LAST;
END IF;
-- Handle own fleets
CONTINUE WHEN NOT els;
SELECT INTO own_c count(*) FROM fleet_switches WHERE loc_id = l_id AND own_id = tg_id;
CONTINUE WHEN own_c = 0;
-- Create event record
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( tg_id , c_tick , 'FLEETS' , 3 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.fleets_events( event_id , location_id , location_name )
VALUES ( evt_id , l_id , l_name );
-- List fleets
INSERT INTO events.fleet_lists ( event_id , owner_id , owner_name , fleet_name , fleet_power , status )
SELECT evt_id , a.own_id , a.own_name , a.name , a.power , a.mode
FROM fleet_switches a
WHERE loc_id = l_id AND own_id = tg_id
ORDER BY a.mode , own_name , name NULLS LAST;
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Creates a map name rejection event
--
-- Parameters:
-- u_id Account identifier
-- n_id Name identifier
-- o_name Old name
-- n_name New name
-- w_sent Whether a warning was sent
-- w_count Current warnings
--
CREATE OR REPLACE FUNCTION events.map_name_rejected_event( u_id INT , n_id INT , o_name TEXT , n_name TEXT , w_sent BOOLEAN , w_count INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
e_id INT;
evt_id BIGINT;
BEGIN
-- Get empire identifier
SELECT INTO e_id e.name_id
FROM emp.empires e
INNER JOIN naming.empire_names en ON en.id = e.name_id
WHERE en.owner_id = u_id;
IF NOT FOUND
THEN
RETURN;
END IF;
-- Add event
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( e_id , sys.get_tick( ) - 1 , 'ADMIN' , 0 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.admin_events( event_id , n_warnings , location_id , old_name , new_name )
VALUES( evt_id , ( CASE WHEN w_sent THEN w_count ELSE NULL END ) , n_id , o_name , n_name );
END;
$$ LANGUAGE plpgsql;
--
-- Creates an empire name rejection event
--
-- Parameters:
-- n_id Name identifier
-- o_name Old name
-- n_name New name
-- w_sent Whether a warning was sent
-- w_count Current warnings
--
CREATE OR REPLACE FUNCTION events.empire_name_rejected_event( n_id INT , o_name TEXT , n_name TEXT , w_sent BOOLEAN , w_count INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
evt_id BIGINT;
BEGIN
-- Add event
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( n_id , sys.get_tick( ) - 1 , 'ADMIN' , 1 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.admin_events( event_id , n_warnings ,old_name , new_name )
VALUES( evt_id , ( CASE WHEN w_sent THEN w_count ELSE NULL END ) , o_name , n_name );
END;
$$ LANGUAGE plpgsql;
--
-- Creates an alliance name rejection event
--
-- Parameters:
-- n_id Empire identifier
-- o_name Alliance name
-- w_sent Whether a warning was sent
-- w_count Current warnings
--
CREATE OR REPLACE FUNCTION events.alliance_name_rejected_event( n_id INT , o_name TEXT , w_sent BOOLEAN , w_count INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
evt_id BIGINT;
BEGIN
-- Add event
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( n_id , sys.get_tick( ) - 1 , 'ADMIN' , 2 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.admin_events( event_id , n_warnings , old_name )
VALUES( evt_id , ( CASE WHEN w_sent THEN w_count ELSE NULL END ) , o_name );
END;
$$ LANGUAGE plpgsql;
--
-- Creates events for updated bug reports
--
-- Parameters:
-- e_id Empire identifier
-- br_id Bug report identifier
-- s_id Submitter identifier
--
CREATE OR REPLACE FUNCTION events.bug_report_updated_event( e_id INT , br_id BIGINT , s_id BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
evt_id BIGINT;
BEGIN
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( e_id , sys.get_tick( ) - 1 , 'BUGS' , 0 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.bug_events( event_id , bug_id , submitter_id )
VALUES ( evt_id , br_id , s_id );
END;
$$ LANGUAGE plpgsql;
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- EVENTS VIEWS, USED BY THE MESSAGE SYSTEM --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
--
-- Main events lists
--
CREATE VIEW events.queue_events_view
AS SELECT e.event_id AS id , e.evt_type , e.evt_subtype , e.tick , e.real_time , ed.*
FROM events.events e
INNER JOIN events.queue_events ed USING (event_id);
GRANT SELECT ON events.queue_events_view TO :dbuser;
CREATE VIEW events.empire_events_view
AS SELECT e.event_id AS id , e.evt_type , e.evt_subtype , e.tick , e.real_time , s.name AS technology
FROM events.events e
LEFT OUTER JOIN events.empire_events ed USING (event_id)
LEFT OUTER JOIN tech.levels tl ON tl.id = ed.technology_id
LEFT OUTER JOIN defs.strings s ON s.id = tl.name_id
WHERE e.evt_type = 'EMPIRE';
GRANT SELECT ON events.empire_events_view TO :dbuser;
CREATE VIEW events.fleets_events_view
AS SELECT e.event_id AS id , e.evt_type , e.evt_subtype , e.tick , e.real_time ,
ed.* , s.x , s.y , p.orbit
FROM events.events e
INNER JOIN events.fleets_events ed USING (event_id)
INNER JOIN verse.planets p ON p.name_id = ed.location_id
INNER JOIN verse.systems s ON s.id = p.system_id;
GRANT SELECT ON events.fleets_events_view TO :dbuser;
CREATE VIEW events.planet_events_view
AS SELECT e.event_id AS id , e.evt_type , e.evt_subtype , e.tick , e.real_time ,
ed.* , s.x , s.y , p.orbit
FROM events.events e
INNER JOIN events.planet_events ed USING (event_id)
INNER JOIN verse.planets p ON p.name_id = ed.location_id
INNER JOIN verse.systems s ON s.id = p.system_id;
GRANT SELECT ON events.planet_events_view TO :dbuser;
CREATE VIEW events.alliance_events_view
AS SELECT e.event_id AS id , e.evt_type , e.evt_subtype , e.tick , e.real_time , ed.*
FROM events.events e
INNER JOIN events.alliance_events ed USING (event_id);
GRANT SELECT ON events.alliance_events_view TO :dbuser;
CREATE VIEW events.admin_events_view
AS SELECT e.event_id AS id , e.evt_type , e.evt_subtype , e.tick , e.real_time , ed.*
FROM events.events e
INNER JOIN events.admin_events ed USING ( event_id );
GRANT SELECT ON events.admin_events_view TO :dbuser;
CREATE VIEW events.bugs_events_view
AS SELECT e.event_id AS id , e.evt_type , e.evt_subtype , e.tick , e.real_time , ed.bug_id ,
bs.is_admin AS submitter_admin , bs.name AS submitter_name
FROM events.events e
INNER JOIN events.bug_events ed USING ( event_id )
INNER JOIN bugs.submitters bs USING ( submitter_id );
GRANT SELECT ON events.bugs_events_view TO :dbuser;
--
-- Queue event locations
--
CREATE VIEW events.queue_locations_view
AS SELECT bqe.* , s.x , s.y , p.orbit
FROM events.bqe_locations bqe
INNER JOIN verse.planets p ON p.name_id = bqe.location_id
INNER JOIN verse.systems s ON s.id = p.system_id;
GRANT SELECT ON events.queue_locations_view TO :dbuser;

File diff suppressed because it is too large Load diff

View file

@ -0,0 +1,937 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Functions and views to manage administrative accounts
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- ADMINISTRATOR MANAGEMENT FUNCTIONS --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
--
-- Creates an administrative user
--
-- Parameters:
-- u_addr User account address
-- a_name Administrative name
-- privs Administrative privileges
--
-- Returns:
-- err_code Error code:
-- 0 success
-- 1 unknown user
-- 2 invalid user status
-- 3 name already in use
-- 4 user already has admin access
-- admin_id Administrator ID or NULL on failure
--
CREATE OR REPLACE FUNCTION admin.create_admin( IN u_addr TEXT , IN a_name TEXT , IN privs INT ,
OUT err_code INT , OUT admin_id INT )
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
u_id INT;
u_stat TEXT;
p_sha1 TEXT;
p_md5 TEXT;
BEGIN
-- Get user ID, status and password hashes
SELECT INTO u_id , u_stat , p_sha1 , p_md5 id , status , pass_sha1 , pass_md5
FROM users.accounts_view
WHERE address = lower( u_addr );
IF NOT FOUND
THEN
err_code := 1;
RETURN;
ELSEIF u_stat IN ( 'UNCONFIRMED' , 'BANNED' )
THEN
err_code := 2;
RETURN;
END IF;
-- Try adding the admin's record
BEGIN
INSERT INTO admin.administrators ( appear_as , pass_md5 , pass_sha1 , privileges )
VALUES ( a_name , p_md5 , p_sha1 , privs )
RETURNING id INTO admin_id;
EXCEPTION
WHEN unique_violation THEN
err_code := 3;
RETURN;
END;
-- Add the admin <-> user relation
BEGIN
INSERT INTO admin.admin_credentials ( administrator_id , credentials_id )
VALUES ( admin_id , u_id );
err_code := 0;
PERFORM admin.write_log( admin_id , 'INFO'::log_level , 'Administrator ' || a_name || ' created' );
EXCEPTION
WHEN unique_violation THEN
DELETE FROM admin.administrators WHERE id = admin_id;
err_code := 4;
admin_id := NULL;
END;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION admin.create_admin( TEXT, TEXT , INT ) TO :dbuser;
--
-- Type indicating the result of a connection attempt
--
CREATE TYPE admin_connection_result
AS ENUM( 'SUCCESS' , 'PASSWORD' , 'INACTIVE' );
--
-- Log a connection attempt
--
-- Parameters:
-- a_id Administrator identifier
-- c_res Connection attempt result
-- addr IP address
--
CREATE OR REPLACE FUNCTION admin.log_connection( a_id INT , c_res admin_connection_result , addr TEXT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
BEGIN
IF c_res = 'SUCCESS'
THEN
PERFORM admin.write_log( a_id , 'DEBUG'::log_level , 'Successful login attempt from ' || addr );
ELSEIF c_res = 'PASSWORD'
THEN
PERFORM admin.write_log( a_id , 'WARNING'::log_level , 'Failed login attempt from ' || addr
|| ' (incorrect password)' );
ELSEIF c_res = 'INACTIVE'
THEN
PERFORM admin.write_log( a_id , 'WARNING'::log_level , 'Failed login attempt from ' || addr
|| ' (inactive administrator)' );
ELSE
RAISE EXCEPTION 'Unknown connection attempt result value: %' , c_res;
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION admin.log_connection( INT , admin_connection_result , TEXT ) TO :dbuser;
--
-- Log a disconnection
--
-- Parameters:
-- a_id Administrator identifier
--
CREATE OR REPLACE FUNCTION admin.log_disconnection( a_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
BEGIN
PERFORM admin.write_log( a_id , 'DEBUG'::log_level , 'Administrator disconnected' );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION admin.log_disconnection( INT ) TO :dbuser;
--
-- Modifies an administrator's password
--
-- Parameters:
-- a_id Administrator identifier
-- p_sha1 SHA-1 hash of the new password
-- p_md5 MD5 hash of the new password
--
-- Returns:
-- success Whether the operation was successful
--
CREATE OR REPLACE FUNCTION admin.set_password( a_id INT , p_sha1 TEXT , p_md5 TEXT , OUT success BOOLEAN )
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
u_sha1 TEXT;
u_md5 TEXT;
BEGIN
SELECT INTO u_sha1 , u_md5 c.pass_sha1 , c.pass_md5
FROM admin.admins_view a
INNER JOIN users.credentials c ON c.address_id = a.account_id
WHERE a.administrator_id = a_id AND a.active;
success := ( FOUND AND u_sha1 <> p_sha1 AND u_md5 <> p_md5 );
IF success
THEN
UPDATE admin.administrators
SET pass_sha1 = p_sha1 , pass_md5 = p_md5
WHERE id = a_id;
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION admin.set_password( INT , TEXT , TEXT ) TO :dbuser;
--
-- Resets an administrator's password to his/her player account password
--
-- Parameters:
-- a_id Administrator identifier
-- su_id Superuser identifier
--
-- Returns:
-- success Whether the operation was successful
--
CREATE OR REPLACE FUNCTION admin.reset_password( a_id INT , su_id INT , OUT success BOOLEAN )
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
u_sha1 TEXT;
u_md5 TEXT;
a_name TEXT;
BEGIN
SELECT INTO u_sha1 , u_md5 , a_name c.pass_sha1 , c.pass_md5 , a.name
FROM admin.admins_view a
INNER JOIN users.credentials c ON c.address_id = a.account_id
WHERE a.administrator_id = a_id AND a.active;
success := FOUND;
IF success
THEN
UPDATE admin.administrators SET pass_sha1 = u_sha1 , pass_md5 = u_md5
WHERE id = a_id;
PERFORM admin.write_log( su_id , 'INFO'::log_level , 'Reset password of administrator ' || a_name );
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION admin.reset_password( INT , INT ) TO :dbuser;
--
-- Modifies an administrator's privileges
--
-- Parameters:
-- a_id Administrator identifier
-- su_id Superuser identifier
-- n_privs New privileges
--
-- Returns:
-- success Whether the operation was successful
--
CREATE OR REPLACE FUNCTION admin.set_privileges( a_id INT , su_id INT , n_privs INT , OUT success BOOLEAN )
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
a_name TEXT;
o_privs INT;
BEGIN
SELECT INTO a_name , o_privs a.name , a.privileges
FROM admin.admins_view a
WHERE a.administrator_id = a_id AND a.address IS NOT NULL;
success := FOUND;
IF success AND n_privs <> o_privs
THEN
UPDATE admin.administrators SET privileges = n_privs
WHERE id = a_id;
PERFORM admin.write_log( su_id , 'INFO'::log_level , 'Set privileges of administrator ' || a_name
|| ' from ' || o_privs || ' to ' || n_privs );
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION admin.set_privileges( INT , INT , INT ) TO :dbuser;
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- ADMINISTRATOR VIEWS --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
--
-- Active administrators
--
CREATE VIEW admin.admins_view
AS SELECT adm.id AS administrator_id , adm.appear_as AS name , adm.privileges AS privileges ,
adm.pass_sha1 , adm.pass_md5 , addr.id AS account_id , addr.address AS address ,
( addr.id IS NOT NULL AND privileges <> 0 ) AS active ,
( adm.pass_sha1 = cred.pass_sha1 AND adm.pass_md5 = cred.pass_md5 ) AS pass_change_required
FROM admin.administrators adm
LEFT OUTER JOIN admin.admin_credentials ac ON ac.administrator_id = adm.id
LEFT OUTER JOIN users.credentials cred ON cred.address_id = ac.credentials_id
LEFT OUTER JOIN users.addresses addr ON addr.id = ac.credentials_id;
GRANT SELECT ON admin.admins_view TO :dbuser;
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- BANHAMMER FUNCTIONS --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
--
-- Creates a ban request
--
-- Parameters:
-- a_id Administrator identifier
-- u_id User identifier
-- r_txt Reason for the ban request
--
-- Returns:
-- Whether the operation was successful or not
--
CREATE OR REPLACE FUNCTION admin.add_ban_request( a_id INT , u_id INT , r_txt TEXT )
RETURNS BOOLEAN
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
ban_id INT;
BEGIN
INSERT INTO admin.ban_requests ( requested_by , reason )
VALUES ( a_id , r_txt )
RETURNING id INTO ban_id;
BEGIN
INSERT INTO admin.active_ban_requests( request_id , credentials_id )
VALUES( ban_id , u_id );
RETURN TRUE;
EXCEPTION
WHEN unique_violation THEN
DELETE FROM admin.ban_requests WHERE id = ban_id;
RETURN FALSE;
END;
END;
$$ LANGUAGE plpgsql;
--
-- Creates a ban request using an email address as the source
--
-- Parameters:
-- a_id Administrator identifier
-- u_addr Target user's address
-- r_txt Reason for the ban request
--
-- Returns:
-- err_code Error code:
-- 0 success
-- 1 user not found
-- 2 duplicate request
--
CREATE OR REPLACE FUNCTION admin.request_ban_on_address( a_id INT , u_addr TEXT , r_txt TEXT , OUT err_code INT )
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
u_id INT;
BEGIN
SELECT INTO u_id id FROM users.accounts_view
WHERE address = u_addr;
IF NOT FOUND
THEN
err_code := 1;
RETURN;
END IF;
IF admin.add_ban_request( a_id , u_id , r_txt )
THEN
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Requested ban of user #' || u_id || ' (address: ' || u_addr || ')' );
err_code := 0;
ELSE
err_code := 2;
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION admin.request_ban_on_address( INT , TEXT, TEXT ) TO :dbuser;
--
-- Creates a ban request using an empire name as the source
--
-- Parameters:
-- a_id Administrator identifier
-- u_emp Target user's empire name
-- r_txt Reason for the ban request
--
-- Returns:
-- err_code Error code:
-- 0 success
-- 1 user not found
-- 2 duplicate request
--
CREATE OR REPLACE FUNCTION admin.request_ban_on_empire( a_id INT , u_emp TEXT , r_txt TEXT , OUT err_code INT )
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
u_id INT;
BEGIN
SELECT INTO u_id owner_id FROM naming.empire_names
WHERE lower(name) = lower(u_emp);
IF NOT FOUND
THEN
err_code := 1;
RETURN;
END IF;
IF admin.add_ban_request( a_id , u_id , r_txt )
THEN
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Requested ban of user #' || u_id || ' (empire name: ' || u_emp || ')' );
err_code := 0;
ELSE
err_code := 2;
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION admin.request_ban_on_empire( INT , TEXT, TEXT ) TO :dbuser;
--
-- Rejects a ban request
--
-- Parameters:
-- a_id Administrator identifier
-- b_id Ban request identifier
-- r_txt Rejection reason
--
CREATE OR REPLACE FUNCTION admin.reject_ban_request( a_id INT , b_id INT , r_txt TEXT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
u_id INT;
BEGIN
-- Make sure the request exists and hasn't been validated
SELECT INTO u_id credentials_id FROM admin.active_ban_requests
WHERE request_id = b_id AND NOT validated
FOR UPDATE;
IF NOT FOUND
THEN
RETURN;
END IF;
PERFORM * FROM admin.ban_requests WHERE id = b_id FOR UPDATE;
-- Insert archive entry
INSERT INTO admin.archived_ban_requests( request_id , credentials_id )
VALUES ( b_id , u_id );
INSERT INTO admin.rejected_ban_requests( request_id , rejected_by , reason )
VALUES ( b_id , a_id , r_txt );
DELETE FROM admin.active_ban_requests WHERE request_id = b_id;
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Rejected ban of user #' || u_id );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION admin.reject_ban_request( INT , INT , TEXT ) TO :dbuser;
--
-- Confirms a ban request
--
-- Parameters:
-- a_id Administrator identifier
-- b_id Ban request identifier
--
-- Returns:
-- success Whether the operation was successful
-- addr User's email address
-- lang User's language
-- r_txt Reason for the ban
--
CREATE OR REPLACE FUNCTION admin.confirm_ban_request( a_id INT , b_id INT , OUT success BOOLEAN , OUT addr TEXT , OUT lang TEXT , OUT r_txt TEXT )
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
u_id INT;
br_id INT;
BEGIN
-- Make sure there is an active, unvalidated ban request
SELECT INTO u_id credentials_id FROM admin.active_ban_requests
WHERE request_id = b_id AND NOT validated FOR UPDATE;
IF NOT FOUND
THEN
success := FALSE;
RETURN;
END IF;
-- Make sure the request was created by another admin
SELECT INTO br_id , r_txt requested_by , reason FROM admin.ban_requests
WHERE id = b_id AND requested_by <> a_id
FOR UPDATE;
IF NOT FOUND
THEN
success := FALSE;
RETURN;
END IF;
-- Mark request as validated
INSERT INTO admin.validated_ban_requests ( request_id , validated_by )
VALUES ( b_id , a_id );
UPDATE admin.active_ban_requests SET validated = TRUE
WHERE request_id = b_id;
-- Update account
PERFORM * FROM users.credentials WHERE address_id = u_id FOR UPDATE;
LOOP
UPDATE users.inactive_accounts SET since = now( ) , status = 'PROCESSED'
WHERE credentials_id = u_id;
EXIT WHEN FOUND;
BEGIN
INSERT INTO users.inactive_accounts ( credentials_id , since , status )
VALUES ( u_id , now() , 'PROCESSED' );
EXIT;
EXCEPTION
WHEN unique_violation THEN
-- Do nothing
END;
END LOOP;
-- Insert ban entry
INSERT INTO users.bans ( account_id , ban_id )
VALUES( u_id , b_id );
-- Set ban reason
LOOP
UPDATE users.reasons SET reason = r_txt WHERE account_id = u_id;
EXIT WHEN FOUND;
BEGIN
INSERT INTO users.reasons( account_id , reason )
VALUES ( u_id , r_txt );
EXIT;
EXCEPTION
WHEN unique_violation THEN
-- Do nothing
END;
END LOOP;
success := TRUE;
SELECT INTO addr , lang a.address , l.language
FROM users.credentials c
INNER JOIN users.addresses a ON a.id = c.address_id
INNER JOIN defs.languages l ON l.id = c.language_id
WHERE c.address_id = u_id;
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Confirmed ban request on user #' || u_id );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION admin.confirm_ban_request( INT , INT ) TO :dbuser;
--
-- Lifts an existing ban
--
-- Parameters:
-- a_id Administrator identifier
-- b_id Ban identifier
--
-- Returns:
-- success Whether the operation was successful
-- addr User's email address
-- lang User's language
--
CREATE OR REPLACE FUNCTION admin.lift_ban( a_id INT , b_id INT , OUT success BOOLEAN , OUT addr TEXT , OUT lang TEXT )
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
u_id INT;
redeem BOOLEAN;
BEGIN
-- Find / lock the ban and user records
SELECT INTO u_id , redeem ab.credentials_id , ( aa.credentials_id IS NOT NULL )
FROM admin.active_ban_requests ab
INNER JOIN admin.ban_requests br ON br.id = ab.request_id
INNER JOIN users.credentials c ON c.address_id = ab.credentials_id
LEFT OUTER JOIN users.active_accounts aa ON aa.credentials_id = c.address_id
WHERE ab.request_id = b_id AND ab.validated
FOR UPDATE OF ab , br , c;
IF NOT FOUND
THEN
success := FALSE;
RETURN;
END IF;
-- Delete the ban and reason records, and redeem the account if possible
DELETE FROM users.bans WHERE account_id = u_id;
DELETE FROM users.reasons WHERE account_id = u_id;
IF redeem
THEN
DELETE FROM users.inactive_accounts WHERE credentials_id = u_id;
END IF;
-- Delete active and validated ban entries
DELETE FROM admin.validated_ban_requests WHERE request_id = b_id;
DELETE FROM admin.active_ban_requests WHERE request_id = b_id;
-- Insert archive records
INSERT INTO admin.archived_ban_requests( request_id , credentials_id )
VALUES ( b_id , u_id );
INSERT INTO admin.rejected_ban_requests( request_id , rejected_by , reason )
VALUES ( b_id , a_id , '(ban lifted)' );
success := TRUE;
SELECT INTO addr , lang a.address , l.language
FROM users.credentials c
INNER JOIN users.addresses a ON a.id = c.address_id
INNER JOIN defs.languages l ON l.id = c.language_id
WHERE c.address_id = u_id;
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Ban on user #' || u_id || ' has been lifted'
|| (CASE WHEN redeem THEN ' (empire redeemed)' ELSE '' END) );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION admin.lift_ban( INT , INT ) TO :dbuser;
--
-- Causes ban requests to expire
--
CREATE OR REPLACE FUNCTION admin.expire_ban_requests( )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
b_id INT;
u_id INT;
BEGIN
FOR b_id , u_id IN SELECT br.id , ab.credentials_id FROM admin.ban_requests br
INNER JOIN admin.active_ban_requests ab
ON ab.request_id = br.id AND NOT validated
WHERE now() - br.requested >= ( floor( sys.get_constant( 'accounts.banExpiration') ) || 's' )::INTERVAL
FOR UPDATE
LOOP
INSERT INTO admin.archived_ban_requests ( request_id , credentials_id )
VALUES ( b_id , u_id );
DELETE FROM admin.active_ban_requests WHERE request_id = b_id;
PERFORM sys.write_sql_log( 'Bans' , 'INFO'::log_level , 'Ban request #' || b_id
|| ' (user account #' || u_id || ') expired' );
END LOOP;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION admin.expire_ban_requests( ) TO :dbuser;
--
-- Checks for banned players who still have empires past the expiration delay
-- and deletes the empires.
--
-- Returns:
-- Whether an empire was deleted
--
CREATE OR REPLACE FUNCTION admin.delete_banned_empires( )
RETURNS BOOLEAN
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
e_id INT;
a_id INT;
BEGIN
SELECT INTO e_id , a_id e.name_id , c.address_id
FROM emp.empires e
INNER JOIN naming.empire_names en ON en.id = e.name_id
INNER JOIN users.credentials c ON c.address_id = en.owner_id
INNER JOIN users.active_accounts aa ON aa.credentials_id = c.address_id
INNER JOIN users.inactive_accounts ia ON ia.credentials_id = c.address_id
INNER JOIN users.bans b ON b.account_id = ia.credentials_id
WHERE now() - ia.since >= ( floor( sys.get_constant( 'accounts.banDelay') ) || 's' )::INTERVAL
FOR UPDATE LIMIT 1;
IF NOT FOUND
THEN
RETURN FALSE;
END IF;
-- Delete empire and active account record
PERFORM emp.delete_empire( e_id );
DELETE FROM users.active_accounts WHERE credentials_id = a_id;
PERFORM sys.write_sql_log( 'Bans' , 'INFO'::log_level , 'Deleted empire #' || e_id
|| ' (user account #' || a_id || ')' );
RETURN TRUE;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION admin.delete_banned_empires( ) TO :dbuser;
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- VIEWS RELATED TO THE BANHAMMER --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
--
-- Pending requests
--
CREATE VIEW admin.pending_bans
AS SELECT r.id , r.requested_by AS requested_by_id , a.appear_as AS requested_by_name ,
r.reason , r.requested , ab.credentials_id AS account_id , ad.address AS account_mail
FROM admin.ban_requests r
INNER JOIN admin.active_ban_requests ab
ON ab.request_id = r.id AND NOT ab.validated
INNER JOIN admin.administrators a ON a.id = r.requested_by
INNER JOIN users.addresses ad ON ad.id = ab.credentials_id;
GRANT SELECT ON admin.pending_bans TO :dbuser;
--
-- Expired / rejected ban requests
--
CREATE VIEW admin.cancelled_bans
AS SELECT r.id , r.requested_by AS requested_by_id , a.appear_as AS requested_by_name ,
r.reason , r.requested , ab.credentials_id AS account_id , ad.address AS account_mail ,
ab.updated , ( rb.request_id IS NULL ) AS expired ,
rb.rejected_by AS rejected_by_id , ra.appear_as AS rejected_by_name ,
rb.reason AS rejection_reason
FROM admin.ban_requests r
INNER JOIN admin.administrators a ON a.id = r.requested_by
INNER JOIN admin.archived_ban_requests ab ON ab.request_id = r.id
INNER JOIN users.addresses ad ON ad.id = ab.credentials_id
LEFT OUTER JOIN admin.rejected_ban_requests rb ON rb.request_id = r.id
LEFT OUTER JOIN admin.administrators ra ON ra.id = rb.rejected_by;
GRANT SELECT ON admin.cancelled_bans TO :dbuser;
--
-- Active bans
--
CREATE VIEW admin.active_bans
AS SELECT r.id , r.requested_by AS requested_by_id , a.appear_as AS requested_by_name ,
r.reason , r.requested , ab.credentials_id AS account_id , ad.address AS account_mail ,
vr.validated AS updated , ( ua.credentials_id IS NOT NULL ) AS redeemable ,
vr.validated_by AS validated_by_id , va.appear_as AS validated_by_name
FROM admin.ban_requests r
INNER JOIN admin.administrators a ON a.id = r.requested_by
INNER JOIN admin.active_ban_requests ab ON ab.request_id = r.id AND validated
INNER JOIN users.addresses ad ON ad.id = ab.credentials_id
INNER JOIN admin.validated_ban_requests vr ON vr.request_id = r.id
INNER JOIN admin.administrators va ON va.id = vr.validated_by
LEFT OUTER JOIN users.active_accounts ua ON ua.credentials_id = ab.credentials_id;
GRANT SELECT ON admin.active_bans TO :dbuser;
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- WARNING SYSTEM FUNCTIONS --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
--
-- Adds a warning to a player's account, triggering an automatic ban request if necessary
--
-- Parameters:
-- a_id Administrator identifier
-- u_id Player identifier
--
-- Returns:
-- given Whether a warning was issued or not
-- c_count Current amount of warnings for this player
--
CREATE OR REPLACE FUNCTION admin.give_player_warning( a_id INT , u_id INT , OUT given BOOLEAN , OUT c_count INT )
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
last_rec TIMESTAMP WITHOUT TIME ZONE;
BEGIN
LOOP
SELECT INTO c_count , last_rec warnings, last_received
FROM admin.warnings WHERE credentials_id = u_id
FOR UPDATE;
IF FOUND
THEN
given := ( now() - last_rec >= ( floor(sys.get_constant('accounts.warnings.grace')) || 's' )::INTERVAL );
IF given
THEN
c_count := c_count + 1;
UPDATE admin.warnings SET last_received = now( ) , warnings = c_count
WHERE credentials_id = u_id;
END IF;
EXIT;
END IF;
BEGIN
INSERT INTO admin.warnings ( credentials_id ) VALUES ( u_id );
given := TRUE;
c_count := 1;
EXIT;
EXCEPTION
WHEN unique_violation THEN
-- Do nothing
END;
END LOOP;
IF given
THEN
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Warning given to user #' || u_id || ' ('
|| c_count || ' warning(s) total)' );
IF c_count >= sys.get_constant( 'accounts.warnings.autoBan' )
THEN
IF admin.add_ban_request( a_id , u_id , 'Automatic ban after ' || c_count || ' warnings' )
THEN
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Added automatic ban for user ' || u_id );
END IF;
END IF;
END IF;
END;
$$ LANGUAGE plpgsql;
--
-- Causes old warnings to expire
--
CREATE OR REPLACE FUNCTION admin.expire_warnings( )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
e_time INTERVAL;
g_time INTERVAL;
BEGIN
e_time := ( floor( sys.get_constant( 'accounts.warnings.expiration' )
* sys.get_constant( 'accounts.warnings.expiration.units' ) )
|| 's' ) :: INTERVAL;
g_time := ( floor(sys.get_constant('accounts.warnings.grace')) || 's' )::INTERVAL;
UPDATE admin.warnings SET last_received = now( ) - g_time , warnings = warnings - 1
WHERE now() - last_received >= g_time AND warnings > 0;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION admin.expire_warnings( ) TO :dbuser;
--
-- Finds out if it is time to send the administrative recap e-mails
--
CREATE OR REPLACE FUNCTION admin.is_recap_time( OUT is_time TIMESTAMP WITHOUT TIME ZONE )
STRICT VOLATILE
SECURITY DEFINER
AS $$
BEGIN
SELECT INTO is_time last_admin_recap FROM sys.status
WHERE now() - last_admin_recap >= '12 hours'::INTERVAL
FOR UPDATE;
IF FOUND
THEN
UPDATE sys.status SET last_admin_recap = now( );
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION admin.is_recap_time( ) TO :dbuser;
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- USERS VIEW --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
CREATE VIEW admin.user_empires
AS SELECT en.*
FROM emp.empires e
INNER JOIN naming.empire_names en ON e.name_id = en.id;
CREATE VIEW admin.users_list
AS SELECT av.* , ue.id AS current_empire_id , ue.name AS current_empire ,
a1.id AS ban_req_id , a1.appear_as AS ban_req_name ,
a2.id AS ban_val_id , a2.appear_as AS ban_val_name ,
( CASE WHEN w IS NULL THEN 0 ELSE w.warnings END ) AS warnings_count ,
w.last_received AS warnings_last
FROM users.accounts_view av
LEFT OUTER JOIN admin.user_empires ue ON ue.owner_id = av.id
LEFT OUTER JOIN admin.ban_requests br ON br.id = av.ban_request_id
LEFT OUTER JOIN admin.validated_ban_requests vbr ON vbr.request_id = br.id
LEFT OUTER JOIN admin.administrators a1 ON a1.id = br.requested_by
LEFT OUTER JOIN admin.administrators a2 ON a2.id = vbr.validated_by
LEFT OUTER JOIN admin.warnings w ON w.credentials_id = av.id
ORDER BY av.address;
GRANT SELECT ON admin.users_list TO :dbuser;

File diff suppressed because it is too large Load diff

View file

@ -0,0 +1,64 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Views used to generate the administration overview
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
CREATE VIEW admin.ov_new_messages
AS SELECT admin_id , count(*) AS new_messages
FROM msgs.admin_delivery
WHERE status = 'UNREAD'
GROUP BY admin_id;
CREATE VIEW admin.ov_pending_names
AS SELECT count(*) AS pending_names
FROM naming.changed_map_names
LEFT OUTER JOIN naming.validated_map_names USING (name_id)
WHERE validated_at IS NULL;
CREATE VIEW admin.ov_pending_bans
AS SELECT count(*) AS pending_bans
FROM admin.active_ban_requests
WHERE NOT validated;
CREATE VIEW admin.ov_pending_bugs
AS SELECT count(*) AS pending_bugs
FROM bugs.br_main_view
WHERE status = 'PENDING';
CREATE VIEW admin.ov_open_bugs
AS SELECT count(*) AS open_bugs
FROM bugs.br_main_view
WHERE status = 'OPEN';
CREATE VIEW admin.ov_updated_bugs
AS SELECT administrator_id , count(*) AS updated_bugs
FROM bugs.br_admin_view
WHERE updated
GROUP BY administrator_id;
CREATE VIEW admin.overview
AS SELECT a.id AS admin_id ,
( CASE WHEN nm IS NULL THEN 0 ELSE nm.new_messages END )::BIGINT AS new_messages ,
pn.pending_names , pb.pending_bans , pbg.pending_bugs , ob.open_bugs ,
( CASE WHEN ub IS NULL THEN 0 ELSE ub.updated_bugs END )::BIGINT AS updated_bugs
FROM admin.administrators a
LEFT OUTER JOIN admin.ov_new_messages nm ON nm.admin_id = a.id
INNER JOIN admin.ov_pending_names pn ON TRUE
INNER JOIN admin.ov_pending_bans pb ON TRUE
INNER JOIN admin.ov_pending_bugs pbg ON TRUE
INNER JOIN admin.ov_open_bugs ob ON TRUE
LEFT OUTER JOIN admin.ov_updated_bugs ub ON ub.administrator_id = a.id
WHERE a.privileges <> 0;
GRANT SELECT ON admin.overview TO :dbuser;