Game updates improvements

* Added a set of tables which define game updates and their targets.
These definitions replace the old enumerate type. Added a set of
triggers which automatically create specific update tables, insert
missing entries, etc... when game update types are being manipulated.

* Removed manual insertion of game updates from empire creation
function and universe generator.

* Added registration of core update targets (i.e. planets and empires),
updated all existing game update processing functions and added type
registrations

* Created Maven project for game updates control components, moved
existing components from the -simple project, rewritten most of what
they contained, added new components for server-side update batch
processing
This commit is contained in:
Emmanuel BENOîT 2012-02-03 16:25:03 +01:00
parent ba6a1e2b41
commit 56eddcc4f0
93 changed files with 4004 additions and 578 deletions

View file

@ -1,7 +1,7 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- System & game updates status
-- System & ticker status
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
@ -53,55 +53,3 @@ INSERT INTO sys.ticker( task_name , status )
VALUES ( 'Game update' , 'STOPPED' );
GRANT SELECT ON sys.ticker TO :dbuser;
--
-- Updates
--
CREATE TABLE sys.updates(
id BIGSERIAL NOT NULL PRIMARY KEY ,
gu_type update_type NOT NULL ,
status processing_status NOT NULL DEFAULT 'FUTURE' ,
last_tick BIGINT NOT NULL DEFAULT -1
);
CREATE INDEX idx_updates_finder
ON sys.updates (gu_type, status, last_tick);
--
-- Planet updates
--
CREATE TABLE verse.updates(
update_id BIGINT NOT NULL PRIMARY KEY ,
planet_id INT NOT NULL
);
CREATE INDEX idx_planetupdates_planet
ON verse.updates (planet_id);
ALTER TABLE verse.updates
ADD CONSTRAINT fk_planetupdates_update
FOREIGN KEY ( update_id ) REFERENCES sys.updates ,
ADD CONSTRAINT fk_planetupdates_planet
FOREIGN KEY ( planet_id ) REFERENCES verse.planets;
--
-- Empire updates
--
CREATE TABLE emp.updates(
update_id BIGINT NOT NULL PRIMARY KEY ,
empire_id INT NOT NULL
);
CREATE INDEX idx_empireupdates_empire
ON emp.updates( empire_id );
ALTER TABLE emp.updates
ADD CONSTRAINT fk_empireupdates_update
FOREIGN KEY ( update_id ) REFERENCES sys.updates ,
ADD CONSTRAINT fk_empireupdates_empire
FOREIGN KEY ( empire_id ) REFERENCES emp.empires
ON DELETE CASCADE;

View file

@ -0,0 +1,172 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Game updates control tables
--
-- Copyright(C) 2004-2012, DeepClone Development
-- --------------------------------------------------------
/*
* Update targets
* ---------------
*
* An update target refers to a table whose rows are the units to be updated
* by some step of the game update.
*
* Inserting rows into this control table will generate a new, specific table
* to store references, and a set of triggers.
*/
DROP TABLE IF EXISTS sys.update_targets CASCADE;
CREATE TABLE sys.update_targets(
/* Automatically generated identifier of the target type */
updtgt_id SERIAL NOT NULL PRIMARY KEY ,
/* Name of the target, displayed in the administration interface */
updtgt_name VARCHAR( 32 ) NOT NULL ,
/* Schema in which the target table resides */
updtgt_schema NAME NOT NULL ,
/* Name of the target table */
updtgt_table NAME NOT NULL
);
/* Update target names are unique */
CREATE UNIQUE INDEX idx_updtgt_name
ON sys.update_targets ( LOWER( updtgt_name ) );
/* Schema / table combinations are unique */
CREATE UNIQUE INDEX idx_updtgt_target
ON sys.update_targets ( updtgt_schema , updtgt_table );
/*
* Update type definitions
* ------------------------
*
* An update type corresponds to a procedure which will be applied at each
* game update cycle (once per minute, unless defaults have been modified),
* and which performs a computation or set thereof on the game's data.
*/
DROP TABLE IF EXISTS sys.update_types CASCADE;
CREATE TABLE sys.update_types(
/* Automatically generated identifier of the update type */
updtype_id SERIAL NOT NULL ,
/* The type of target this update refers to */
updtgt_id INT NOT NULL ,
/* Name of the update type, used in the administration interface and when
* updates need to be executed externally.
*/
updtype_name VARCHAR( 64 ) NOT NULL ,
/* Ordering index of the update type. This field is always re-generated
* when update types are added or removed.
*/
updtype_ordering INT NOT NULL ,
/* Description of the update type to be included in the administration
* interface.
*/
updtype_description TEXT NOT NULL ,
/* Name of the stored procedure which handles the update. When this is
* NULL, the update type is assumed to be supported externally (i.e. by
* the game server) rather than internally. Otherwise, a stored procedure
* bearing that name, accepting a BIGINT as its parameter and returning
* VOID, must exist in the sys schema.
*/
updtype_proc_name NAME ,
/* Size of the update batch. If this is NULL, the global value from the
* game.batchSize constant will be used.
*/
updtype_batch_size INT ,
/* The primary key includes both the update type identifier and the target
* identifier for coherence reasons.
*/
PRIMARY KEY( updtype_id , updtgt_id ) ,
/* Batch sizes are either NULL or strictly positive */
CHECK( updtype_batch_size IS NULL
OR updtype_batch_size > 0 )
);
/* Update names must be unique, independently of the case */
CREATE UNIQUE INDEX idx_updtype_name
ON sys.update_types ( LOWER( updtype_name ) );
/* Update ordering index must be unique */
CREATE UNIQUE INDEX idx_updtype_ordering
ON sys.update_types ( updtype_ordering );
/* Procedure names must be unique */
CREATE UNIQUE INDEX idx_updtype_procname
ON sys.update_types ( updtype_proc_name );
ALTER TABLE sys.update_types
ADD CONSTRAINT fk_updtype_target
FOREIGN KEY ( updtgt_id ) REFERENCES sys.update_targets( updtgt_id );
/*
* Update state type
* ------------------
*
* This type represents the possible states of a game update
*/
DROP TYPE IF EXISTS sys.update_state_type CASCADE;
CREATE TYPE sys.update_state_type
AS ENUM (
/* The row will be included in the current game update */
'FUTURE' ,
/* The row is being processed */
'PROCESSING' ,
/* The row has been processed by the current or previous game update */
'PROCESSED'
);
/*
* Main updates table
* -------------------
*
* This table lists all update rows, including their type and target, as well
* as their state.
*/
DROP TABLE IF EXISTS sys.updates CASCADE;
CREATE TABLE sys.updates(
/* The update row's automatically generated identifier */
update_id BIGSERIAL NOT NULL ,
/* The type of update this row is about */
updtype_id INT NOT NULL ,
/* The type of target for the update */
updtgt_id INT NOT NULL ,
/* The update row's current state */
update_state sys.update_state_type
NOT NULL
DEFAULT 'FUTURE' ,
/* The tick identifier corresponding to the last game update in which
* this row was processed.
*/
update_last BIGINT NOT NULL
DEFAULT -1 ,
/* The primary key includes the automatically generated identifier but
* also the type and target type.
*/
PRIMARY KEY( update_id , updtype_id , updtgt_id )
);
ALTER TABLE sys.updates
ADD CONSTRAINT fk_update_type
FOREIGN KEY ( updtype_id , updtgt_id ) REFERENCES sys.update_types
ON DELETE CASCADE;

View file

@ -0,0 +1,571 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Game updates - support functions for update definitions
--
-- Copyright(C) 2004-2012, DeepClone Development
-- --------------------------------------------------------
/*
* Type that represents a field from a primary key
* ------------------------------------------------
*
* This type represents both the field itself (as a name) and its type.
*/
DROP TYPE IF EXISTS sys.pk_field_type CASCADE;
CREATE TYPE sys.pk_field_type AS (
f_name NAME ,
f_type NAME
);
/*
* Get a table's primary key fields and field types
* -------------------------------------------------
*
* This function will list all fields from a table's primary key along with
* their types.
*
* Parameters:
* _schema_name The name of the schema the table resides in
* _table_name The name of the table
*
* Returns:
* ? A set of sys.pk_field_type records
*/
DROP FUNCTION IF EXISTS sys.get_table_pkey( NAME , NAME ) CASCADE;
CREATE FUNCTION sys.get_table_pkey( _schema_name NAME , _table_name NAME )
RETURNS SETOF sys.pk_field_type
LANGUAGE SQL
STRICT IMMUTABLE
SECURITY INVOKER
AS $get_table_pkey$
SELECT _attr.attname AS f_name , _type.typname AS f_type
FROM pg_namespace _schema
INNER JOIN pg_class _table
ON _table.relnamespace = _schema.oid
INNER JOIN (
SELECT indrelid , unnest( indkey ) AS indattnum
FROM pg_index WHERE indisprimary
) _index ON _index.indrelid = _table.oid
INNER JOIN pg_attribute _attr
ON _attr.attrelid = _table.oid
AND _attr.attnum = _index.indattnum
INNER JOIN pg_type _type
ON _type.oid = _attr.atttypid
WHERE _schema.nspname = $1
AND _table.relname = $2
ORDER BY _index.indattnum;
$get_table_pkey$;
REVOKE EXECUTE
ON FUNCTION sys.get_table_pkey( NAME , NAME )
FROM PUBLIC;
/*
* Automatic update row insertion
* -------------------------------
*
* This trigger function is added to all type-specific update tables. It is
* called before insertions, and will make sure a generic update row exists
* for the new row.
*/
DROP FUNCTION IF EXISTS sys.tgf_speupd_before_insert( ) CASCADE;
CREATE FUNCTION sys.tgf_speupd_before_insert( )
RETURNS TRIGGER
LANGUAGE PLPGSQL
STRICT VOLATILE
SECURITY INVOKER
AS $tgf_speupd_before_insert$
DECLARE
_update_id BIGINT;
BEGIN
INSERT INTO sys.updates ( updtype_id , updtgt_id )
VALUES ( NEW.updtype_id , NEW.updtgt_id )
RETURNING update_id INTO _update_id;
NEW.update_id := _update_id;
RETURN NEW;
END;
$tgf_speupd_before_insert$;
REVOKE EXECUTE
ON FUNCTION sys.tgf_speupd_before_insert( )
FROM PUBLIC;
/*
* Automatic update row removal
* -----------------------------
*
* This trigger function is added to all type-specific update tables. It is
* called once a row has been deleted, and will remove the corresponding
* generic update row.
*/
DROP FUNCTION IF EXISTS sys.tgf_speupd_after_delete( ) CASCADE;
CREATE FUNCTION sys.tgf_speupd_after_delete( )
RETURNS TRIGGER
LANGUAGE PLPGSQL
STRICT VOLATILE
SECURITY INVOKER
AS $tgf_speupd_after_delete$
BEGIN
DELETE FROM sys.updates
WHERE update_id = OLD.update_id
AND updtype_id = OLD.updtype_id
AND updtgt_id = OLD.updtgt_id;
RETURN OLD;
END;
$tgf_speupd_after_delete$;
REVOKE EXECUTE
ON FUNCTION sys.tgf_speupd_after_delete( )
FROM PUBLIC;
/*
* Add missing update rows
* ------------------------
*
* This function adds rows missing from the update and specific update tables
* for a given target type.
*
* Parameters:
* _target_type The identifier of the target type for which missing
* rows are to be inserted.
*/
DROP FUNCTION IF EXISTS sys.insert_missing_updates( INT ) CASCADE;
CREATE FUNCTION sys.insert_missing_updates( _target_type INT )
RETURNS VOID
LANGUAGE PLPGSQL
STRICT VOLATILE
SECURITY INVOKER
AS $insert_missing_updates$
DECLARE
_t_schema TEXT;
_t_table TEXT;
_field_list TEXT;
_query TEXT;
BEGIN
SELECT INTO _t_schema , _t_table updtgt_schema , updtgt_table
FROM sys.update_targets
WHERE updtgt_id = _target_type;
SELECT INTO _field_list array_to_string( array_agg( f_name ) , ' , ' )
FROM sys.get_table_pkey( _t_schema , _t_table );
_query := 'INSERT INTO "' || _t_schema || '"."' || _t_table || '_updates" '
|| '( updtgt_id , updtype_id , ' || _field_list || ') '
|| 'SELECT updtgt_id , updtype_id , ' || _field_list
|| ' FROM sys.update_types CROSS JOIN "'
|| _t_schema || '"."' || _t_table || '" LEFT OUTER JOIN "'
|| _t_schema || '"."' || _t_table
|| '_updates" USING ( updtgt_id , updtype_id , ' || _field_list
|| ') WHERE update_id IS NULL AND updtgt_id = ' || _target_type;
EXECUTE _query;
END;
$insert_missing_updates$;
REVOKE EXECUTE
ON FUNCTION sys.insert_missing_updates( INT )
FROM PUBLIC;
/*
* Trigger function that adds missing update rows
* ----------------------------------------------
*
* This function calls sys.insert_missing_updates. The main difference between
* the original function and this one is that the former cannot be used in
* triggers, while the latter is meant to be used as a trigger on the target
* table.
*/
DROP FUNCTION IF EXISTS sys.tgf_insert_missing_updates( ) CASCADE;
CREATE FUNCTION sys.tgf_insert_missing_updates( )
RETURNS TRIGGER
LANGUAGE PLPGSQL
STRICT VOLATILE
SECURITY INVOKER
AS $tgf_insert_missing_updates$
BEGIN
IF TG_NARGS <> 1 THEN
RAISE EXCEPTION 'This trigger function requires one argument';
END IF;
PERFORM sys.insert_missing_updates( TG_ARGV[ 0 ]::INT );
RETURN NULL;
END;
$tgf_insert_missing_updates$;
REVOKE EXECUTE
ON FUNCTION sys.tgf_insert_missing_updates( )
FROM PUBLIC;
/*
* Handle new update types
* ------------------------
*
* This function is triggered when a new update type is created; it will insert
* the update rows for the new type.
*/
DROP FUNCTION IF EXISTS sys.tgf_updtype_after_insert_row( ) CASCADE;
CREATE FUNCTION sys.tgf_updtype_after_insert_row( )
RETURNS TRIGGER
LANGUAGE PLPGSQL
STRICT VOLATILE
SECURITY INVOKER
AS $tgf_updtype_after_insert$
BEGIN
PERFORM sys.insert_missing_updates( NEW.updtgt_id );
RETURN NEW;
END;
$tgf_updtype_after_insert$;
REVOKE EXECUTE
ON FUNCTION sys.tgf_updtype_after_insert_row( )
FROM PUBLIC;
CREATE TRIGGER tg_updtype_after_insert_row
AFTER INSERT ON sys.update_types
FOR EACH ROW EXECUTE PROCEDURE sys.tgf_updtype_after_insert_row( );
/*
* Update type definition check
* -----------------------------
*
* This trigger function is called when a new update type is added or when
* an update type's stored procedure is updated. It makes sure that the
* corresponding stored procedure actually exists.
*/
DROP FUNCTION IF EXISTS sys.tgf_check_update_type_proc( ) CASCADE;
CREATE FUNCTION sys.tgf_check_update_type_proc( )
RETURNS TRIGGER
LANGUAGE PLPGSQL
STRICT VOLATILE
SECURITY INVOKER
AS $tgf_check_update_type_proc$
BEGIN
IF NEW.updtype_proc_name IS NULL THEN
RETURN NEW;
END IF;
PERFORM 1
FROM pg_namespace _schema
INNER JOIN pg_proc _proc
ON _proc.pronamespace = _schema.oid
WHERE _schema.nspname = 'sys'
AND _proc.proname = NEW.updtype_proc_name;
IF NOT FOUND THEN
RAISE EXCEPTION 'Update type % has invalid update function sys.%' ,
NEW.updtype_name , NEW.updtype_proc_name;
END IF;
RETURN NEW;
END;
$tgf_check_update_type_proc$;
REVOKE EXECUTE
ON FUNCTION sys.tgf_check_update_type_proc( )
FROM PUBLIC;
CREATE TRIGGER tg_check_update_type_proc_insert
BEFORE INSERT ON sys.update_types
FOR EACH ROW EXECUTE PROCEDURE sys.tgf_check_update_type_proc( );
CREATE TRIGGER tg_check_update_type_proc_update
BEFORE UPDATE OF updtype_proc_name ON sys.update_types
FOR EACH ROW EXECUTE PROCEDURE sys.tgf_check_update_type_proc( );
/*
* Trigger that reorders the update types
* ---------------------------------------
*
* This function will update the ordering field of update types whenever rows
* are inserted or deleted.
*/
DROP FUNCTION IF EXISTS sys.tgf_reorder_update_types( ) CASCADE;
CREATE FUNCTION sys.tgf_reorder_update_types( )
RETURNS TRIGGER
LANGUAGE PLPGSQL
STRICT VOLATILE
SECURITY INVOKER
AS $tgf_reorder_update_types$
DECLARE
_max_ordering INT;
BEGIN
SELECT INTO _max_ordering MAX( updtype_ordering ) FROM sys.update_types;
IF _max_ordering IS NOT NULL THEN
UPDATE sys.update_types
SET updtype_ordering = updtype_ordering + _max_ordering * 2;
END IF;
UPDATE sys.update_types
SET updtype_ordering = updtype_rownumber * 2
FROM (
SELECT updtype_id AS id,
row_number( ) OVER (
ORDER BY updtype_ordering
) AS updtype_rownumber
FROM sys.update_types
) _row
WHERE updtype_id = _row.id;
RETURN NULL;
END;
$tgf_reorder_update_types$;
REVOKE EXECUTE
ON FUNCTION sys.tgf_reorder_update_types( )
FROM PUBLIC;
CREATE TRIGGER tg_updtype_after_insert_stmt
AFTER INSERT ON sys.update_types
FOR EACH STATEMENT EXECUTE PROCEDURE sys.tgf_reorder_update_types( );
CREATE TRIGGER tg_updtype_after_delete_stmt
AFTER DELETE ON sys.update_types
FOR EACH STATEMENT EXECUTE PROCEDURE sys.tgf_reorder_update_types( );
/*
* Check target tables
* --------------------
*
* Before a new row is inserted into sys.update_targets, make sure
* the target table it contains actually exists.
*/
DROP FUNCTION IF EXISTS sys.tgf_updtgt_before_insert( ) CASCADE;
CREATE FUNCTION sys.tgf_updtgt_before_insert( )
RETURNS TRIGGER
LANGUAGE PLPGSQL
STRICT VOLATILE
SECURITY INVOKER
AS $tgf_updtgt_before_insert$
BEGIN
PERFORM 1
FROM pg_class pc
INNER JOIN pg_namespace pn
ON pn.oid = pc.relnamespace
INNER JOIN pg_roles pr
ON pr.oid = pc.relowner
WHERE pn.nspname = NEW.updtgt_schema
AND pc.relname = NEW.updtgt_table
AND pc.reltype <> 0 AND pc.relkind = 'r'
AND pr.rolname <> 'postgres';
IF NOT FOUND THEN
RAISE EXCEPTION 'Update target table %.% not found' ,
NEW.updtgt_schema , NEW.updtgt_table
USING ERRCODE = 'foreign_key_violation';
END IF;
RETURN NEW;
END;
$tgf_updtgt_before_insert$;
REVOKE EXECUTE
ON FUNCTION sys.tgf_updtgt_before_insert( )
FROM PUBLIC;
CREATE TRIGGER tg_updtgt_before_insert
BEFORE INSERT ON sys.update_targets
FOR EACH ROW EXECUTE PROCEDURE sys.tgf_updtgt_before_insert( );
/*
* Create update list and triggers for target table
* -------------------------------------------------
*
* After a new update type has been registered, a table listing updates
* as well as a set of triggers on the target table need to be created.
*/
DROP FUNCTION IF EXISTS sys.tgf_updtgt_after_insert( ) CASCADE;
CREATE FUNCTION sys.tgf_updtgt_after_insert( )
RETURNS TRIGGER
LANGUAGE PLPGSQL
STRICT VOLATILE
AS $tgf_updtgt_after_insert$
DECLARE
_table_name TEXT;
_query TEXT;
_field_name NAME;
_field_type NAME;
_field_list TEXT;
BEGIN
_table_name := '"' || NEW.updtgt_schema || '"."' || NEW.updtgt_table || '_updates"';
_query := 'CREATE TABLE ' || _table_name || $_table_base_fields$(
update_id BIGINT NOT NULL ,
updtype_id INT NOT NULL ,
updtgt_id INT NOT NULL
$_table_base_fields$;
-- List target table's primary key fields
_field_list := '';
FOR _field_name , _field_type IN
SELECT * FROM sys.get_table_pkey( NEW.updtgt_schema , NEW.updtgt_table )
LOOP
_query := _query || ', "' || _field_name || '" "' || _field_type
|| '" NOT NULL';
IF _field_list <> '' THEN
_field_list := _field_list || ' , ';
END IF;
_field_list := _field_list || '"' || _field_name || '"';
END LOOP;
_query := _query ||
' , PRIMARY KEY ( updtgt_id , updtype_id , update_id , '
|| _field_list || ' ) , CHECK ( updtgt_id = ' || NEW.updtgt_id || ' ) )';
EXECUTE _query;
-- Add foreign keys
_query := 'ALTER TABLE ' || _table_name
|| ' ADD CONSTRAINT fk_upd_' || NEW.updtgt_table || '_update '
|| 'FOREIGN KEY ( update_id , updtype_id , updtgt_id ) REFERENCES sys.updates '
|| 'ON DELETE CASCADE , '
|| ' ADD CONSTRAINT fk_upd_' || NEW.updtgt_table || '_target '
|| 'FOREIGN KEY ( ' || _field_list
|| ' ) REFERENCES "' || NEW.updtgt_schema || '"."' || NEW.updtgt_table
|| '" ON DELETE CASCADE';
EXECUTE _query;
-- Create automatic update creation/deletion triggers
_query := 'CREATE TRIGGER tg_speupd_before_insert BEFORE INSERT ON ' || _table_name
|| ' FOR EACH ROW EXECUTE PROCEDURE sys.tgf_speupd_before_insert( )';
EXECUTE _query;
_query := 'CREATE TRIGGER tg_speupd_after_delete AFTER DELETE ON ' || _table_name
|| ' FOR EACH ROW EXECUTE PROCEDURE sys.tgf_speupd_after_delete( )';
EXECUTE _query;
-- Create triggers that will insert/delete update rows when new items are added/removed
_query := 'CREATE TRIGGER tg_speupd_after_insert AFTER INSERT ON "'
|| NEW.updtgt_schema || '"."' || NEW.updtgt_table
|| '" FOR EACH STATEMENT EXECUTE PROCEDURE sys.tgf_insert_missing_updates( '
|| NEW.updtgt_id || ' )';
EXECUTE _query;
RETURN NEW;
END;
$tgf_updtgt_after_insert$;
REVOKE EXECUTE
ON FUNCTION sys.tgf_updtgt_after_insert( )
FROM PUBLIC;
CREATE TRIGGER tg_updtgt_after_insert
AFTER INSERT ON sys.update_targets
FOR EACH ROW EXECUTE PROCEDURE sys.tgf_updtgt_after_insert( );
/*
* Trigger function that deletes specific update tables
* -----------------------------------------------------
*
* This trigger function is called after a row has been deleted from the
* update target definitions table. It will destroy the corresponding table.
*/
DROP FUNCTION IF EXISTS sys.tgf_updtgt_after_delete( );
CREATE FUNCTION sys.tgf_updtgt_after_delete( )
RETURNS TRIGGER
LANGUAGE PLPGSQL
STRICT VOLATILE
SECURITY INVOKER
AS $tgf_updtgt_after_delete$
DECLARE
_query TEXT;
BEGIN
_query := 'DROP TABLE "' || OLD.updtgt_schema || '"."' || OLD.updtgt_table || '_updates"';
EXECUTE _query;
RETURN NULL;
END;
$tgf_updtgt_after_delete$;
REVOKE EXECUTE
ON FUNCTION sys.tgf_updtgt_after_delete( )
FROM PUBLIC;
CREATE TRIGGER tg_updtgt_after_delete
AFTER DELETE ON sys.update_targets
FOR EACH ROW EXECUTE PROCEDURE sys.tgf_updtgt_after_delete( );
/*
* Stored update type registration
* --------------------------------
*
* This function can be called to register an update type that uses a stored
* procedure. The new update type is added at the end of the list of updates.
*
* Since this function is meant to be used from the SQL definition code only,
* it does not handle errors and will raise exceptions when something goes
* wrong.
*
* Parameters:
* _target The name of the target for this update type
* _name The name of the update type
* _description The update type's description
* _proc The name of the stored procedure
*/
DROP FUNCTION IF EXISTS sys.register_update_type( TEXT , TEXT , TEXT , NAME );
CREATE FUNCTION sys.register_update_type( _target TEXT , _name TEXT , _description TEXT , _proc NAME )
RETURNS VOID
LANGUAGE PLPGSQL
STRICT VOLATILE
SECURITY INVOKER
AS $register_update_type$
DECLARE
_target_id INT;
_max_ordering INT;
BEGIN
SELECT INTO _target_id updtgt_id
FROM sys.update_targets
WHERE updtgt_name = _target;
SELECT INTO _max_ordering MAX( updtype_ordering )
FROM sys.update_types;
IF _max_ordering IS NULL THEN
_max_ordering := 1;
END IF;
INSERT INTO sys.update_types(
updtgt_id , updtype_name , updtype_ordering ,
updtype_description , updtype_proc_name
) VALUES (
_target_id , _name , _max_ordering + 1 ,
_description , _proc
);
END;
$register_update_type$;
REVOKE EXECUTE
ON FUNCTION sys.register_update_type( TEXT , TEXT , TEXT , NAME )
FROM PUBLIC;

View file

@ -45,18 +45,6 @@ BEGIN
-- Add empire resources
INSERT INTO emp.resources ( empire_id , resource_name_id )
SELECT _name_id , resource_name_id FROM defs.resources;
-- Add empire update records
FOR _update_type IN SELECT _type
FROM unnest( enum_range( NULL::update_type ) ) AS _type
WHERE _type::text LIKE 'EMPIRE_%'
LOOP
INSERT INTO sys.updates( gu_type )
VALUES ( _update_type )
RETURNING id INTO _update;
INSERT INTO emp.updates ( update_id , empire_id )
VALUES ( _update , _name_id );
END LOOP;
END;
$$ LANGUAGE plpgsql;

View file

@ -196,17 +196,6 @@ BEGIN
-- FIXME: for now, just stick data about resources in the appropriate table
INSERT INTO verse.planet_resources ( planet_id , resource_name_id )
SELECT pnid , resource_name_id FROM defs.resources;
-- 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;

View file

@ -8,17 +8,29 @@
--
-- Start a tick
--
CREATE OR REPLACE FUNCTION sys.start_tick( OUT tick_id BIGINT )
/*
* Start a game update cycle
* --------------------------
*
* This function prepares the execution of a cycle of game updates. It will
* try to find the identifier of the next update, and mark all game updates
* as requiring an update for this identifier.
*
* Returns:
* tick_id The identifier of the new update cycle, or NULL if an
* update was already in progress.
*/
DROP FUNCTION IF EXISTS sys.start_tick( ) CASCADE;
CREATE FUNCTION sys.start_tick( OUT tick_id BIGINT )
LANGUAGE PLPGSQL
STRICT VOLATILE
SECURITY DEFINER
AS $$
AS $start_tick$
DECLARE
n_tick BIGINT;
c_tick BIGINT;
BEGIN
-- Get next / current tick
SELECT INTO n_tick , c_tick next_tick , current_tick
@ -31,17 +43,27 @@ BEGIN
END IF;
-- Prepare game updates
UPDATE sys.updates SET last_tick = n_tick , status = 'FUTURE'
WHERE last_tick < n_tick;
UPDATE sys.updates
SET update_last = n_tick ,
update_state = 'FUTURE'
WHERE update_last < n_tick;
-- Update system status
UPDATE sys.status SET current_tick = n_tick , next_tick = n_tick + 1;
UPDATE sys.status
SET current_tick = n_tick ,
next_tick = n_tick + 1;
tick_id := n_tick;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION sys.start_tick( ) TO :dbuser;
END;
$start_tick$;
REVOKE EXECUTE
ON FUNCTION sys.start_tick( )
FROM PUBLIC;
GRANT EXECUTE
ON FUNCTION sys.start_tick( )
TO :dbuser;
@ -64,17 +86,29 @@ $$ LANGUAGE plpgsql;
--
-- Check if a tick got "stuck"
--
CREATE OR REPLACE FUNCTION sys.check_stuck_tick( OUT tick_id BIGINT )
/*
* Check if a game update cycle got "stuck"
* -----------------------------------------
*
* Check sys.status for an in-progress game update identifier. If there is
* one, check if there are further updates to execute in the cycle in
* question.
*
* Returns:
* tick_id The stuck tick's identifier, or NULL if there is no stuck
* tick or if maintenance mode is enabled
*/
DROP FUNCTION IF EXISTS sys.check_stuck_tick( ) CASCADE;
CREATE FUNCTION sys.check_stuck_tick( OUT tick_id BIGINT )
LANGUAGE PLPGSQL
STRICT VOLATILE
SECURITY DEFINER
AS $$
AS $check_stuck_tick$
DECLARE
c_tick BIGINT;
u_count INT;
BEGIN
-- Get next / current tick
SELECT INTO c_tick current_tick
@ -87,71 +121,123 @@ BEGIN
END IF;
-- Are there any updates left?
SELECT INTO u_count count(*) FROM sys.updates
WHERE status = 'FUTURE' AND last_tick = c_tick;
SELECT INTO u_count count(*)
FROM sys.updates
WHERE update_state = 'FUTURE'
AND update_last = c_tick;
IF u_count = 0 THEN
PERFORM sys.end_tick( c_tick );
tick_id := NULL;
ELSE
tick_id := c_tick;
END IF;
END;
$$ LANGUAGE plpgsql;
$check_stuck_tick$;
GRANT EXECUTE ON FUNCTION sys.check_stuck_tick( ) TO :dbuser;
REVOKE EXECUTE
ON FUNCTION sys.check_stuck_tick( )
FROM PUBLIC;
GRANT EXECUTE
ON FUNCTION sys.check_stuck_tick( )
TO :dbuser;
--
-- Process game updates
--
-- Parameters:
-- c_tick Current tick
--
-- Returns:
-- TRUE if the function must be called again, FALSE otherwise
--
CREATE OR REPLACE FUNCTION sys.process_updates( IN c_tick BIGINT , OUT has_more BOOLEAN )
/*
* Process game updates
* ---------------------
*
* This function checks for game update elements, marking some of them for
* processing depending on their type. If there are no more updates to run,
* end the update cycle; otherwise, depending on the type of update, process
* the items internally or return a value that indicates they are to be
* processed by the external Java code.
*
* Parameters:
* _current_update Current game update's identifier
*
* Returns:
* _has_more TRUE if the function must be called again, FALSE
* otherwise
* _process_externally NULL if there is no update to process or if the
* updates were processed in the database, or
* the name of the update type if external
* processing is needed.
*/
DROP FUNCTION IF EXISTS sys.process_updates( BIGINT ) CASCADE;
CREATE FUNCTION sys.process_updates(
IN _current_update BIGINT ,
OUT _has_more BOOLEAN ,
OUT _process_externally TEXT )
LANGUAGE PLPGSQL
STRICT VOLATILE
SECURITY DEFINER
AS $$
AS $process_updates$
DECLARE
b_size INT;
p_utype update_type;
utype update_type;
uid BIGINT;
_current_type INT;
_batch_size INT;
_type_name TEXT;
_proc_name NAME;
BEGIN
b_size := sys.get_constant( 'game.batchSize' );
p_utype := NULL;
-- Mark all entries that were being processed as having been processed
UPDATE sys.updates
SET update_state = 'PROCESSED'
WHERE update_state = 'PROCESSING'
AND update_last = _current_update;
-- Mark at most b_size entries as being updated
FOR uid , utype IN SELECT id , gu_type FROM sys.updates
WHERE last_tick = c_tick AND status = 'FUTURE'
ORDER BY gu_type LIMIT b_size
LOOP
IF p_utype IS NULL THEN
p_utype := utype;
-- Find the next type of update to process and its specific parameters
SELECT INTO _current_type , _batch_size , _type_name , _proc_name
updtype_id , updtype_batch_size , updtype_name , updtype_proc_name
FROM sys.update_types
INNER JOIN sys.updates
USING ( updtype_id , updtgt_id )
WHERE update_state = 'FUTURE'
AND update_last = _current_update
ORDER BY updtype_ordering
LIMIT 1;
_has_more := FOUND;
IF _has_more THEN
-- Check batch size
IF _batch_size IS NULL THEN
_batch_size := sys.get_constant( 'game.batchSize' );
END IF;
EXIT WHEN utype <> p_utype;
UPDATE sys.updates SET status = 'PROCESSING' WHERE id = uid;
END LOOP;
-- Mark at most _batch_size entries of the right type as being updated
UPDATE sys.updates
SET update_state = 'PROCESSING'
WHERE update_id IN (
SELECT update_id FROM sys.updates
WHERE updtype_id = _current_type
AND update_state = 'FUTURE'
AND update_last = _current_update
LIMIT _batch_size
);
has_more := p_utype IS NOT NULL;
IF has_more THEN
-- Execute actual updates
EXECUTE 'SELECT sys.process_' || lower( p_utype::TEXT ) || '_updates( $1 )'
USING c_tick;
UPDATE sys.updates SET status = 'PROCESSED'
WHERE status = 'PROCESSING' AND last_tick = c_tick;
IF _proc_name IS NULL THEN
-- External processing is required
_process_externally := _type_name;
ELSE
-- Process updates using a stored procedure
EXECUTE 'SELECT sys."' || _proc_name || '"( $1 )'
USING _current_update;
END IF;
ELSE
-- If nothing was found, we're done
PERFORM sys.end_tick( c_tick );
-- No updates left to run
PERFORM sys.end_tick( _current_update );
END IF;
END;
$$ LANGUAGE plpgsql;
$process_updates$;
GRANT EXECUTE ON FUNCTION sys.process_updates( BIGINT ) TO :dbuser;
REVOKE EXECUTE
ON FUNCTION sys.process_updates( BIGINT )
FROM PUBLIC;
GRANT EXECUTE
ON FUNCTION sys.process_updates( BIGINT )
TO :dbuser;

View file

@ -0,0 +1,16 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Game updates - core update targets
--
-- Copyright(C) 2004-2012, DeepClone Development
-- --------------------------------------------------------
INSERT INTO sys.update_targets (
updtgt_name , updtgt_schema , updtgt_table
) VALUES (
'Planets' , 'verse' , 'planets'
) , (
'Empires' , 'emp' , 'empires'
);

View file

@ -18,13 +18,14 @@ DECLARE
c_debt REAL;
BEGIN
-- Lock empires for update
PERFORM e.name_id FROM sys.updates su
INNER JOIN emp.updates eu
ON eu.update_id = su.id
PERFORM e.name_id
FROM sys.updates su
INNER JOIN emp.empires_updates eu
USING ( updtgt_id , updtype_id , update_id )
INNER JOIN emp.empires e
ON eu.empire_id = e.name_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'EMPIRE_MONEY'
USING ( name_id )
WHERE su.update_last = c_tick
AND su.update_state = 'PROCESSING'
FOR UPDATE OF e;
-- Select all money-related data from empires being updated
@ -32,14 +33,16 @@ BEGIN
( pov.planet_income - pov.planet_upkeep ) AS p_money ,
fov.fleet_upkeep AS f_money , ( v.status = 'PROCESSED' ) AS on_vacation
FROM sys.updates su
INNER JOIN emp.updates eu ON eu.update_id = su.id
INNER JOIN emp.empires e ON eu.empire_id = e.name_id
INNER JOIN emp.empires_updates eu
USING ( updtgt_id , updtype_id , update_id )
INNER JOIN emp.empires e
USING ( name_id )
INNER JOIN emp.fleets_overview fov ON fov.empire = e.name_id
INNER JOIN emp.planets_overview pov ON pov.empire = e.name_id
INNER JOIN naming.empire_names en ON en.id = e.name_id
LEFT OUTER JOIN users.vacations v ON v.account_id = en.owner_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'EMPIRE_MONEY'
WHERE su.update_last = c_tick
AND su.update_state = 'PROCESSING'
LOOP
-- Compute new cash reserve
c_cash := 0;
@ -78,4 +81,12 @@ BEGIN
WHERE name_id = rec.id;
END LOOP;
END;
$$ LANGUAGE plpgsql;
$$ LANGUAGE plpgsql;
SELECT sys.register_update_type( 'Empires' , 'EmpireMoney' ,
'Empires'' money is being updated using the previous update''s results. '
|| 'This update type should disappear, as everything it does will '
|| 'be replaced by the resources update.' ,
'process_empire_money_updates'
);

View file

@ -42,17 +42,16 @@ AS $process_empire_resources_updates$
END
FROM sys.updates _upd_sys
INNER JOIN emp.updates _upd_emp
ON _upd_emp.update_id = _upd_sys.id
INNER JOIN emp.empires_updates _upd_emp
USING ( updtgt_id , updtype_id , update_id )
INNER JOIN emp.planets _emp_planets
USING ( empire_id )
ON empire_id = name_id
INNER JOIN verse.planet_resources _pl_resources
USING ( planet_id )
WHERE _upd_sys.last_tick = $1
AND _upd_sys.status = 'PROCESSING'
AND _upd_sys.gu_type = 'EMPIRE_RESOURCES'
AND _emp_resources.empire_id = _upd_emp.empire_id
WHERE _upd_sys.update_last = $1
AND _upd_sys.update_state = 'PROCESSING'
AND _emp_resources.empire_id = _upd_emp.name_id
AND _emp_resources.resource_name_id = _pl_resources.resource_name_id;
$process_empire_resources_updates$ LANGUAGE SQL;
@ -61,3 +60,10 @@ $process_empire_resources_updates$ LANGUAGE SQL;
REVOKE EXECUTE
ON FUNCTION sys.process_empire_resources_updates( BIGINT )
FROM PUBLIC;
SELECT sys.register_update_type( 'Empires' , 'EmpireResources' ,
'Empires'' resources are being updated using the previous update''s results. ' ,
'process_empire_resources_updates'
);

View file

@ -18,28 +18,31 @@ DECLARE
tu_rec RECORD;
BEGIN
-- Lock empires for update and planets for share
PERFORM e.name_id FROM sys.updates su
INNER JOIN emp.updates eu ON eu.update_id = su.id
INNER JOIN emp.empires e ON eu.empire_id = e.name_id
PERFORM e.name_id
FROM sys.updates _upd_sys
INNER JOIN emp.empires_updates eu
USING ( updtgt_id , updtype_id , update_id )
INNER JOIN emp.empires e USING ( name_id )
INNER JOIN emp.planets ep ON ep.empire_id = e.name_id
INNER JOIN verse.planets p ON p.name_id = ep.planet_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'EMPIRE_RESEARCH'
WHERE _upd_sys.update_last = c_tick
AND _upd_sys.update_state = 'PROCESSING'
FOR UPDATE OF e
FOR SHARE OF ep , p;
-- Process empires
FOR rec IN SELECT e.name_id AS id , ( v.status = 'PROCESSED' ) AS on_vacation ,
sum( p.population ) AS population
FROM sys.updates su
INNER JOIN emp.updates eu ON eu.update_id = su.id
INNER JOIN emp.empires e ON eu.empire_id = e.name_id
FROM sys.updates _upd_sys
INNER JOIN emp.empires_updates eu
USING ( updtgt_id , updtype_id , update_id )
INNER JOIN emp.empires e USING ( name_id )
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.empire_names en ON en.id = e.name_id
LEFT OUTER JOIN users.vacations v ON v.account_id = en.owner_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'EMPIRE_RESEARCH'
WHERE _upd_sys.update_last = c_tick
AND _upd_sys.update_state = 'PROCESSING'
GROUP BY e.name_id , v.status
LOOP
-- Insert any missing tech line
@ -83,4 +86,9 @@ BEGIN
END LOOP;
END LOOP;
END;
$$ LANGUAGE plpgsql;
$$ LANGUAGE plpgsql;
SELECT sys.register_update_type( 'Empires' , 'EmpireResearch' ,
'Empire research points are being attributed to technologies.' ,
'process_empire_research_updates'
);

View file

@ -25,11 +25,13 @@ BEGIN
bld_dr := sys.get_constant( 'game.debt.buildings');
FOR empire, debt IN SELECT e.name_id AS id , e.debt
FROM sys.updates su
INNER JOIN emp.updates eu ON eu.update_id = su.id
INNER JOIN emp.empires e ON eu.empire_id = e.name_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'EMPIRE_DEBT' AND e.debt > 0
FROM sys.updates _upd_sys
INNER JOIN emp.empires_updates eu
USING ( updtgt_id , updtype_id , update_id )
INNER JOIN emp.empires e USING ( name_id )
WHERE _upd_sys.update_last = c_tick
AND _upd_sys.update_state = 'PROCESSING'
AND e.debt > 0
FOR UPDATE
LOOP
PERFORM sys.write_log( 'EmpireDebt' , 'DEBUG'::log_level , 'Handling debt for empire #'
@ -59,4 +61,9 @@ BEGIN
PERFORM verse.handle_debt( empire , upkeep , debt , bld_dr );
END LOOP;
END;
$$ LANGUAGE plpgsql;
$$ LANGUAGE plpgsql;
SELECT sys.register_update_type( 'Empires' , 'EmpireDebt' ,
'The effects of empires'' debts are being computed.' ,
'process_empire_debt_updates'
);

View file

@ -7,7 +7,7 @@
-- --------------------------------------------------------
CREATE OR REPLACE FUNCTION sys.process_planet_fleet_arrivals_updates( c_tick BIGINT )
CREATE OR REPLACE FUNCTION sys.process_fleet_arrivals_updates( c_tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
@ -18,14 +18,16 @@ DECLARE
f_ids BIGINT[];
BEGIN
-- Lock all records
PERFORM f.id FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
PERFORM 1
FROM sys.updates su
INNER JOIN verse.planets_updates vu
USING ( update_id , updtype_id , updtgt_id )
INNER JOIN verse.planets p
USING ( name_id )
INNER JOIN fleets.fleets f ON f.location_id = p.name_id
INNER JOIN fleets.movements fm ON fm.fleet_id = f.id
INNER JOIN emp.empires e ON e.name_id = f.owner_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_FLEET_ARRIVALS'
WHERE su.update_last = c_tick AND su.update_state = 'PROCESSING'
AND f.status = 'AVAILABLE' AND fm.time_left = 1
FOR UPDATE;
@ -34,8 +36,10 @@ BEGIN
f.owner_id AS fleet_owner , ( v.status = 'PROCESSED' AND b.id IS NULL ) AS on_vacation ,
bool_or( f.attacking ) AS attacking
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
INNER JOIN verse.planets_updates vu
USING ( update_id , updtype_id , updtgt_id )
INNER JOIN verse.planets p
USING ( name_id )
INNER JOIN fleets.fleets f ON f.location_id = p.name_id
INNER JOIN fleets.movements fm ON fm.fleet_id = f.id
LEFT OUTER JOIN emp.planets ep ON ep.planet_id = p.name_id
@ -43,9 +47,8 @@ BEGIN
LEFT OUTER JOIN users.vacations v ON v.account_id = en.owner_id
LEFT OUTER JOIN battles.battles b
ON b.location_id = p.name_id AND b.last_tick IS NULL
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_FLEET_ARRIVALS'
AND f.status = 'AVAILABLE' AND fm.time_left = 1
WHERE su.update_last = c_tick AND su.update_state = 'PROCESSING'
AND f.status = 'AVAILABLE' AND fm.time_left = 1
GROUP BY p.name_id , ep.empire_id , f.owner_id , v.status , b.id
LOOP
-- Fleets owned by the planet's owner are never attacking, same for fleets arriving on
@ -103,16 +106,17 @@ BEGIN
SELECT f.location_id , ln.name , f.owner_id , fon.name ,
f.name , fs.power , f.attacking , fm.source_id , sn.name
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
INNER JOIN verse.planets_updates vu
USING ( update_id , updtype_id , updtgt_id )
INNER JOIN verse.planets p
USING ( name_id )
INNER JOIN fleets.fleets f ON f.location_id = p.name_id
INNER JOIN fleets.movements fm ON fm.fleet_id = f.id
INNER JOIN fleets.stats_view fs ON fs.id = f.id
INNER JOIN naming.empire_names fon ON fon.id = f.owner_id
INNER JOIN naming.map_names ln ON ln.id = f.location_id
INNER JOIN naming.map_names sn ON sn.id = fm.source_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_FLEET_ARRIVALS'
WHERE su.update_last = c_tick AND su.update_state = 'PROCESSING'
AND f.status = 'AVAILABLE' AND fm.time_left = 1;
-- Delete movement records, set redeployment penalties, update battles
@ -120,15 +124,16 @@ BEGIN
f.attacking AS attacking , b.id AS battle ,
f.location_id AS location
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
INNER JOIN verse.planets_updates vu
USING ( update_id , updtype_id , updtgt_id )
INNER JOIN verse.planets p
USING ( name_id )
INNER JOIN fleets.fleets f ON f.location_id = p.name_id
INNER JOIN fleets.movements fm ON fm.fleet_id = f.id
INNER JOIN fleets.stats_view fs ON fs.id = f.id
LEFT OUTER JOIN battles.battles b
ON b.location_id = p.name_id AND b.last_tick IS NULL
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_FLEET_ARRIVALS'
WHERE su.update_last = c_tick AND su.update_state = 'PROCESSING'
AND f.status = 'AVAILABLE' AND fm.time_left = 1
LOOP
DELETE FROM fleets.movements
@ -145,4 +150,10 @@ BEGIN
-- Send fleet arrival events
PERFORM events.commit_fleet_arrivals( c_tick );
END;
$$ LANGUAGE plpgsql;
$$ LANGUAGE plpgsql;
SELECT sys.register_update_type( 'Planets' , 'FleetArrivals' ,
'Fleets which were one update away are arriving at their destinations.' ,
'process_fleet_arrivals_updates'
);

View file

@ -7,7 +7,7 @@
-- --------------------------------------------------------
CREATE OR REPLACE FUNCTION sys.process_planet_fleet_movements_updates( c_tick BIGINT )
CREATE OR REPLACE FUNCTION sys.process_fleet_movements_updates( c_tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
@ -18,13 +18,14 @@ DECLARE
BEGIN
-- Lock all records
PERFORM f.id FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
INNER JOIN verse.planets_updates vu
USING ( update_id , updtype_id , updtgt_id )
INNER JOIN verse.planets p
USING ( name_id )
INNER JOIN fleets.fleets f ON f.location_id = p.name_id
INNER JOIN fleets.movements fm ON fm.fleet_id = f.id
INNER JOIN emp.empires e ON e.name_id = f.owner_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_FLEET_MOVEMENTS'
WHERE su.update_last = c_tick AND su.update_state = 'PROCESSING'
AND f.status = 'AVAILABLE'
FOR UPDATE;
@ -36,8 +37,10 @@ BEGIN
rp.system_id AS is_ref_point_system , rp.orbit AS is_ref_point_orbit ,
rps.x AS is_ref_point_x , rps.y AS is_ref_point_y
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
INNER JOIN verse.planets_updates vu
USING ( update_id , updtype_id , updtgt_id )
INNER JOIN verse.planets p
USING ( name_id )
INNER JOIN verse.systems s ON s.id = p.system_id
INNER JOIN fleets.fleets f ON f.location_id = p.name_id
INNER JOIN fleets.ships fs ON fs.fleet_id = f.id
@ -46,8 +49,7 @@ BEGIN
LEFT OUTER JOIN fleets.ms_system isms ON isms.movement_id = f.id
LEFT OUTER JOIN verse.planets rp ON isms.ref_point_id = rp.name_id
LEFT OUTER JOIN verse.systems rps ON rps.id = rp.system_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_FLEET_MOVEMENTS'
WHERE su.update_last = c_tick AND su.update_state = 'PROCESSING'
AND f.status = 'AVAILABLE' AND m.state_time_left = 1
GROUP BY f.id , s.x , s.y , s.id , isms.ref_point_id , isms.outwards ,
isms.past_ref_point , rp.system_id , rp.orbit , rps.x , rps.y
@ -98,13 +100,19 @@ BEGIN
time_left = time_left - 1
WHERE fleet_id IN (
SELECT f.id FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
INNER JOIN verse.planets_updates vu
USING ( update_id , updtype_id , updtgt_id )
INNER JOIN verse.planets p
USING ( name_id )
INNER JOIN fleets.fleets f ON f.location_id = p.name_id
INNER JOIN fleets.movements fm ON fm.fleet_id = f.id
INNER JOIN emp.empires e ON e.name_id = f.owner_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_FLEET_MOVEMENTS'
WHERE su.update_last = c_tick AND su.update_state = 'PROCESSING'
AND f.status = 'AVAILABLE' );
END;
$$ LANGUAGE plpgsql;
$$ LANGUAGE plpgsql;
SELECT sys.register_update_type( 'Planets' , 'FleetMovements' ,
'Fleets are moving.' ,
'process_fleet_movements_updates'
);

View file

@ -7,7 +7,7 @@
-- --------------------------------------------------------
CREATE OR REPLACE FUNCTION sys.process_planet_fleet_status_updates( c_tick BIGINT )
CREATE OR REPLACE FUNCTION sys.process_fleet_status_updates( c_tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
@ -18,26 +18,27 @@ DECLARE
BEGIN
-- Lock all records
PERFORM f.id FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
INNER JOIN verse.planets_updates vu
USING ( update_id , updtype_id , updtgt_id )
INNER JOIN verse.planets p
USING ( name_id )
INNER JOIN fleets.fleets f ON f.location_id = p.name_id
INNER JOIN emp.empires e ON e.name_id = f.owner_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_FLEET_STATUS'
WHERE su.update_last = c_tick AND su.update_state = 'PROCESSING'
FOR UPDATE;
-- Fleet deployments
FOR rec IN SELECT f.id AS fleet , f.owner_id AS owner , f.location_id AS location ,
b.id AS battle
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN fleets.fleets f ON f.location_id = vu.planet_id
INNER JOIN verse.planets_updates vu
USING ( update_id , updtype_id , updtgt_id )
INNER JOIN fleets.fleets f ON f.location_id = vu.name_id
AND f.status = 'DEPLOYING' AND f.penalty = 1
INNER JOIN emp.empires e ON e.name_id = f.owner_id
LEFT OUTER JOIN battles.battles b
ON b.location_id = f.location_id AND b.last_tick IS NULL
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_FLEET_STATUS'
WHERE su.update_last = c_tick AND su.update_state = 'PROCESSING'
LOOP
-- Add fleet to battle (will be ignored if battle is NULL)
PERFORM battles.add_fleet( rec.battle , rec.fleet , TRUE , c_tick );
@ -62,16 +63,21 @@ BEGIN
-- Fleets that must become available
UPDATE fleets.fleets f SET status = 'AVAILABLE' , penalty = 0
FROM sys.updates su , verse.updates vu
WHERE vu.update_id = su.id AND f.location_id = vu.planet_id
AND f.penalty = 1 AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_FLEET_STATUS' AND su.last_tick = c_tick;
FROM sys.updates su , verse.planets_updates vu
WHERE vu.update_id = su.update_id AND f.location_id = vu.name_id
AND f.penalty = 1
AND su.update_state = 'PROCESSING' AND su.update_last = c_tick;
-- Fleets that still have a penalty
UPDATE fleets.fleets f SET penalty = penalty - 1
FROM sys.updates su , verse.updates vu
WHERE vu.update_id = su.id AND f.location_id = vu.planet_id
AND f.penalty > 1 AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_FLEET_STATUS' AND su.last_tick = c_tick;
FROM sys.updates su , verse.planets_updates vu
WHERE vu.update_id = su.update_id AND f.location_id = vu.name_id
AND f.penalty > 1
AND su.update_state = 'PROCESSING' AND su.update_last = c_tick;
END;
$$ LANGUAGE plpgsql;
$$ LANGUAGE plpgsql;
SELECT sys.register_update_type( 'Planets' , 'FleetStatus' ,
'Fleet states (e.g. "deploying", "unavailable", etc...) are being updated.' ,
'process_fleet_status_updates'
);

View file

@ -7,7 +7,7 @@
-- --------------------------------------------------------
CREATE OR REPLACE FUNCTION sys.process_planet_battle_start_updates( c_tick BIGINT )
CREATE OR REPLACE FUNCTION sys.process_battle_start_updates( c_tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
@ -17,12 +17,14 @@ DECLARE
BEGIN
FOR p_id IN SELECT p.name_id
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON vu.planet_id = p.name_id
INNER JOIN verse.planets_updates vu
USING ( update_id , updtype_id , updtgt_id )
INNER JOIN verse.planets p
USING ( name_id )
LEFT OUTER JOIN battles.battles b
ON b.location_id = p.name_id AND b.last_tick IS NULL
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_BATTLE_START' AND b.location_id IS NULL
WHERE su.update_last = c_tick AND su.update_state = 'PROCESSING'
AND b.location_id IS NULL
FOR UPDATE OF p
LOOP
IF battles.check_start( p_id ) THEN
@ -32,10 +34,13 @@ BEGIN
END;
$$ LANGUAGE plpgsql;
SELECT sys.register_update_type( 'Planets' , 'BattleStart' ,
'Battles are being started.' ,
'process_battle_start_updates'
);
CREATE OR REPLACE FUNCTION sys.process_planet_battle_main_updates( c_tick BIGINT )
CREATE OR REPLACE FUNCTION sys.process_battle_main_updates( c_tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
@ -63,13 +68,14 @@ BEGIN
FOR rec IN SELECT b.id AS battle , b.first_tick AS first_tick ,
b.location_id AS location , ( ph.current / p.population )::REAL AS happiness
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON vu.planet_id = p.name_id
INNER JOIN verse.planets_updates vu
USING ( update_id , updtype_id , updtgt_id )
INNER JOIN verse.planets p
USING ( name_id )
INNER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id
INNER JOIN battles.battles b
ON b.location_id = p.name_id AND b.last_tick IS NULL
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_BATTLE_MAIN'
WHERE su.update_last = c_tick AND su.update_state = 'PROCESSING'
FOR UPDATE OF p , b
LOOP
PERFORM sys.write_log( 'BattleUpdate' , 'DEBUG'::log_level , 'Handling battle #' || rec.battle
@ -115,10 +121,14 @@ BEGIN
END;
$$ LANGUAGE plpgsql;
SELECT sys.register_update_type( 'Planets' , 'BattleCompute' ,
'In-progress battles are being updated.' ,
'process_battle_main_updates'
);
CREATE OR REPLACE FUNCTION sys.process_planet_battle_end_updates( c_tick BIGINT )
CREATE OR REPLACE FUNCTION sys.process_battle_end_updates( c_tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
@ -129,12 +139,13 @@ DECLARE
BEGIN
FOR rec IN SELECT b.id AS battle , b.location_id AS location
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON vu.planet_id = p.name_id
INNER JOIN verse.planets_updates vu
USING ( update_id , updtype_id , updtgt_id )
INNER JOIN verse.planets p
USING ( name_id )
INNER JOIN battles.battles b
ON b.location_id = p.name_id AND b.last_tick IS NULL
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_BATTLE_END'
WHERE su.update_last = c_tick AND su.update_state = 'PROCESSING'
FOR UPDATE OF p , b
LOOP
IF battles.get_fleets_power( rec.battle , c_tick , TRUE ) = 0 THEN
@ -179,3 +190,7 @@ BEGIN
END;
$$ LANGUAGE plpgsql;
SELECT sys.register_update_type( 'Planets' , 'BattleEnd' ,
'Finished battles are being ended.' ,
'process_battle_end_updates'
);

View file

@ -16,24 +16,31 @@ DECLARE
p_id INT;
BEGIN
-- Lock all records
PERFORM p.name_id FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
INNER JOIN emp.planets ep ON p.name_id = vu.planet_id
INNER JOIN emp.empires e ON e.name_id = ep.empire_id
INNER JOIN emp.abandon a ON a.planet_id = p.name_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_ABANDON'
PERFORM p.name_id
FROM sys.updates su
INNER JOIN verse.planets_updates vu
USING ( update_id , updtype_id , updtgt_id )
INNER JOIN verse.planets p
USING ( name_id )
INNER JOIN emp.planets ep
ON ep.planet_id = p.name_id
INNER JOIN emp.empires e
ON e.name_id = ep.empire_id
INNER JOIN emp.abandon a
ON a.planet_id = p.name_id
WHERE su.update_last = c_tick AND su.update_state = 'PROCESSING'
FOR UPDATE;
-- Handle planets where time has run out
FOR p_id IN SELECT p.name_id
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
INNER JOIN emp.abandon a ON a.planet_id = p.name_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_ABANDON' AND a.time_left = 1
INNER JOIN verse.planets_updates vu
USING ( update_id , updtype_id , updtgt_id )
INNER JOIN verse.planets p
USING ( name_id )
INNER JOIN emp.abandon a ON a.planet_id = p.name_id
WHERE su.update_last = c_tick AND su.update_state = 'PROCESSING'
AND a.time_left = 1
LOOP
PERFORM emp.leave_planet( p_id );
END LOOP;
@ -41,8 +48,14 @@ BEGIN
-- Update all abandon records
UPDATE emp.abandon a SET time_left = a.time_left - 1
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_ABANDON' AND a.planet_id = vu.planet_id;
INNER JOIN verse.planets_updates vu
USING ( update_id , updtype_id , updtgt_id )
WHERE su.update_last = c_tick AND su.update_state = 'PROCESSING'
AND a.planet_id = vu.name_id;
END;
$$ LANGUAGE plpgsql;
$$ LANGUAGE plpgsql;
SELECT sys.register_update_type( 'Planets' , 'PlanetAbandon' ,
'Planets are being abandoned.' ,
'process_planet_abandon_updates'
);

View file

@ -46,8 +46,10 @@ BEGIN
qi.destroy AS destroy , qi.building_id AS building ,
b.work AS req_work , b.cost AS req_cost
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON vu.planet_id = p.name_id
INNER JOIN verse.planets_updates vu
USING ( update_id , updtype_id , updtgt_id )
INNER JOIN verse.planets p
USING ( name_id )
INNER JOIN emp.planets ep ON ep.planet_id = p.name_id
INNER JOIN emp.empires e ON e.name_id = ep.empire_id
INNER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id
@ -56,8 +58,7 @@ BEGIN
INNER JOIN tech.buildables b ON b.name_id = qi.building_id
INNER JOIN naming.empire_names en ON en.id = e.name_id
LEFT OUTER JOIN users.vacations v ON v.account_id = en.owner_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_CONSTRUCTION'
WHERE su.update_last = c_tick AND su.update_state = 'PROCESSING'
AND ( v.account_id IS NULL OR v.status <> 'PROCESSED' )
ORDER BY e.name_id , p.name_id , qi.queue_order
FOR UPDATE OF p , e , q , qi
@ -215,3 +216,8 @@ BEGIN
END IF;
END;
$$ LANGUAGE plpgsql;
SELECT sys.register_update_type( 'Planets' , 'CivilianConstruction' ,
'Civilian build queues are being processed.' ,
'process_planet_construction_updates'
);

View file

@ -44,8 +44,10 @@ BEGIN
qi.queue_order AS qorder , qi.amount AS amount ,
qi.ship_id AS ship , s.work AS req_work , s.cost AS req_cost
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON vu.planet_id = p.name_id
INNER JOIN verse.planets_updates vu
USING ( update_id , updtype_id , updtgt_id )
INNER JOIN verse.planets p
USING ( name_id )
INNER JOIN emp.planets ep ON ep.planet_id = p.name_id
INNER JOIN emp.empires e ON e.name_id = ep.empire_id
INNER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id
@ -54,8 +56,7 @@ BEGIN
INNER JOIN tech.buildables s ON s.name_id = qi.ship_id
INNER JOIN naming.empire_names en ON en.id = e.name_id
LEFT OUTER JOIN users.vacations v ON v.account_id = en.owner_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_MILITARY'
WHERE su.update_last = c_tick AND su.update_state = 'PROCESSING'
AND ( v.account_id IS NULL OR v.status <> 'PROCESSED' )
ORDER BY e.name_id , p.name_id , qi.queue_order
FOR UPDATE OF p , e , q , qi
@ -225,3 +226,8 @@ BEGIN
DROP TABLE blt_ships;
END;
$$ LANGUAGE plpgsql;
SELECT sys.register_update_type( 'Planets' , 'MilitaryConstruction' ,
'Military build queues are being processed.' ,
'process_planet_military_updates'
);

View file

@ -37,11 +37,12 @@ BEGIN
ph.target AS target , ph.current AS happy_pop ,
( ph.current / p.population )::REAL AS current
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON vu.planet_id = p.name_id
INNER JOIN verse.planets_updates vu
USING ( update_id , updtype_id , updtgt_id )
INNER JOIN verse.planets p
USING ( name_id )
INNER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_POPULATION'
WHERE su.update_last = c_tick AND su.update_state = 'PROCESSING'
FOR UPDATE OF p, ph
LOOP
IF round( rec.target / rel_ch ) = round( rec.current / rel_ch ) THEN
@ -101,4 +102,9 @@ BEGIN
END IF;
END LOOP;
END;
$$ LANGUAGE plpgsql;
$$ LANGUAGE plpgsql;
SELECT sys.register_update_type( 'Planets' , 'PlanetPopulation' ,
'Planet populations are being updated.' ,
'process_planet_population_updates'
);

View file

@ -16,7 +16,7 @@
* Parameters:
* _tick The identifier of the game update
*/
CREATE OR REPLACE FUNCTION sys.process_planet_res_regen_updates( _tick BIGINT )
CREATE OR REPLACE FUNCTION sys.process_res_regen_updates( _tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
@ -31,17 +31,21 @@ AS $process_planet_res_regen_updates$
)
FROM sys.updates _upd_sys
INNER JOIN verse.updates _upd_verse
ON _upd_verse.update_id = _upd_sys.id
INNER JOIN verse.planets_updates _upd_verse
USING ( update_id , updtype_id , updtgt_id )
WHERE _upd_sys.last_tick = $1
AND _upd_sys.status = 'PROCESSING'
AND _upd_sys.gu_type = 'PLANET_RES_REGEN'
AND _provider.planet_id = _upd_verse.planet_id;
WHERE _upd_sys.update_last = $1
AND _upd_sys.update_state = 'PROCESSING'
AND _provider.planet_id = _upd_verse.name_id;
$process_planet_res_regen_updates$ LANGUAGE SQL;
REVOKE EXECUTE
ON FUNCTION sys.process_planet_res_regen_updates( BIGINT )
ON FUNCTION sys.process_res_regen_updates( BIGINT )
FROM PUBLIC;
SELECT sys.register_update_type( 'Planets' , 'ResourceRegeneration' ,
'Resource providers are being regenerated.' ,
'process_res_regen_updates'
);

View file

@ -20,13 +20,14 @@ BEGIN
( ph.current / p.population )::REAL AS happiness ,
( ea.planet_id IS NULL ) AS produces_income
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON vu.planet_id = p.name_id
INNER JOIN verse.planets_updates vu
USING ( update_id , updtype_id , updtgt_id )
INNER JOIN verse.planets p
USING ( 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
LEFT OUTER JOIN emp.abandon ea ON ea.planet_id = p.name_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_MONEY'
WHERE su.update_last = c_tick AND su.update_state = 'PROCESSING'
FOR UPDATE OF p, pm
LOOP
IF rec.produces_income THEN
@ -42,4 +43,9 @@ BEGIN
WHERE planet_id = rec.id;
END LOOP;
END;
$$ LANGUAGE plpgsql;
$$ LANGUAGE plpgsql;
SELECT sys.register_update_type( 'Planets' , 'PlanetMoney' ,
'Planets'' income and upkeep are being updated.' ,
'process_planet_money_updates'
);

View file

@ -127,12 +127,12 @@ AS $gu_pmc_get_data$
pmc_total AS total_weight
FROM sys.updates _upd_sys
INNER JOIN verse.updates _upd_verse
ON _upd_sys.id = _upd_verse.update_id
INNER JOIN verse.planets_updates _upd_verse
USING ( update_id , updtype_id , updtgt_id )
INNER JOIN verse.planets _planet
ON _planet.name_id = _upd_verse.planet_id
USING ( name_id )
INNER JOIN verse.resource_providers _resprov
USING ( planet_id )
ON planet_id = name_id
INNER JOIN verse.planet_resources _pres
USING ( planet_id , resource_name_id )
LEFT OUTER JOIN (
@ -141,10 +141,10 @@ AS $gu_pmc_get_data$
pmc_total , _happ.current AS happiness
FROM sys.updates _upd_sys
INNER JOIN verse.updates _upd_verse
ON _upd_sys.id = _upd_verse.update_id
INNER JOIN verse.planets_updates _upd_verse
USING ( update_id , updtype_id , updtgt_id )
INNER JOIN emp.planets _emp_planet
USING ( planet_id )
ON _emp_planet.planet_id = _upd_verse.name_id
INNER JOIN emp.empires _emp
ON _emp_planet.empire_id = _emp.name_id
INNER JOIN emp.mining_settings _emset
@ -161,17 +161,15 @@ AS $gu_pmc_get_data$
) AS _pmset
USING ( empire_id , planet_id , resource_name_id )
WHERE _upd_sys.last_tick = $1
AND _upd_sys.status = 'PROCESSING'
AND _upd_sys.gu_type = 'PLANET_MINING'
WHERE _upd_sys.update_last = $1
AND _upd_sys.update_state = 'PROCESSING'
FOR SHARE OF _emp_planet , _emp , _emset , _happ
) AS _owner
USING ( planet_id , resource_name_id )
WHERE _upd_sys.last_tick = $1
AND _upd_sys.status = 'PROCESSING'
AND _upd_sys.gu_type = 'PLANET_MINING'
WHERE _upd_sys.update_last = $1
AND _upd_sys.update_state = 'PROCESSING'
FOR UPDATE OF _resprov , _pres
FOR SHARE OF _planet ;
@ -286,3 +284,8 @@ $process_planet_mining_updates$ LANGUAGE PLPGSQL;
REVOKE EXECUTE
ON FUNCTION sys.process_planet_mining_updates( BIGINT )
FROM PUBLIC;
SELECT sys.register_update_type( 'Planets' , 'PlanetMining' ,
'Resources are being extracted from mines.' ,
'process_planet_mining_updates'
);