Resource database structures
* Added structures for resource definitions, natural resources definitions, resource providers, empire resources and empire mining settings (both empire-wide and planet-specific). * Added a few common utility functions to the SQL test suite. These functions allow test initialisation to be a little shorter. * Added "MINE" production type and an associated building definition. The production will not be added to the XML dump or to the output of the planets summary page, as this is extremely temporary.
This commit is contained in:
parent
631f49fb86
commit
4e1bb91780
20 changed files with 2223 additions and 2 deletions
legacyworlds-server-data/db-structure/tests/utils
|
@ -0,0 +1,68 @@
|
|||
/*
|
||||
* Utility functions used by unit tests
|
||||
*
|
||||
* User accounts
|
||||
*/
|
||||
|
||||
|
||||
/*
|
||||
* Find a test address
|
||||
*/
|
||||
CREATE FUNCTION _find_address( TEXT ) RETURNS INT AS $$
|
||||
SELECT id FROM users.addresses WHERE address = $1 || '@example.org';
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
/*
|
||||
* Create a set of user addresses using some prefix
|
||||
*/
|
||||
CREATE FUNCTION _create_addresses( _quantity INT , _prefix TEXT )
|
||||
RETURNS VOID
|
||||
AS $$
|
||||
DECLARE
|
||||
i INT;
|
||||
BEGIN
|
||||
i := 0;
|
||||
WHILE i < _quantity
|
||||
LOOP
|
||||
i := i + 1;
|
||||
BEGIN
|
||||
INSERT INTO users.addresses ( address )
|
||||
VALUES ( _prefix || i::TEXT || '@example.org' );
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
-- Address already exists, that's nice
|
||||
END;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
/*
|
||||
* Create a set of user accounts
|
||||
*/
|
||||
CREATE FUNCTION _create_accounts( _quantity INT , _prefix TEXT )
|
||||
RETURNS VOID
|
||||
AS $$
|
||||
DECLARE
|
||||
i INT;
|
||||
BEGIN
|
||||
PERFORM _create_test_strings( 0 );
|
||||
PERFORM _create_addresses( _quantity , _prefix );
|
||||
i := 0;
|
||||
WHILE i < _quantity
|
||||
LOOP
|
||||
i := i + 1;
|
||||
BEGIN
|
||||
INSERT INTO users.credentials (
|
||||
address_id , pass_md5 , pass_sha1 , language_id , credits
|
||||
) VALUES (
|
||||
_find_address( _prefix || i::TEXT ) , '' , '' , _get_language( 't' ) , 0
|
||||
);
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
-- Account already exists
|
||||
END;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
93
legacyworlds-server-data/db-structure/tests/utils/naming.sql
Normal file
93
legacyworlds-server-data/db-structure/tests/utils/naming.sql
Normal file
|
@ -0,0 +1,93 @@
|
|||
/*
|
||||
* Utility functions used by unit tests
|
||||
*
|
||||
* Naming system
|
||||
*/
|
||||
|
||||
|
||||
/*
|
||||
* Obtain a map name identifier
|
||||
*/
|
||||
CREATE FUNCTION _get_map_name( TEXT ) RETURNS INT AS $$
|
||||
SELECT id FROM naming.map_names WHERE name = $1;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
/*
|
||||
* Obtain a map name identifier that does not exist
|
||||
*/
|
||||
CREATE FUNCTION _get_bad_map_name( ) RETURNS INT AS $$
|
||||
SELECT MAX( id ) + 1 FROM naming.map_names;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
/*
|
||||
* Create a few map names using a prefix
|
||||
*/
|
||||
CREATE FUNCTION _create_map_names( _quantity INT , _prefix TEXT )
|
||||
RETURNS VOID
|
||||
AS $$
|
||||
DECLARE
|
||||
i INT;
|
||||
BEGIN
|
||||
i := 0;
|
||||
WHILE i < _quantity
|
||||
LOOP
|
||||
i := i + 1;
|
||||
BEGIN
|
||||
INSERT INTO naming.map_names (name) VALUES ( _prefix || i::TEXT );
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
-- Ignore the error
|
||||
END;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE PLPGSQL;
|
||||
|
||||
|
||||
/*
|
||||
* Get the empire that belongs to some user, based on that user's email
|
||||
*/
|
||||
CREATE FUNCTION _get_emp_name( TEXT ) RETURNS INT AS $$
|
||||
SELECT id FROM naming.empire_names WHERE owner_id = _find_address( $1 );
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
/*
|
||||
* Obtain a map name identifier that does not exist
|
||||
*/
|
||||
CREATE FUNCTION _get_bad_emp_name( ) RETURNS INT AS $$
|
||||
SELECT MAX( id ) + 1 FROM naming.empire_names;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
/*
|
||||
* Create a few empire names using a prefix for user accounts.
|
||||
* Empires are named "testX" independently of the user accounts.
|
||||
*/
|
||||
CREATE FUNCTION _create_emp_names( _quantity INT , _prefix TEXT )
|
||||
RETURNS VOID
|
||||
AS $$
|
||||
DECLARE
|
||||
i INT;
|
||||
j INT;
|
||||
BEGIN
|
||||
PERFORM _create_accounts( _quantity , _prefix );
|
||||
i := 0;
|
||||
WHILE i < _quantity
|
||||
LOOP
|
||||
i := i + 1;
|
||||
j := 0;
|
||||
LOOP
|
||||
BEGIN
|
||||
INSERT INTO naming.empire_names ( owner_id , name )
|
||||
VALUES ( _find_address( _prefix || i::TEXT ) , 'test' || j::TEXT );
|
||||
EXIT;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
j := j + 1;
|
||||
END;
|
||||
END LOOP;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE PLPGSQL;
|
|
@ -0,0 +1,63 @@
|
|||
/*
|
||||
* Utility functions used by unit tests
|
||||
*
|
||||
* Resources and natural resources
|
||||
*/
|
||||
|
||||
|
||||
/*
|
||||
* Function that creates some quantity of resources
|
||||
* All resources are created using the specified prefix for the strings
|
||||
*/
|
||||
CREATE FUNCTION _create_resources( _quantity INT , _prefix TEXT )
|
||||
RETURNS VOID
|
||||
AS $$
|
||||
DECLARE
|
||||
i INT;
|
||||
BEGIN
|
||||
PERFORM _create_test_strings( _quantity , _prefix );
|
||||
PERFORM _create_test_strings( _quantity , _prefix || 'Description' );
|
||||
|
||||
i := 0;
|
||||
WHILE i < _quantity
|
||||
LOOP
|
||||
i := i + 1;
|
||||
INSERT INTO defs.resources (
|
||||
resource_name_id , resource_description_id , resource_weight
|
||||
) VALUES (
|
||||
_get_string( _prefix || i::TEXT ) ,
|
||||
_get_string( _prefix || 'Description' || i::TEXT ) ,
|
||||
i
|
||||
);
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE PLPGSQL;
|
||||
|
||||
|
||||
/*
|
||||
* Function that creates some quantity of /natural/ resources
|
||||
* All resources are created using the specified prefix for the strings
|
||||
*/
|
||||
CREATE FUNCTION _create_natural_resources( _quantity INT , _prefix TEXT )
|
||||
RETURNS VOID
|
||||
AS $$
|
||||
DECLARE
|
||||
i INT;
|
||||
BEGIN
|
||||
PERFORM _create_resources( _quantity , _prefix );
|
||||
|
||||
i := 0;
|
||||
WHILE i < _quantity
|
||||
LOOP
|
||||
i := i + 1;
|
||||
INSERT INTO defs.natural_resources(
|
||||
resource_name_id , natres_p_presence , natres_quantity_avg ,
|
||||
natres_quantity_dev , natres_difficulty_avg ,
|
||||
natres_difficulty_dev , natres_recovery_avg ,
|
||||
natres_recovery_dev
|
||||
) VALUES (
|
||||
_get_string( _prefix || i::TEXT ) , 0.5 , 100 , 1 , 0.5 , 0.05 , 0.5 , 0.05
|
||||
);
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE PLPGSQL;
|
|
@ -0,0 +1,65 @@
|
|||
/*
|
||||
* Utility functions used by unit tests
|
||||
*
|
||||
* I18N string creation and access
|
||||
*/
|
||||
|
||||
|
||||
/*
|
||||
* Function that returns an invalid string identifier.
|
||||
*/
|
||||
CREATE FUNCTION _get_bad_string( ) RETURNS INT AS $$
|
||||
SELECT MAX( id ) + 1 FROM defs.strings;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
/*
|
||||
* Function that returns a language's identifier
|
||||
*/
|
||||
CREATE FUNCTION _get_language( TEXT ) RETURNS INT AS $$
|
||||
SELECT id FROM defs.languages WHERE language = $1;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
/*
|
||||
* Function that returns a string's identifier
|
||||
*/
|
||||
CREATE FUNCTION _get_string( TEXT ) RETURNS INT AS $$
|
||||
SELECT id FROM defs.strings WHERE name = $1;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
/*
|
||||
* Function that creates some quantity of test strings
|
||||
*/
|
||||
CREATE FUNCTION _create_test_strings( _quantity INT )
|
||||
RETURNS VOID
|
||||
AS $$
|
||||
DECLARE
|
||||
i INT;
|
||||
BEGIN
|
||||
PERFORM _create_test_strings( _quantity , 'test' );
|
||||
END;
|
||||
$$ LANGUAGE PLPGSQL;
|
||||
|
||||
|
||||
/*
|
||||
* Function that creates some quantity of test strings using a specific prefix
|
||||
*/
|
||||
CREATE FUNCTION _create_test_strings( _quantity INT , _prefix TEXT )
|
||||
RETURNS VOID
|
||||
AS $$
|
||||
DECLARE
|
||||
i INT;
|
||||
BEGIN
|
||||
PERFORM defs.uoc_language( 't' , 'Test' );
|
||||
|
||||
i := 0;
|
||||
WHILE i < _quantity
|
||||
LOOP
|
||||
i := i + 1;
|
||||
PERFORM defs.uoc_translation( 't' , _prefix || i::TEXT ,
|
||||
'Test string #' || i::TEXT );
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE PLPGSQL;
|
|
@ -0,0 +1,71 @@
|
|||
/*
|
||||
* Utility functions used by unit tests
|
||||
*
|
||||
* Universe
|
||||
*/
|
||||
|
||||
/*
|
||||
* Create a new system at some coordinates and return its identifier
|
||||
*/
|
||||
CREATE FUNCTION _create_system( INT , INT ) RETURNS INT AS $$
|
||||
INSERT INTO verse.systems ( x , y )
|
||||
VALUES ( $1 , $2 )
|
||||
RETURNING id;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
/*
|
||||
* Create "raw" planets
|
||||
*/
|
||||
CREATE FUNCTION _create_raw_planets( _quantity INT , _prefix TEXT )
|
||||
RETURNS VOID
|
||||
AS $$
|
||||
DECLARE
|
||||
_system INT;
|
||||
_orbit INT;
|
||||
i INT;
|
||||
BEGIN
|
||||
PERFORM _create_map_names( _quantity , _prefix );
|
||||
|
||||
i := 0;
|
||||
WHILE i < _quantity
|
||||
LOOP
|
||||
i := i + 1;
|
||||
|
||||
IF _system IS NULL
|
||||
THEN
|
||||
_system := _create_system( i , i );
|
||||
_orbit := 1;
|
||||
END IF;
|
||||
|
||||
INSERT INTO verse.planets(
|
||||
name_id , system_id , orbit , picture , population
|
||||
) VALUES (
|
||||
_get_map_name( _prefix || i::TEXT ) , _system , _orbit , 1 , 1
|
||||
);
|
||||
|
||||
IF _orbit = 5
|
||||
THEN
|
||||
_system := NULL;
|
||||
ELSE
|
||||
_orbit := _orbit + 1;
|
||||
END IF;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE PLPGSQL;
|
||||
|
||||
|
||||
/*
|
||||
* Create a resource provider
|
||||
*/
|
||||
CREATE FUNCTION _create_resource_provider( TEXT , TEXT ) RETURNS VOID AS $$
|
||||
INSERT INTO verse.resource_providers(
|
||||
planet_id , resource_name_id ,
|
||||
resprov_quantity_max , resprov_quantity ,
|
||||
resprov_difficulty , resprov_recovery
|
||||
) VALUES (
|
||||
_get_map_name( $1 ) , _get_string( $2 ) ,
|
||||
100 , 50 ,
|
||||
0.5 , 0.5
|
||||
);
|
||||
$$ LANGUAGE SQL;
|
Reference in a new issue