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
legacyworlds-server-data/db-structure/parts/040-functions

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;