This repository has been archived on 2025-01-04. You can view files and clone it, but cannot push or open issues or pull requests.
lwb6/legacyworlds-server-data/db-structure/parts/040-functions/170-events.sql
Emmanuel BENOîT 0c67d1e799 Event definition functions
Added functions that allow new event types to be defined. The functions
are:
 * events.evdef_start() which starts recording a definition,
 * events.evdef_addfld_*(), a set of functions to add fields to
the current definition,
 * events.evdef_finalise() which adds the definition records and creates
the event queue table.

It is not possible to modify or delete event definitions at this time.
They will be added if and when they become necessary.
2012-06-29 15:18:18 +02:00

1717 lines
48 KiB
PL/PgSQL

-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Functions and views to create and manipulate events
--
-- Copyright(C) 2004-2012, DeepClone Development
-- --------------------------------------------------------
/*
* Return values for event definition functions
* ---------------------------------------------
*/
DROP TYPE IF EXISTS events.evdef_create_result CASCADE;
CREATE TYPE events.evdef_create_result AS ENUM(
/* The event type definition function succeeded. If it was the initial
* creation function or a field creation function, this means the creation
* can continue. If it was the finalisation function, this means the event
* definition has been added.
*/
'OK' ,
/* A bad identifier was specified. This value is returned by both the
* initial creation function and event field definition functions.
*/
'BAD_ID' ,
/* Duplicate event or field identifier found. This value is returned by
* the finalisation function, with its "_fld" set to NULL if the duplicate
* identifier is the event's.
*/
'DUPLICATE' ,
/* Bad event or field specification found. This value is returned by the
* finalisation function when an event or field cannot be inserted due to
* check failures.
*/
'BAD_SPEC'
);
/*
* Start defining a new event type
* -------------------------------
*
* This function creates a temporary table used to defgine a new type of
* event. No checks beyond the length and contents of the event type's
* identifier are made at this point.
*
* Note: the temporary table will be created in all cases, even when the
* identifier is invalid.
*
* Parameters:
* _id The identifier of the event type
* _prio The event type's default priority
* _adj Whether the player may adjust the priority for this type
* of events.
*
* Returns:
* ??? An error code: OK or BAD_ID
* (see events.evdef_create_result)
*/
DROP FUNCTION IF EXISTS events.evdef_start( TEXT , INT , BOOLEAN );
CREATE FUNCTION events.evdef_start( _id TEXT , _prio INT , _adj BOOLEAN )
RETURNS events.evdef_create_result
LANGUAGE PLPGSQL
STRICT VOLATILE SECURITY DEFINER
AS $evdef_start$
BEGIN
CREATE TEMPORARY TABLE evdef_temp(
evdef_id TEXT ,
evfld_id TEXT ,
evfld_typespec TEXT
) ON COMMIT DROP;
IF LENGTH( _id ) < 2 OR LENGTH( _id ) > 48
OR NOT _id ~ '^[a-z\-]+$'
THEN
RETURN 'BAD_ID'::events.evdef_create_result;
END IF;
INSERT INTO evdef_temp( evdef_id , evfld_typespec )
VALUES( _id , _prio::TEXT || ' , ' || _adj::TEXT );
RETURN 'OK'::events.evdef_create_result;
END;
$evdef_start$;
REVOKE EXECUTE
ON FUNCTION events.evdef_start( TEXT , INT , BOOLEAN )
FROM PUBLIC;
GRANT EXECUTE
ON FUNCTION events.evdef_start( TEXT , INT , BOOLEAN )
TO :dbuser;
/*
* Create a new field
* ------------------
*
* /!\ INTERNAL FUNCTION /!\
*
* This function adds data about a new field to the temporary event
* definition table.
*
* Parameters:
* _id The field's identifier
* _opt Whether the field is optional
* _type The field's type
* _etype The field's entity type (may be NULL)
* _is_int Whether the field is an integer (may be NULL)
* _min_val Minimal value/length (may be NULL)
* _max_val Maximal value/length (may be NULL)
*
* Returns:
* ??? An error code: OK or BAD_ID
* (see events.evdef_create_result)
*/
DROP FUNCTION IF EXISTS events.evdef_addfld_internal(
TEXT , BOOLEAN , events.field_type , events.entity_field_type ,
BOOLEAN , NUMERIC , NUMERIC ) CASCADE;
CREATE FUNCTION events.evdef_addfld_internal(
_id TEXT ,
_opt BOOLEAN ,
_type events.field_type ,
_etype events.entity_field_type ,
_is_int BOOLEAN ,
_min_val NUMERIC ,
_max_val NUMERIC
) RETURNS events.evdef_create_result
LANGUAGE PLPGSQL
CALLED ON NULL INPUT
VOLATILE SECURITY INVOKER
AS $evdef_addfld_internal$
DECLARE
_iq_string TEXT;
BEGIN
IF LENGTH( _id ) < 2 OR LENGTH( _id ) > 48
OR NOT _id ~ '^[a-z\-]+$'
THEN
RETURN 'BAD_ID'::events.evdef_create_result;
END IF;
_iq_string := _opt::TEXT || ' , ''' || _type::TEXT || ''' , ';
IF _etype IS NULL
THEN
_iq_string := _iq_string || 'NULL';
ELSE
_iq_string := _iq_string || '''' || _etype::TEXT || '''';
END IF;
_iq_string := _iq_string || ' , ';
IF _is_int IS NULL
THEN
_iq_string := _iq_string || 'NULL';
ELSE
_iq_string := _iq_string || _is_int::TEXT;
END IF;
_iq_string := _iq_string || ' , ';
IF _min_val IS NULL
THEN
_iq_string := _iq_string || 'NULL';
ELSE
_iq_string := _iq_string || _min_val::TEXT;
END IF;
_iq_string := _iq_string || ' , ';
IF _max_val IS NULL
THEN
_iq_string := _iq_string || 'NULL';
ELSE
_iq_string := _iq_string || _max_val::TEXT;
END IF;
INSERT INTO evdef_temp( evdef_id , evfld_id , evfld_typespec )
SELECT evdef_id , _id , _iq_string
FROM evdef_temp
WHERE evfld_id IS NULL;
RETURN 'OK'::events.evdef_create_result;
END;
$evdef_addfld_internal$;
REVOKE EXECUTE
ON FUNCTION events.evdef_addfld_internal(
TEXT , BOOLEAN , events.field_type , events.entity_field_type ,
BOOLEAN , NUMERIC , NUMERIC )
FROM PUBLIC;
/*
* Actual field creation functions
* --------------------------------
*
* Bunch of functions that create the field records in the temporary table
* through events.evdef_addfld_internal().
*
* Note:
* These functions are not dropped manually here, as it is assumed that
* dropping events.evdef_addfld_internal() will have cascaded.
*/
-- INTEGER FIELD, NO BOUNDS
CREATE FUNCTION events.evdef_addfld_int( _id TEXT , _opt BOOLEAN )
RETURNS events.evdef_create_result
LANGUAGE SQL
STRICT VOLATILE SECURITY DEFINER
AS $$ SELECT events.evdef_addfld_internal(
$1,$2,'NUMERIC'::events.field_type,NULL,TRUE,NULL,NULL); $$;
REVOKE EXECUTE
ON FUNCTION events.evdef_addfld_int( TEXT , BOOLEAN )
FROM PUBLIC;
GRANT EXECUTE
ON FUNCTION events.evdef_addfld_int( TEXT , BOOLEAN )
TO :dbuser;
-- INTEGER FIELD W/ LOWER BOUND
CREATE FUNCTION events.evdef_addfld_int_min( _id TEXT , _opt BOOLEAN , _min INT )
RETURNS events.evdef_create_result
LANGUAGE SQL
STRICT VOLATILE SECURITY DEFINER
AS $$ SELECT events.evdef_addfld_internal(
$1,$2,'NUMERIC'::events.field_type,NULL,TRUE,$3::NUMERIC,NULL); $$;
REVOKE EXECUTE
ON FUNCTION events.evdef_addfld_int_min( TEXT , BOOLEAN , INT )
FROM PUBLIC;
GRANT EXECUTE
ON FUNCTION events.evdef_addfld_int_min( TEXT , BOOLEAN , INT )
TO :dbuser;
-- INTEGER FIELD W/ HIGHER BOUND
CREATE FUNCTION events.evdef_addfld_int_max( _id TEXT , _opt BOOLEAN , _max INT )
RETURNS events.evdef_create_result
LANGUAGE SQL
STRICT VOLATILE SECURITY DEFINER
AS $$ SELECT events.evdef_addfld_internal(
$1,$2,'NUMERIC'::events.field_type,NULL,TRUE,NULL,$3::NUMERIC); $$;
REVOKE EXECUTE
ON FUNCTION events.evdef_addfld_int_max( TEXT , BOOLEAN , INT )
FROM PUBLIC;
GRANT EXECUTE
ON FUNCTION events.evdef_addfld_int_max( TEXT , BOOLEAN , INT )
TO :dbuser;
-- INTEGER FIELD W/ LIMITED RANGE
CREATE FUNCTION events.evdef_addfld_int_range( _id TEXT , _opt BOOLEAN , _min INT , _max INT )
RETURNS events.evdef_create_result
LANGUAGE SQL
STRICT VOLATILE SECURITY DEFINER
AS $$ SELECT events.evdef_addfld_internal(
$1,$2,'NUMERIC'::events.field_type,NULL,TRUE,$3::NUMERIC,$4::NUMERIC); $$;
REVOKE EXECUTE
ON FUNCTION events.evdef_addfld_int_range( TEXT , BOOLEAN , INT , INT )
FROM PUBLIC;
GRANT EXECUTE
ON FUNCTION events.evdef_addfld_int_range( TEXT , BOOLEAN , INT , INT )
TO :dbuser;
-- REAL FIELD, NO BOUNDS
CREATE FUNCTION events.evdef_addfld_real( _id TEXT , _opt BOOLEAN )
RETURNS events.evdef_create_result
LANGUAGE SQL
STRICT VOLATILE SECURITY DEFINER
AS $$ SELECT events.evdef_addfld_internal(
$1,$2,'NUMERIC'::events.field_type,NULL,FALSE,NULL,NULL); $$;
REVOKE EXECUTE
ON FUNCTION events.evdef_addfld_real( TEXT , BOOLEAN )
FROM PUBLIC;
GRANT EXECUTE
ON FUNCTION events.evdef_addfld_real( TEXT , BOOLEAN )
TO :dbuser;
-- REAL FIELD W/ LOWER BOUND
CREATE FUNCTION events.evdef_addfld_real_min( _id TEXT , _opt BOOLEAN , _min DOUBLE PRECISION )
RETURNS events.evdef_create_result
LANGUAGE SQL
STRICT VOLATILE SECURITY DEFINER
AS $$ SELECT events.evdef_addfld_internal(
$1,$2,'NUMERIC'::events.field_type,NULL,FALSE,$3::NUMERIC,NULL); $$;
REVOKE EXECUTE
ON FUNCTION events.evdef_addfld_real_min( TEXT , BOOLEAN , DOUBLE PRECISION )
FROM PUBLIC;
GRANT EXECUTE
ON FUNCTION events.evdef_addfld_real_min( TEXT , BOOLEAN , DOUBLE PRECISION )
TO :dbuser;
-- REAL FIELD W/ HIGHER BOUND
CREATE FUNCTION events.evdef_addfld_real_max( _id TEXT , _opt BOOLEAN , _max DOUBLE PRECISION )
RETURNS events.evdef_create_result
LANGUAGE SQL
STRICT VOLATILE SECURITY DEFINER
AS $$ SELECT events.evdef_addfld_internal(
$1,$2,'NUMERIC'::events.field_type,NULL,FALSE,NULL,$3::NUMERIC); $$;
REVOKE EXECUTE
ON FUNCTION events.evdef_addfld_real_max( TEXT , BOOLEAN , DOUBLE PRECISION )
FROM PUBLIC;
GRANT EXECUTE
ON FUNCTION events.evdef_addfld_real_max( TEXT , BOOLEAN , DOUBLE PRECISION )
TO :dbuser;
-- REAL FIELD W/ LIMITED RANGE
CREATE FUNCTION events.evdef_addfld_real_range( _id TEXT , _opt BOOLEAN , _min DOUBLE PRECISION , _max DOUBLE PRECISION )
RETURNS events.evdef_create_result
LANGUAGE SQL
STRICT VOLATILE SECURITY DEFINER
AS $$ SELECT events.evdef_addfld_internal(
$1,$2,'NUMERIC'::events.field_type,NULL,FALSE,$3::NUMERIC,$4::NUMERIC); $$;
REVOKE EXECUTE
ON FUNCTION events.evdef_addfld_real_range( TEXT , BOOLEAN , DOUBLE PRECISION , DOUBLE PRECISION )
FROM PUBLIC;
GRANT EXECUTE
ON FUNCTION events.evdef_addfld_real_range( TEXT , BOOLEAN , DOUBLE PRECISION , DOUBLE PRECISION )
TO :dbuser;
-- TEXT FIELD, NO BOUNDS
CREATE FUNCTION events.evdef_addfld_text( _id TEXT , _opt BOOLEAN )
RETURNS events.evdef_create_result
LANGUAGE SQL
STRICT VOLATILE SECURITY DEFINER
AS $$ SELECT events.evdef_addfld_internal(
$1,$2,'TEXT'::events.field_type,NULL,NULL,NULL,NULL); $$;
REVOKE EXECUTE
ON FUNCTION events.evdef_addfld_text( TEXT , BOOLEAN )
FROM PUBLIC;
GRANT EXECUTE
ON FUNCTION events.evdef_addfld_text( TEXT , BOOLEAN )
TO :dbuser;
-- TEXT FIELD W/ LOWER BOUND
CREATE FUNCTION events.evdef_addfld_text_min( _id TEXT , _opt BOOLEAN , _min INT )
RETURNS events.evdef_create_result
LANGUAGE SQL
STRICT VOLATILE SECURITY DEFINER
AS $$ SELECT events.evdef_addfld_internal(
$1,$2,'TEXT'::events.field_type,NULL,NULL,$3::NUMERIC,NULL); $$;
REVOKE EXECUTE
ON FUNCTION events.evdef_addfld_text_min( TEXT , BOOLEAN , INT )
FROM PUBLIC;
GRANT EXECUTE
ON FUNCTION events.evdef_addfld_text_min( TEXT , BOOLEAN , INT )
TO :dbuser;
-- TEXT FIELD W/ HIGHER BOUND
CREATE FUNCTION events.evdef_addfld_text_max( _id TEXT , _opt BOOLEAN , _max INT )
RETURNS events.evdef_create_result
LANGUAGE SQL
STRICT VOLATILE SECURITY DEFINER
AS $$ SELECT events.evdef_addfld_internal(
$1,$2,'TEXT'::events.field_type,NULL,NULL,NULL,$3::NUMERIC); $$;
REVOKE EXECUTE
ON FUNCTION events.evdef_addfld_text_max( TEXT , BOOLEAN , INT )
FROM PUBLIC;
GRANT EXECUTE
ON FUNCTION events.evdef_addfld_text_max( TEXT , BOOLEAN , INT )
TO :dbuser;
-- TEXT FIELD W/ LIMITED RANGE
CREATE FUNCTION events.evdef_addfld_text_range( _id TEXT , _opt BOOLEAN , _min INT , _max INT )
RETURNS events.evdef_create_result
LANGUAGE SQL
STRICT VOLATILE SECURITY DEFINER
AS $$ SELECT events.evdef_addfld_internal(
$1,$2,'TEXT'::events.field_type,NULL,NULL,$3::NUMERIC,$4::NUMERIC); $$;
REVOKE EXECUTE
ON FUNCTION events.evdef_addfld_text_range( TEXT , BOOLEAN , INT , INT )
FROM PUBLIC;
GRANT EXECUTE
ON FUNCTION events.evdef_addfld_text_range( TEXT , BOOLEAN , INT , INT )
TO :dbuser;
-- BOOLEAN FIELD
CREATE FUNCTION events.evdef_addfld_bool( _id TEXT , _opt BOOLEAN )
RETURNS events.evdef_create_result
LANGUAGE SQL
STRICT VOLATILE SECURITY DEFINER
AS $$ SELECT events.evdef_addfld_internal(
$1,$2,'BOOL'::events.field_type,NULL,NULL,NULL,NULL); $$;
REVOKE EXECUTE
ON FUNCTION events.evdef_addfld_bool( TEXT , BOOLEAN )
FROM PUBLIC;
GRANT EXECUTE
ON FUNCTION events.evdef_addfld_bool( TEXT , BOOLEAN )
TO :dbuser;
-- I18N TEXT FIELD
CREATE FUNCTION events.evdef_addfld_i18n( _id TEXT , _opt BOOLEAN )
RETURNS events.evdef_create_result
LANGUAGE SQL
STRICT VOLATILE SECURITY DEFINER
AS $$ SELECT events.evdef_addfld_internal(
$1,$2,'I18N'::events.field_type,NULL,NULL,NULL,NULL); $$;
REVOKE EXECUTE
ON FUNCTION events.evdef_addfld_i18n( TEXT , BOOLEAN )
FROM PUBLIC;
GRANT EXECUTE
ON FUNCTION events.evdef_addfld_i18n( TEXT , BOOLEAN )
TO :dbuser;
-- ENTITY LINK FIELD
CREATE FUNCTION events.evdef_addfld_entity( _id TEXT , _opt BOOLEAN , _etype events.entity_field_type )
RETURNS events.evdef_create_result
LANGUAGE SQL
STRICT VOLATILE SECURITY DEFINER
AS $$ SELECT events.evdef_addfld_internal(
$1,$2,'ENTITY'::events.field_type,$3,NULL,NULL,NULL); $$;
REVOKE EXECUTE
ON FUNCTION events.evdef_addfld_entity( TEXT , BOOLEAN , events.entity_field_type )
FROM PUBLIC;
GRANT EXECUTE
ON FUNCTION events.evdef_addfld_entity( TEXT , BOOLEAN , events.entity_field_type )
TO :dbuser;
/*
* Create an event definition record
* ---------------------------------
*
* /!\ INTERNAL FUNCTION /!\
*
* This function inserts the record for an event definition into the
* appropriate table.
*
* Returns:
* ??? An error code
*/
DROP FUNCTION IF EXISTS events.evdef_create_record( );
CREATE FUNCTION events.evdef_create_record( )
RETURNS events.evdef_create_result
LANGUAGE PLPGSQL
STRICT VOLATILE SECURITY INVOKER
AS $evdef_create_record$
DECLARE
_rec RECORD;
_qstr TEXT;
BEGIN
SELECT INTO _rec *
FROM evdef_temp
WHERE evfld_id IS NULL;
_qstr := 'INSERT INTO events.event_definitions (' ||
'evdef_id , evdef_priority , evdef_adjustable' ||
') VALUES ( $1 , ' || _rec.evfld_typespec || ');';
BEGIN
EXECUTE _qstr USING _rec.evdef_id;
EXCEPTION
WHEN unique_violation THEN
RETURN 'DUPLICATE';
WHEN check_violation THEN
RETURN 'BAD_SPEC';
END;
RETURN 'OK';
END;
$evdef_create_record$;
REVOKE EXECUTE
ON FUNCTION events.evdef_create_record( )
FROM PUBLIC;
/*
* Create an event field definition record
* ---------------------------------------
*
* /!\ INTERNAL FUNCTION /!\
*
* This function inserts a new event field definition record into the
* appropriate table.
*
* Parameters:
* _evdef_id The event definition's identifier
* _efdef_id The field's identifier
* _typespec The type specification from the temporary table
*
* Returns:
* ??? An error code
*/
DROP FUNCTION IF EXISTS events.evdef_create_field_record(
TEXT , TEXT , TEXT );
CREATE FUNCTION events.evdef_create_field_record(
_evdef_id TEXT ,
_efdef_id TEXT ,
_typespec TEXT )
RETURNS events.evdef_create_result
LANGUAGE PLPGSQL
STRICT VOLATILE SECURITY INVOKER
AS $evdef_create_field_record$
DECLARE
_qstr TEXT;
BEGIN
_qstr := 'INSERT INTO events.field_definitions (' ||
'evdef_id , efdef_id , efdef_optional , efdef_type , ' ||
'efdef_entity , efdef_integer , efdef_min , efdef_max ' ||
') VALUES ( $1 , $2 , ' || _typespec || ');';
BEGIN
EXECUTE _qstr USING _evdef_id , _efdef_id;
EXCEPTION
WHEN unique_violation THEN
RETURN 'DUPLICATE';
WHEN check_violation THEN
RETURN 'BAD_SPEC';
END;
RETURN 'OK';
END;
$evdef_create_field_record$;
REVOKE EXECUTE
ON FUNCTION events.evdef_create_field_record( TEXT , TEXT , TEXT )
FROM PUBLIC;
/*
* Generate the DDL for a numeric field
* ------------------------------------
*
* /!\ INTERNAL FUNCTION /!\
*
* This function generates the DDL for a numeric event field in an event queue
* table.
*
* Parameters:
* _fname The field's table name
* _opt Whether the field is optional
* _is_int Whether the field is an integer
* _min Minimal value of the field (may be NULL)
* _max Maximal value of the field (may be NULL)
*
* Returns:
* ??? The field's DDL
*/
DROP FUNCTION IF EXISTS events.efdef_ddl_numeric(
TEXT , BOOLEAN , BOOLEAN , NUMERIC , NUMERIC );
CREATE FUNCTION events.efdef_ddl_numeric(
_fname TEXT ,
_opt BOOLEAN ,
_is_int BOOLEAN ,
_min NUMERIC ,
_max NUMERIC )
RETURNS TEXT
LANGUAGE SQL
IMMUTABLE SECURITY INVOKER
CALLED ON NULL INPUT
AS $efdef_ddl_numeric$
SELECT ',' || $1 || ' '
|| ( CASE WHEN $3 THEN 'BIGINT' ELSE 'DOUBLE PRECISION' END )
|| ( CASE WHEN $2 THEN '' ELSE ' NOT NULL' END )
|| ( CASE
WHEN $4 IS NULL AND $5 IS NULL
THEN ''
ELSE
' CHECK(' || $1 || ( CASE
WHEN $5 IS NULL
THEN '>=' || $4::TEXT
WHEN $4 IS NULL
THEN '<=' || $5::TEXT
ELSE
' BETWEEN ' || $4::TEXT || ' AND ' || $5::TEXT
END ) || ')'
END );
$efdef_ddl_numeric$;
REVOKE EXECUTE
ON FUNCTION events.efdef_ddl_numeric(
TEXT , BOOLEAN , BOOLEAN , NUMERIC , NUMERIC )
FROM PUBLIC;
/*
* Generate the DDL for a text field
* ---------------------------------
*
* /!\ INTERNAL FUNCTION /!\
*
* This function generates the DDL for a text event field in an event queue
* table.
*
* Parameters:
* _fname The field's table name
* _opt Whether the field is optional
* _min Minimal length of the field (may be NULL)
* _max Maximal length of the field (may be NULL)
*
* Returns:
* ??? The field's DDL
*/
DROP FUNCTION IF EXISTS events.efdef_ddl_text(
TEXT , BOOLEAN , NUMERIC , NUMERIC );
CREATE FUNCTION events.efdef_ddl_text(
_fname TEXT ,
_opt BOOLEAN ,
_min NUMERIC ,
_max NUMERIC )
RETURNS TEXT
LANGUAGE SQL
IMMUTABLE SECURITY INVOKER
CALLED ON NULL INPUT
AS $efdef_ddl_text$
SELECT ',' || $1 || ' '
|| ( CASE WHEN $4 IS NULL THEN 'TEXT' ELSE 'VARCHAR(' || $4::TEXT || ')' END )
|| ( CASE WHEN $2 THEN '' ELSE ' NOT NULL' END )
|| ( CASE
WHEN $3 IS NULL
THEN ''
ELSE
' CHECK(LENGTH(' || $1 || ')>=' || $3::TEXT || ')'
END );
$efdef_ddl_text$;
REVOKE EXECUTE
ON FUNCTION events.efdef_ddl_text(
TEXT , BOOLEAN , NUMERIC , NUMERIC )
FROM PUBLIC;
/*
* Generate the DDL for an entity field
* ------------------------------------
*
* /!\ INTERNAL FUNCTION /!\
*
* This function generates the DDL for an entity event field in an event queue
* table.
*
* Parameters:
* _fname The field's table name
* _opt Whether the field is optional
* _etype Type of entity to reference
*
* Returns:
* ??? The field's DDL
*/
DROP FUNCTION IF EXISTS events.efdef_ddl_entity(
TEXT , BOOLEAN , events.entity_field_type );
CREATE FUNCTION events.efdef_ddl_entity(
_fname TEXT ,
_opt BOOLEAN ,
_etype events.entity_field_type )
RETURNS TEXT
LANGUAGE SQL
STRICT IMMUTABLE SECURITY INVOKER
AS $efdef_ddl_entity$
SELECT ',' || $1 || ' '
|| ( CASE
WHEN $3 IN ( 'EMP' , 'PLN', 'ALL' , 'ADM' ) THEN 'INT'
ELSE 'BIGINT'
END ) || ( CASE WHEN $2 THEN ' NOT NULL' ELSE '' END )
|| ' REFERENCES ' || ( CASE $3
WHEN 'EMP' THEN 'emp.empires(name_id)'
WHEN 'PLN' THEN 'verse.planets(name_id)'
WHEN 'FLT' THEN 'fleets.fleets(id)'
WHEN 'ALL' THEN 'emp.alliances(id)'
WHEN 'BAT' THEN 'battles.battles(id)'
WHEN 'ADM' THEN 'admin.administrators(id)'
WHEN 'BUG' THEN 'bugs.initial_report_events(event_id)'
END ) || ' ON DELETE CASCADE';
$efdef_ddl_entity$;
REVOKE EXECUTE
ON FUNCTION events.efdef_ddl_entity(
TEXT , BOOLEAN , events.entity_field_type )
FROM PUBLIC;
/*
* Create the event queuing table for a new definition
* ---------------------------------------------------
*
* /!\ INTERNAL FUNCTION /!\
*
* This function generates the event queuing table from the list of fields
* that compose an event definition. The queuing table's name will always be
* "events.evq_<type identifier>"; it will contain an event identifier
* generated from the event ID sequence (events.event_id_sequence), an empire
* identifier, a timestamp, the tick identifier, and rows corresponding to the
* event definition's fields.
*
* Parameters:
* _evdef_id The event definition's identifier
*/
DROP FUNCTION IF EXISTS events.evdef_create_queue_table( TEXT );
CREATE FUNCTION _temp_init_func(_user TEXT) RETURNS VOID LANGUAGE PLPGSQL AS $init_func$
BEGIN EXECUTE $init_code$
CREATE FUNCTION events.evdef_create_queue_table( _evdef_id TEXT )
RETURNS VOID
LANGUAGE PLPGSQL
STRICT VOLATILE SECURITY INVOKER
AS $evdef_create_queue_table$
DECLARE
_rec RECORD;
_qstr TEXT;
_fname TEXT;
BEGIN
_qstr := 'CREATE TABLE events.eq_' || replace( _evdef_id , '-' , '_' )
|| $tbl_def$ (
event_id BIGINT NOT NULL PRIMARY KEY
DEFAULT nextval('events.event_id_sequence'::regclass) ,
event_rtime TIMESTAMP WITHOUT TIME ZONE NOT NULL
DEFAULT now( ) ,
event_gtime BIGINT NOT NULL ,
empire_id INT NOT NULL REFERENCES emp.empires ( name_id )
ON DELETE CASCADE
$tbl_def$;
FOR _rec IN SELECT *
FROM events.field_definitions
WHERE evdef_id = _evdef_id
LOOP
_fname := 'ef_' || replace( _rec.efdef_id , '-' , '_' );
_qstr := _qstr || ( CASE _rec.efdef_type
WHEN 'NUMERIC' THEN
events.efdef_ddl_numeric( _fname , _rec.efdef_optional ,
_rec.efdef_integer , _rec.efdef_min , _rec.efdef_max )
WHEN 'TEXT' THEN
events.efdef_ddl_text( _fname , _rec.efdef_optional ,
_rec.efdef_min , _rec.efdef_max )
WHEN 'BOOL' THEN
',' || _fname || ' BOOLEAN' || ( CASE
WHEN NOT _rec.efdef_optional THEN ' NOT NULL'
ELSE ''
END )
WHEN 'I18N' THEN
',' || _fname || ' VARCHAR(64)' || ( CASE
WHEN NOT _rec.efdef_optional THEN ' NOT NULL'
ELSE ''
END ) || ' REFERENCES defs.strings(name)'
WHEN 'ENTITY' THEN
events.efdef_ddl_entity( _fname , _rec.efdef_optional ,
_rec.efdef_entity )
END );
END LOOP;
_qstr := _qstr || ');';
EXECUTE _qstr;
_qstr := 'GRANT INSERT ON TABLE events.eq_' || replace( _evdef_id , '-' , '_' )
|| ' TO $init_code$ || $1 || $init_code$;';
EXECUTE _qstr;
END;
$evdef_create_queue_table$; $init_code$ USING $1; END; $init_func$;
SELECT _temp_init_func(:dbuser_string);
DROP FUNCTION _temp_init_func(TEXT);
REVOKE EXECUTE
ON FUNCTION events.evdef_create_queue_table( TEXT )
FROM PUBLIC;
/*
* Validate and finalise an event definition
* -----------------------------------------
*
* This function inserts the contents of the temporary event definition table
* into the main table. If everything goes well, the event queuing table is
* created and the temporary table is destroyed.
*
* Returns:
* _error An error code (see events.evdef_create_result)
* _fld The name of the field which caused the error, or NULL
* if the error was table-related or if there was no
* error.
*/
DROP FUNCTION IF EXISTS events.evdef_finalise( );
CREATE FUNCTION events.evdef_finalise(
OUT _error events.evdef_create_result ,
OUT _fld TEXT )
LANGUAGE PLPGSQL
STRICT VOLATILE SECURITY DEFINER
AS $evdef_finalise$
DECLARE
_eid TEXT;
_rec RECORD;
BEGIN
-- First create the event definition record
_fld := NULL;
_error := events.evdef_create_record( );
IF _error = 'OK'
THEN
-- Then create records for all fields
FOR _rec IN SELECT * FROM evdef_temp WHERE evfld_id IS NOT NULL
LOOP
_error := events.evdef_create_field_record(
_rec.evdef_id , _rec.evfld_id , _rec.evfld_typespec );
IF _error <> 'OK'
THEN
-- Destroy the definition record on failure
_fld := _rec.evfld_id;
DELETE FROM events.event_definitions
WHERE evdef_id = _rec.evdef_id;
EXIT;
END IF;
END LOOP;
END IF;
-- If everything went well so far, create the queueing table
IF _error = 'OK'
THEN
SELECT INTO _eid evdef_id FROM evdef_temp LIMIT 1;
PERFORM events.evdef_create_queue_table( _eid );
END IF;
DROP TABLE evdef_temp;
END;
$evdef_finalise$;
REVOKE EXECUTE
ON FUNCTION events.evdef_finalise( )
FROM PUBLIC;
GRANT EXECUTE
ON FUNCTION events.evdef_finalise( )
TO :dbuser;
/*
* OLD B6M1 CODE BELOW!
*/
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- 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 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.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;