In-game resources views

* Added session records to carry resource information over to the
clients

* Added SQL support code for the various views

* Added interface and implementation of the resource information access
component

* Hooked resources information queries into both the empire and planet
management component

* Added resources display to planet and overview pages
This commit is contained in:
Emmanuel BENOîT 2012-02-04 10:43:12 +01:00
parent 56eddcc4f0
commit 597429fadf
45 changed files with 3211 additions and 52 deletions

View file

@ -505,3 +505,59 @@ GRANT EXECUTE
DOUBLE PRECISION , DOUBLE PRECISION , DOUBLE PRECISION ,
DOUBLE PRECISION )
TO :dbuser;
/*
* View of resource category weights
*
* This view computes the average resource weight per category for all
* resource definitions.
*
* Fields:
* resource_category_id The category's identifier
* resource_category_weight The average weight of resource defintions
* in the category.
*/
DROP VIEW IF EXISTS defs.resource_category_weight_view CASCADE;
CREATE VIEW defs.resource_category_weight_view
AS SELECT resource_category_id ,
AVG( resource_weight ) AS resource_category_weight
FROM defs.resources
WHERE resource_category_id IS NOT NULL
GROUP BY resource_category_id;
/*
* Ordered resource definitions
*
* This view contains the name, category and description identifier for all
* resource definitions, ordered based on the category's average weight and
* the resource's own weight.
*
* Fields:
* resource_name_id The identifier of the resource's name
* resource_category_id The identifier of the category's name, or NULL
* if the resource is not in a category
* resource_description_id The identifier of the resource's description
* resource_ordering The index of the resource in a sorted view
*/
DROP VIEW IF EXISTS defs.ordered_resources_view CASCADE;
CREATE VIEW defs.ordered_resources_view
AS SELECT resource_name_id , resource_category_id , resource_description_id ,
row_number( ) OVER(
ORDER BY (
CASE
WHEN resource_category_id IS NULL THEN
resource_weight
ELSE
resource_category_weight
END ) , resource_weight
) AS resource_ordering
FROM defs.resources
LEFT OUTER JOIN defs.resource_category_weight_view
USING ( resource_category_id )
;

View file

@ -668,4 +668,112 @@ CREATE VIEW emp.enemy_lists
INNER JOIN emp.alliances a ON a.id = el.alliance_id
) AS x;
GRANT SELECT ON emp.enemy_lists TO :dbuser;
GRANT SELECT ON emp.enemy_lists TO :dbuser;
/*
* Planets income and upkeep totals
*
* This view computes the totals of planets' incomes and upkeeps for each
* empire and resource type.
*
* FIXME: time-related factor is hardcoded
*
* Fields:
* empire_id The empire's identifier
* resource_name_id The identifier of the resource type
* planets_income The planets' income over 12h RT / 1 month GT,
* rounded down
* planets_upkeep The planets' upkeep over 12h RT / 1 month GT,
* rounded up
*/
DROP VIEW IF EXISTS emp.planet_resources_view CASCADE;
CREATE VIEW emp.planet_resources_view
AS SELECT
empire_id , resource_name_id ,
FLOOR( SUM( pres_income ) * 720.0 )::BIGINT AS planets_income ,
CEIL( SUM( pres_upkeep ) * 720.0 )::BIGINT AS planets_upkeep
FROM emp.planets
LEFT OUTER JOIN verse.planet_resources
USING ( planet_id )
GROUP BY empire_id , resource_name_id;
/*
* Empire resources view
*
* This view contains all resource-related information for each empire and
* resource type.
*
* FIXME: fleets upkeep is set to 0 at the moment.
*
* Fields:
* empire_id The empire's identifier
* resource_identifier The text identifier of the resource
* resource_name The internationalised name of the resource
* resource_description The internationalised description of the
* resource
* resource_category The internationalised category of the resource,
* or NULL if the resource is not in a
* category.
* empres_possessed The empire's stockpile of this type of
* resource, rounded down
* empmset_weight The empire-wide mining setting for the
* resource type, or NULL if this is a basic
* resource
* planets_income The planets' total income
* planets_upkeep The planets' total upkeep
* fleets_upkeep The fleets' total upkeep
*/
DROP VIEW IF EXISTS emp.resources_view CASCADE;
CREATE VIEW emp.resources_view
AS SELECT
empire_id ,
_r_name_str.name AS resource_identifier ,
_r_name.translated_string AS resource_name ,
_r_desc.translated_string AS resource_description ,
_r_cat.translated_string AS resource_category ,
FLOOR( empres_possessed )::BIGINT AS empres_possessed ,
empmset_weight ,
( CASE
WHEN planets_income IS NULL THEN
0::BIGINT
ELSE
planets_income
END ) AS planets_income ,
( CASE
WHEN planets_upkeep IS NULL THEN
0::BIGINT
ELSE
planets_upkeep
END ) AS planets_upkeep ,
0::BIGINT AS fleets_upkeep
FROM defs.ordered_resources_view
INNER JOIN emp.resources
USING ( resource_name_id )
INNER JOIN naming.empire_names _name
ON _name.id = empire_id
INNER JOIN users.credentials _creds
ON _creds.address_id = _name.owner_id
INNER JOIN defs.strings _r_name_str
ON _r_name_str.id = resource_name_id
INNER JOIN defs.translations _r_name
ON _r_name.string_id = resource_name_id
AND _r_name.lang_id = _creds.language_id
INNER JOIN defs.translations _r_desc
ON _r_desc.string_id = resource_description_id
AND _r_desc.lang_id = _creds.language_id
LEFT OUTER JOIN defs.translations _r_cat
ON _r_cat.string_id = resource_category_id
AND _r_cat.lang_id = _creds.language_id
LEFT OUTER JOIN emp.mining_settings
USING ( empire_id , resource_name_id )
LEFT OUTER JOIN emp.planet_resources_view
USING ( empire_id , resource_name_id )
ORDER BY resource_ordering;
GRANT SELECT
ON emp.resources_view
TO :dbuser;

View file

@ -139,3 +139,139 @@ REVOKE EXECUTE
DOUBLE PRECISION , DOUBLE PRECISION )
FROM PUBLIC;
/*
* Planet resources type
*
* This type is used to transmit a planet's resources information to the game
* server. It contains the resource's description, the planet's economic data
* and, if there is a resource provider on the planet, the provider's
* information and mining priority.
*/
DROP TYPE IF EXISTS emp.planet_resources_type CASCADE;
CREATE TYPE emp.planet_resources_type AS (
/* Text identifier of the resource */
resource_identifier TEXT ,
/* Internationalised name of the resource */
resource_name TEXT ,
/* Internationalised description of the resource */
resource_description TEXT ,
/* Internationalised name of the category the resource is a part of, or
* NULL if the resource is not in any category.
*/
resource_category TEXT ,
/* The planet's income for this resource, over a period of 12h RT/ 1 month
* GT.
*/
pres_income BIGINT ,
/* The planet's upkeep for this resource, over a period of 12h RT/ 1 month
* GT.
*/
pres_upkeep BIGINT ,
/* The current quantity of this resource invested in the planet's build
* queues.
*/
pres_invested BIGINT ,
/** The capacity of the resource provider, if there is one, or NULL if
* there is no provider.
*/
resprov_capacity BIGINT ,
/** The quantity of resources in the resource provider, if there is one,
* or NULL if there is no provider.
*/
resprov_quantity BIGINT ,
/** The extraction difficulty of the resource provider as a percentage, or
* NULL if there is no provider.
*/
resprov_difficulty INT ,
/* The mining priority for the resource in question, or NULL if there is no
* resource provider.
*/
mset_weight INT
);
/*
* Access all available information about a planet's resources
*
* This function retrieves resource information about an empire-owned planet,
* and converts it to the format used in the game server (rounded quantities,
* difficulty as percentage, internationalised strings).
*
* FIXME:
* 1) pres_invested is always set to 0 in the output
* 2) time-related computations use hardcoded values
*
* Parameters:
* _planet The planet's identifier
*
* Returns:
* N/A Resource information records, ordered using resource
* weights.
*/
DROP FUNCTION IF EXISTS emp.get_planet_resources( INT );
CREATE FUNCTION emp.get_planet_resources( _planet INT )
RETURNS SETOF emp.planet_resources_type
STRICT STABLE
SECURITY DEFINER
AS $get_planet_resources$
SELECT _name_str.name AS resource_identifier ,
_name_trans.translated_string AS resource_name ,
_desc_trans.translated_string AS resource_description ,
_cat_trans.translated_string AS resource_category ,
FLOOR( pres_income * 720.0 )::BIGINT AS pres_income ,
CEIL( pres_upkeep * 720.0 )::BIGINT AS pres_upkeep ,
0::BIGINT AS pres_invested ,
ROUND( resprov_quantity_max )::BIGINT AS resprov_capacity ,
ROUND( resprov_quantity )::BIGINT AS resprov_quantity ,
ROUND( 100.0 * resprov_difficulty )::INT AS resprov_difficulty ,
mset_weight
FROM defs.ordered_resources_view
INNER JOIN verse.planet_resources USING ( resource_name_id )
INNER JOIN emp.planets USING ( planet_id )
INNER JOIN naming.empire_names _emp_name
ON _emp_name.id = empire_id
INNER JOIN users.credentials _user
ON _emp_name.owner_id = _user.address_id
INNER JOIN defs.strings _name_str
ON _name_str.id = resource_name_id
INNER JOIN defs.translations _name_trans
ON _name_trans.string_id = resource_name_id
AND _name_trans.lang_id = _user.language_id
INNER JOIN defs.translations _desc_trans
ON _desc_trans.string_id = resource_description_id
AND _desc_trans.lang_id = _user.language_id
LEFT OUTER JOIN defs.translations _cat_trans
ON _cat_trans.string_id = resource_category_id
AND _cat_trans.lang_id = _user.language_id
LEFT OUTER JOIN verse.resource_providers
USING ( planet_id , resource_name_id )
LEFT OUTER JOIN emp.mining_settings_view
USING ( planet_id , resource_name_id )
WHERE planet_id = $1
ORDER BY resource_ordering;
$get_planet_resources$ LANGUAGE SQL;
REVOKE EXECUTE
ON FUNCTION emp.get_planet_resources( INT )
FROM PUBLIC;
GRANT EXECUTE
ON FUNCTION emp.get_planet_resources( INT )
TO :dbuser;

View file

@ -0,0 +1,47 @@
/*
* Tests for defs.resource_category_weight_view
*/
BEGIN;
/*
* We need a few resources, with a known average per category. Some of the
* resources must not belong to any category.
*/
\i utils/strings.sql
SELECT _create_test_strings( 5 , 'resource' );
SELECT _create_test_strings( 5 , 'resDesc' );
SELECT _create_test_strings( 2 , 'resCat' );
INSERT INTO defs.resources(
resource_name_id , resource_description_id ,
resource_category_id , resource_weight
) VALUES (
_get_string( 'resource1' ) , _get_string( 'resDesc1' ) ,
_get_string( 'resCat1' ) , 2
) , (
_get_string( 'resource2' ) , _get_string( 'resDesc2' ) ,
_get_string( 'resCat1' ) , 4
) , (
_get_string( 'resource3' ) , _get_string( 'resDesc3' ) ,
_get_string( 'resCat2' ) , 3
) , (
_get_string( 'resource4' ) , _get_string( 'resDesc4' ) ,
_get_string( 'resCat2' ) , 5
) , (
_get_string( 'resource5' ) , _get_string( 'resDesc5' ) ,
NULL , 150
);
SELECT plan( 1 );
SELECT diag_test_name( 'defs.resource_category_weight_view - Resulting set contains correct values' );
SELECT set_eq(
$$ SELECT * FROM defs.resource_category_weight_view $$ ,
$$ VALUES (
_get_string( 'resCat1' ) , 3
) , (
_get_string( 'resCat2' ) , 4
) $$
);
SELECT * FROM finish( );
ROLLBACK;

View file

@ -0,0 +1,57 @@
/*
* Tests for defs.ordered_resources_view
*/
BEGIN;
/*
* We need:
* - one resource without category with weight 1,
* - one resource with category 1 and weight 2,
* - one resource with weight 4 and no category,
* - two resourcew with weights 3 and 7 and category 2.
*/
\i utils/strings.sql
SELECT _create_test_strings( 5 , 'resource' );
SELECT _create_test_strings( 5 , 'resDesc' );
SELECT _create_test_strings( 2 , 'resCat' );
INSERT INTO defs.resources(
resource_name_id , resource_description_id ,
resource_category_id , resource_weight
) VALUES (
_get_string( 'resource1' ) , _get_string( 'resDesc1' ) ,
NULL , 1
) , (
_get_string( 'resource2' ) , _get_string( 'resDesc2' ) ,
_get_string( 'resCat1' ) , 2
) , (
_get_string( 'resource3' ) , _get_string( 'resDesc3' ) ,
NULL , 4
) , (
_get_string( 'resource4' ) , _get_string( 'resDesc4' ) ,
_get_string( 'resCat2' ) , 3
) , (
_get_string( 'resource5' ) , _get_string( 'resDesc5' ) ,
_get_string( 'resCat2' ) , 7
);
SELECT plan( 1 );
SELECT diag_test_name( 'defs.ordered_resources_view - Resources are in the correct order' );
SELECT set_eq(
$$ SELECT resource_name_id , resource_ordering
FROM defs.ordered_resources_view $$ ,
$$ VALUES (
_get_string( 'resource1' ) , 1
) , (
_get_string( 'resource2' ) , 2
) , (
_get_string( 'resource3' ) , 3
) , (
_get_string( 'resource4' ) , 4
) , (
_get_string( 'resource5' ) , 5
) $$
);
SELECT * FROM finish( );
ROLLBACK;

View file

@ -0,0 +1,56 @@
/*
* Tests for emp.planet_resources_view
*/
BEGIN;
/*
* Create two empires, one with 2 planets, the other without. Add 2 planet
* resources records.
*
* Disable all foreign keys to avoid a lot of work.
*/
ALTER TABLE emp.planets
DROP CONSTRAINT fk_eplanets_empire ,
DROP CONSTRAINT fk_eplanets_planet;
ALTER TABLE verse.planet_resources
DROP CONSTRAINT fk_pres_planet ,
DROP CONSTRAINT fk_pres_resource;
INSERT INTO verse.planet_resources (
planet_id , resource_name_id , pres_income , pres_upkeep
) VALUES
( 1 , 1 , 1 , 2 ) , ( 1 , 2 , 3 , 4 ) ,
( 2 , 1 , 3 , 4 ) , ( 2 , 2 , 5 , 6 ) ,
( 3 , 1 , 0.1 / 720 , 0.4 / 720 ) ,
( 3 , 2 , 0.9 / 720, 0.9 / 720 );
INSERT INTO emp.planets( empire_id , planet_id )
VALUES ( 1 , 1 ) , ( 1 , 2 ) , ( 2 , 3 );
/***** TESTS BEGIN HERE *****/
SELECT plan( 3 );
SELECT diag_test_name( 'emp.planet_resources_view - Sums' );
SELECT set_eq(
$$ SELECT * FROM emp.planet_resources_view WHERE empire_id = 1 $$ ,
$$ VALUES ( 1 , 1 , 4 * 720 , 6 * 720 ) , ( 1 , 2 , 8 * 720 , 10 * 720 ) $$
);
SELECT diag_test_name( 'emp.planet_resources_view - Incomes are rounded down' );
SELECT set_eq(
$$ SELECT resource_name_id , planets_income
FROM emp.planet_resources_view
WHERE empire_id = 2 $$ ,
$$ VALUES ( 1 , 0 ) , ( 2 , 0 ) $$
);
SELECT diag_test_name( 'emp.planet_resources_view - Upkeeps are rounded up' );
SELECT set_eq(
$$ SELECT resource_name_id , planets_upkeep
FROM emp.planet_resources_view
WHERE empire_id = 2 $$ ,
$$ VALUES ( 1 , 1 ) , ( 2 , 1 ) $$
);
SELECT * FROM finish( );
ROLLBACK;

View file

@ -0,0 +1,169 @@
/*
* Tests for emp.resources_view
*/
BEGIN;
/*
* We will use a fake emp.planet_resources_view to avoid having to set
* planet resources.
*
* In terms of data, we need two resources (one with a category, the other
* without, and two empires (one with "planet resources", the other
* without). Both empires will have mining settings for one of the resource
* types.
*/
\i utils/strings.sql
SELECT _create_test_strings( 2 , 'resource' , 'Resource name ' );
SELECT _create_test_strings( 2 , 'rDesc' , 'Resource description ' );
SELECT _create_test_strings( 1 , 'rCat' , 'Resource category ' );
INSERT INTO defs.resources (
resource_name_id , resource_description_id ,
resource_category_id , resource_weight
) VALUES (
_get_string( 'resource1' ) , _get_string( 'rDesc1' ) ,
_get_string( 'rCat1' ) , 2
) , (
_get_string( 'resource2' ) , _get_string( 'rDesc2' ) ,
NULL , 1
);
\i utils/accounts.sql
\i utils/naming.sql
SELECT _create_emp_names( 2 , 'emp' );
INSERT INTO emp.empires( name_id , cash )
SELECT id , 0 FROM naming.empire_names;
ALTER TABLE emp.mining_settings DROP CONSTRAINT fk_empmset_resource;
INSERT INTO emp.mining_settings ( empire_id , resource_name_id , empmset_weight )
SELECT id , _get_string( 'resource1' ) , row_number( ) OVER ()
FROM naming.empire_names
ORDER BY id;
INSERT INTO emp.resources ( empire_id , resource_name_id , empres_possessed )
SELECT name_id , resource_name_id , 0.4 * row_number( ) OVER ()
FROM emp.empires
CROSS JOIN defs.resources
ORDER BY name_id , resource_name_id;
CREATE TABLE fake_planet_resources_view (
empire_id INT ,
resource_name_id INT ,
planets_income BIGINT ,
planets_upkeep BIGINT
);
CREATE OR REPLACE VIEW emp.planet_resources_view
AS SELECT * FROM fake_planet_resources_view;
INSERT INTO fake_planet_resources_view
VALUES (
_get_emp_name( 'emp1' ) , _get_string( 'resource1' ) , 1 , 2
) , (
_get_emp_name( 'emp1' ) , _get_string( 'resource2' ) , 3 , 4
);
/***** TESTS BEGIN HERE *****/
SELECT plan( 13 );
SELECT diag_test_name( 'emp.resources_view - One row per empire/resource combination' );
SELECT is( COUNT(*)::INT , 4 ) FROM emp.resources_view;
SELECT diag_test_name( 'emp.resources_view - Resource ordering' );
SELECT set_eq(
$$ SELECT resource_identifier , row_number( ) OVER ( )
FROM emp.resources_view
WHERE empire_id = _get_emp_name( 'emp1' ) $$ ,
$$ VALUES ( 'resource2' , 1 ) , ( 'resource1' , 2 ) $$
);
SELECT diag_test_name( 'emp.resources_view - Name translation' );
SELECT is_empty( $$
SELECT *
FROM emp.resources_view
WHERE resource_name NOT LIKE 'Resource name %'
$$ );
SELECT diag_test_name( 'emp.resources_view - Description translation' );
SELECT is_empty( $$
SELECT *
FROM emp.resources_view
WHERE resource_description NOT LIKE 'Resource description %'
$$ );
SELECT diag_test_name( 'emp.resources_view - Category translation' );
SELECT is_empty( $$
SELECT *
FROM emp.resources_view
WHERE resource_identifier = 'resource1'
AND resource_category NOT LIKE 'Resource category %'
$$ );
SELECT diag_test_name( 'emp.resources_view - NULL category -> NULL translation' );
SELECT is_empty( $$
SELECT *
FROM emp.resources_view
WHERE resource_identifier <> 'resource1'
AND resource_category IS NOT NULL
$$ );
SELECT diag_test_name( 'emp.resources_view - Possessed quantities are rounded down' );
SELECT set_eq(
$$ SELECT empire_id , resource_identifier , empres_possessed
FROM emp.resources_view $$ ,
$$ VALUES (
_get_emp_name( 'emp1' ) , 'resource1' , 0
) , (
_get_emp_name( 'emp1' ) , 'resource2' , 0
) , (
_get_emp_name( 'emp2' ) , 'resource1' , 1
) , (
_get_emp_name( 'emp2' ) , 'resource2' , 1
) $$
);
SELECT diag_test_name( 'emp.resources_view - Basic resources have NULL mining settings' );
SELECT is( COUNT(*)::INT , 2 )
FROM emp.resources_view
WHERE resource_identifier = 'resource2'
AND empmset_weight IS NULL;
SELECT diag_test_name( 'emp.resources_view - Mining settings for natural resources' );
SELECT set_eq(
$$ SELECT empire_id , empmset_weight
FROM emp.resources_view
WHERE resource_identifier = 'resource1' $$ ,
$$ VALUES ( _get_emp_name( 'emp1' ) , 1 ) ,
( _get_emp_name( 'emp2' ) , 2 ) $$
);
SELECT is( COUNT(*)::INT , 2 )
FROM emp.resources_view
WHERE resource_identifier = 'resource1'
AND empmset_weight IS NOT NULL;
SELECT diag_test_name( 'emp.resources_view - Planet upkeep/income is zero when there are no planets' );
SELECT is( COUNT(*)::INT , 2 )
FROM emp.resources_view
WHERE empire_id = _get_emp_name( 'emp2' )
AND planets_upkeep = 0
AND planets_income = 0;
SELECT diag_test_name( 'emp.resources_view - Planet upkeep/income from planet resources view' );
SELECT set_eq(
$$ SELECT resource_identifier , planets_upkeep , planets_income
FROM emp.resources_view
WHERE empire_id = _get_emp_name( 'emp1' ) $$ ,
$$ VALUES ( 'resource1' , 2 , 1 ) , ( 'resource2' , 4 , 3 ) $$
);
SELECT diag_test_name( 'emp.resources_view - FIXME - Fleets upkeep set to zero' );
SELECT is_empty(
$$ SELECT * FROM emp.resources_view
WHERE fleets_upkeep <> 0 $$
);
SELECT * FROM finish( );
ROLLBACK;

View file

@ -0,0 +1,187 @@
/*
* Tests for the emp.get_planet_resources() function
*/
BEGIN;
/*
* We need two planets, one being owned by some empire, the other being
* neutral. Both planets' resource records must exist. Both planets will
* also include resource providers which will serve as tests for the
* various rounding which takes place.
*
* To avoid having to define actual natural resources, we disable the
* foreign keys on resource providers and mining settings. We can't do
* that for the empire, tho: we need an actual account as the translations
* must be looked up.
*/
\i utils/strings.sql
SELECT _create_test_strings( 3 , 'resource' , 'Resource name ' );
SELECT _create_test_strings( 3 , 'rDesc' , 'Resource description ' );
SELECT _create_test_strings( 1 , 'rCat' , 'Resource category ' );
INSERT INTO defs.resources (
resource_name_id , resource_description_id ,
resource_category_id , resource_weight
) VALUES (
_get_string( 'resource1' ) , _get_string( 'rDesc1' ) ,
_get_string( 'rCat1' ) , 2
) , (
_get_string( 'resource2' ) , _get_string( 'rDesc2' ) ,
NULL , 1
) , (
_get_string( 'resource3' ) , _get_string( 'rDesc3' ) ,
NULL , 3
);
\i utils/accounts.sql
\i utils/naming.sql
SELECT _create_emp_names( 1 , 'emp' );
INSERT INTO emp.empires( name_id , cash )
VALUES( _get_emp_name( 'emp1' ) , 0 );
ALTER TABLE emp.mining_settings DROP CONSTRAINT fk_empmset_resource;
INSERT INTO emp.mining_settings ( empire_id , resource_name_id )
SELECT _get_emp_name( 'emp1' ) , resource_name_id
FROM defs.resources;
\i utils/universe.sql
SELECT _create_raw_planets( 2 , 'planet' );
INSERT INTO verse.planet_resources (
planet_id , resource_name_id , pres_income , pres_upkeep
) VALUES (
_get_map_name( 'planet1' ) , _get_string( 'resource1' ) ,
99.4 / 720.0 , 99.4 / 720.0
) , (
_get_map_name( 'planet1' ) , _get_string( 'resource2' ) ,
99.5 / 720.0 , 99.5 / 720.0
) , (
_get_map_name( 'planet1' ) , _get_string( 'resource3' ) ,
99.6 / 720.0 , 99.6 / 720.0
);
INSERT INTO verse.planet_resources ( planet_id , resource_name_id )
SELECT _get_map_name( 'planet2' ) , resource_name_id
FROM defs.resources;
ALTER TABLE verse.resource_providers DROP CONSTRAINT fk_resprov_resource;
INSERT INTO verse.resource_providers(
planet_id , resource_name_id , resprov_quantity_max ,
resprov_quantity , resprov_difficulty , resprov_recovery
) VALUES (
_get_map_name( 'planet1' ) , _get_string( 'resource1' ) , 99.4 ,
99.4 , 0.494 , 0.5
) , (
_get_map_name( 'planet1' ) , _get_string( 'resource2' ) , 99.5 ,
99.5 , 0.495 , 0.5
) , (
_get_map_name( 'planet2' ) , _get_string( 'resource1' ) , 100 ,
100 , 0.5 , 0.5
);
INSERT INTO emp.planets ( empire_id , planet_id )
VALUES ( _get_emp_name( 'emp1' ) , _get_map_name( 'planet1' ) );
/***** TESTS BEGIN HERE *****/
SELECT plan( 13 );
SELECT diag_test_name( 'emp.get_planet_resources() - No results on missing planets' );
SELECT is_empty( $$ SELECT * FROM emp.get_planet_resources( _get_bad_map_name( ) ) $$ );
SELECT diag_test_name( 'emp.get_planet_resources() - No results on neutral planets' );
SELECT is_empty( $$ SELECT * FROM emp.get_planet_resources( _get_map_name( 'planet2' ) ) $$ );
SELECT diag_test_name( 'emp.get_planet_resources() - One row per resource type' );
SELECT is( COUNT(*)::INT , 3 ) FROM emp.get_planet_resources( _get_map_name( 'planet1' ) );
SELECT diag_test_name( 'emp.get_planet_resources() - Row ordering' );
SELECT set_eq(
$$ SELECT resource_identifier , row_number() OVER ( )
FROM emp.get_planet_resources( _get_map_name( 'planet1' ) ) $$ ,
$$ VALUES (
'resource1' , 2
) , (
'resource2' , 1
) , (
'resource3' , 3
) $$
);
SELECT diag_test_name( 'emp.get_planet_resources() - Name translation' );
SELECT is_empty( $$
SELECT *
FROM emp.get_planet_resources( _get_map_name( 'planet1' ) )
WHERE resource_name NOT LIKE 'Resource name %'
$$ );
SELECT diag_test_name( 'emp.get_planet_resources() - Description translation' );
SELECT is_empty( $$
SELECT *
FROM emp.get_planet_resources( _get_map_name( 'planet1' ) )
WHERE resource_description NOT LIKE 'Resource description %'
$$ );
SELECT diag_test_name( 'emp.get_planet_resources() - Category translation' );
SELECT is_empty( $$
SELECT *
FROM emp.get_planet_resources( _get_map_name( 'planet1' ) )
WHERE resource_identifier = 'resource1'
AND resource_category NOT LIKE 'Resource category %'
$$ );
SELECT diag_test_name( 'emp.get_planet_resources() - NULL category -> NULL translation' );
SELECT is_empty( $$
SELECT *
FROM emp.get_planet_resources( _get_map_name( 'planet1' ) )
WHERE resource_identifier <> 'resource1'
AND resource_category IS NOT NULL
$$ );
SELECT diag_test_name( 'emp.get_planet_resources() - Upkeep is valid and rounded up' );
SELECT is_empty( $$
SELECT *
FROM emp.get_planet_resources( _get_map_name( 'planet1' ) )
WHERE pres_upkeep IS NULL OR pres_upkeep <> 100
$$ );
SELECT diag_test_name( 'emp.get_planet_resources() - Income is valid and rounded down' );
SELECT is_empty( $$
SELECT * FROM emp.get_planet_resources( _get_map_name( 'planet1' ) )
WHERE pres_income IS NULL OR pres_income <> 99
$$ );
SELECT diag_test_name( 'emp.get_planet_resources() - No mining-related fields when there is no resource provider' );
SELECT is_empty( $$
SELECT * FROM emp.get_planet_resources( _get_map_name( 'planet1' ) )
WHERE resource_identifier = 'resource3' AND NOT (
resprov_capacity IS NULL
AND resprov_quantity IS NULL
AND resprov_difficulty IS NULL
AND mset_weight IS NULL
);
$$ );
SELECT diag_test_name( 'emp.get_planet_resources() - Resource provider fields are present' );
SELECT is_empty( $$
SELECT * FROM emp.get_planet_resources( _get_map_name( 'planet1' ) )
WHERE resource_identifier <> 'resource3' AND (
resprov_capacity IS NULL
OR resprov_quantity IS NULL
OR resprov_difficulty IS NULL
OR mset_weight IS NULL
);
$$ );
SELECT diag_test_name( 'emp.get_planet_resources() - Resource provider values' );
SELECT set_eq( $$
SELECT resource_identifier , resprov_capacity , resprov_quantity , resprov_difficulty
FROM emp.get_planet_resources( _get_map_name( 'planet1' ) )
WHERE resource_identifier <> 'resource3'
$$ , $$ VALUES (
'resource1' , 99 , 99 , 49
) , (
'resource2' , 100 , 100 , 50
) $$ );
SELECT * FROM finish( );
ROLLBACK;

View file

@ -0,0 +1,11 @@
/*
* Test privileges on defs.resource_category_weight_view
*/
BEGIN;
SELECT plan( 1 );
SELECT diag_test_name( 'defs.resource_category_weight_view - Privileges' );
SELECT throws_ok( 'SELECT * FROM defs.resource_category_weight_view' , 42501 );
SELECT * FROM finish( );
ROLLBACK;

View file

@ -0,0 +1,11 @@
/*
* Test privileges on defs.ordered_resources_view
*/
BEGIN;
SELECT plan( 1 );
SELECT diag_test_name( 'defs.ordered_resources_view - Privileges' );
SELECT throws_ok( 'SELECT * FROM defs.ordered_resources_view' , 42501 );
SELECT * FROM finish( );
ROLLBACK;

View file

@ -0,0 +1,11 @@
/*
* Test privileges on emp.planet_resources_view
*/
BEGIN;
SELECT plan( 1 );
SELECT diag_test_name( 'emp.planet_resources_view - Privileges' );
SELECT throws_ok( 'SELECT * FROM emp.planet_resources_view' , 42501 );
SELECT * FROM finish( );
ROLLBACK;

View file

@ -0,0 +1,11 @@
/*
* Test privileges on emp.resources_view
*/
BEGIN;
SELECT plan( 1 );
SELECT diag_test_name( 'emp.resources_view - Privileges' );
SELECT lives_ok( 'SELECT * FROM emp.resources_view' );
SELECT * FROM finish( );
ROLLBACK;

View file

@ -0,0 +1,13 @@
/*
* Test privileges on emp.get_planet_resources()
*/
BEGIN;
SELECT plan( 1 );
SELECT diag_test_name( 'emp.get_planet_resources() - Privileges' );
SELECT lives_ok( $$
SELECT emp.get_planet_resources( 1 )
$$ );
SELECT * FROM finish( );
ROLLBACK;

View file

@ -29,24 +29,11 @@ CREATE FUNCTION _get_string( TEXT ) RETURNS INT AS $$
$$ 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
* and translation prefix.
*/
CREATE FUNCTION _create_test_strings( _quantity INT , _prefix TEXT )
CREATE FUNCTION _create_test_strings( _quantity INT , _prefix TEXT , _trans TEXT )
RETURNS VOID
AS $$
DECLARE
@ -59,7 +46,27 @@ BEGIN
LOOP
i := i + 1;
PERFORM defs.uoc_translation( 't' , _prefix || i::TEXT ,
'Test string #' || i::TEXT );
_trans || i::TEXT );
END LOOP;
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 $$
SELECT _create_test_strings( $1 , $2 , 'Test string #' );
$$ LANGUAGE SQL;
/*
* Function that creates some quantity of test strings
*/
CREATE FUNCTION _create_test_strings( _quantity INT )
RETURNS VOID
AS $$
SELECT _create_test_strings( $1 , 'test' );
$$ LANGUAGE SQL;