Extracted quantities update as soon as possible

* The quantities of resources extracted from mines will now be updated
as soon as they have a reason to. This includes planet assignment,
abandonment, ownership changes, and updates to mining priorities.

* The mining update will now remove the current resource income from the
providers, and only then re-compute all extracted quantities. This is
more logical and corresponds to the way the other game updates work.

* Fixed bug in extraction computation where the size of the planet's
happy population was used instead of the happy/total ratio when
adjusting the mining production for riots.

* The following SQL scripts must be re-executed to upgrade a database:
  -> 040-functions/040-empire.sql
  -> 040-functions/145-resource-providers.sql
  -> 040-functions/147-empire-mining.sql
  -> 050-updates/120-planet-mining.sql
This commit is contained in:
Emmanuel BENOîT 2012-02-09 10:54:00 +01:00
parent f3aa563758
commit bf6bea5a79
35 changed files with 863 additions and 372 deletions
legacyworlds-server-data/db-structure/parts/040-functions

View file

@ -3,12 +3,13 @@
--
-- Empire management functions and views
--
-- Copyright(C) 2004-2010, DeepClone Development
-- Copyright(C) 2004-2012, DeepClone Development
-- --------------------------------------------------------
/*
* Empire creation
* ----------------
*
* This function inserts the rows that represent an empire and its settings.
* It also initialises the empire's updates.
@ -27,10 +28,8 @@ CREATE FUNCTION emp.create_empire(
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
_update BIGINT;
_update_type update_type;
BEGIN
-- Add empire and give initial planet
INSERT INTO emp.empires ( name_id , cash )
VALUES ( _name_id , _initial_cash );
@ -45,6 +44,14 @@ BEGIN
-- Add empire resources
INSERT INTO emp.resources ( empire_id , resource_name_id )
SELECT _name_id , resource_name_id FROM defs.resources;
-- Update resource mining quantities
UPDATE verse.planet_resources
SET pres_income = emp.mining_compute_extraction( _update_row )
FROM emp.mining_get_input( _name_id ) _update_row
WHERE planet_id = _update_row.planet
AND resource_name_id = _update_row.resource;
END;
$$ LANGUAGE plpgsql;

View file

@ -142,6 +142,7 @@ REVOKE EXECUTE
/*
* 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
@ -275,3 +276,285 @@ GRANT EXECUTE
ON FUNCTION emp.get_planet_resources( INT )
TO :dbuser;
/*
* Planet mining update data
* --------------------------
*
* This type is used by the records used by planet mining updates to compute a
* planet's mining output.
*/
DROP TYPE IF EXISTS emp.planet_mining_type CASCADE;
CREATE TYPE emp.planet_mining_type AS (
/* The planet's identifier */
planet INT ,
/* The resource's identifier */
resource INT ,
/* The provider's quantity of resources */
quantity DOUBLE PRECISION ,
/* The provider's maximal quantity of resources */
quantity_max DOUBLE PRECISION ,
/* The provider's extraction difficulty */
difficulty DOUBLE PRECISION ,
/* The empire who owns the planet, or NULL if the planet is neutral */
empire INT ,
/* The planet's happiness, or NULL if the planet is neutral */
happiness REAL ,
/* The weight computed from the resource's extraction priority as
* set by either the empire in general or the planet-specific settings,
* or NULL if the planet is neutral.
*/
weight DOUBLE PRECISION ,
/* The total weight computed from either the empire-wide or the
* planet-specific mining settings, or NULL if the planet is neutral.
*/
total_weight DOUBLE PRECISION
);
/*
* Mining computation - Weights view
* ----------------------------------
*
* This view computes the actual values used in the mining computations for
* each resource provider on all empire-owned planets.
*
* Columns:
* planet_id The planet's identifier
* resource_name_id The resource type's identifier
* pmc_weight The computed weight
*/
DROP VIEW IF EXISTS emp.scaled_mining_weights_view CASCADE;
CREATE VIEW emp.scaled_mining_weights_view
AS SELECT planet_id , resource_name_id ,
POW( sys.get_constant( 'game.resources.weightBase' ) ,
mset_weight ) AS pmc_weight
FROM emp.mining_settings_view;
/*
* Mining computation - Total weights view
* ----------------------------------------
*
* This view computes per-planet totals for actual mining weights.
*
* Columns:
* planet_id The planet's identifier
* pmc_total The sum of all mining weights on the planet.
*/
DROP VIEW IF EXISTS emp.total_mining_weights_view CASCADE;
CREATE VIEW emp.total_mining_weights_view
AS SELECT planet_id , SUM( pmc_weight ) AS pmc_total
FROM emp.scaled_mining_weights_view
GROUP BY planet_id;
/*
* Compute the extracted quantity
* -------------------------------
*
* Compute the quantity of resources that will be extracted from a resource
* provider at the next game update. This function is used by the mining
* update, obviously, but also by the various functions which control mining
* settings and by ownership changes.
*
* Parameters:
* _input Data about the resource provider to update
*
* Returns:
* ? The quantity that will be extracted from the provider
*/
DROP FUNCTION IF EXISTS emp.mining_compute_extraction( emp.planet_mining_type );
CREATE FUNCTION emp.mining_compute_extraction( _input emp.planet_mining_type )
RETURNS DOUBLE PRECISION
LANGUAGE PLPGSQL
STRICT IMMUTABLE
SECURITY INVOKER
AS $resprov_compute_extraction$
DECLARE
_extraction DOUBLE PRECISION;
_allocation DOUBLE PRECISION;
_production DOUBLE PRECISION;
_quantity DOUBLE PRECISION;
BEGIN
IF _input.empire IS NULL THEN
RETURN 0;
END IF;
_extraction := verse.get_extraction_factor(
_input.quantity / _input.quantity_max ,
_input.difficulty );
_allocation := _input.weight / _input.total_weight;
_production := verse.adjust_production(
verse.get_raw_production( _input.planet , 'MINE' ) ,
_input.happiness )
* sys.get_constant( 'game.resources.extraction' )
/ 1440.0; -- FIXME: hardcoded!
_quantity := _allocation * _production * _extraction;
IF _quantity > _input.quantity THEN
_quantity := _input.quantity;
END IF;
RETURN _quantity;
END;
$resprov_compute_extraction$;
REVOKE EXECUTE
ON FUNCTION emp.mining_compute_extraction( emp.planet_mining_type )
FROM PUBLIC;
/*
* Get resource extraction input for a single planet
* --------------------------------------------------
*
* This function locks and retrieves all data required to update a single
* planet's resource extraction quantities. It is used when a planet's
* owner changes (including planet assignment) or when a planet's specific
* mining settings are modified.
*
* Parameters:
* _planet The planet's identifier
*
* Returns:
* the set of emp.planet_mining_type records for the planet
*/
DROP FUNCTION IF EXISTS verse.mining_get_input( _planet INT );
CREATE FUNCTION verse.mining_get_input( _planet INT )
RETURNS SETOF emp.planet_mining_type
LANGUAGE SQL
STRICT VOLATILE
SECURITY INVOKER
AS $mining_get_input$
SELECT planet_id AS planet ,
resource_name_id AS resource,
resprov_quantity AS quantity ,
resprov_quantity_max AS quantity_max ,
resprov_difficulty AS difficulty ,
empire_id AS empire ,
( happy_pop / _planet.population ) AS happiness ,
pmc_weight AS weight ,
pmc_total AS total_weight
FROM verse.planets _planet
INNER JOIN verse.resource_providers _resprov
ON planet_id = name_id
INNER JOIN verse.planet_resources _pres
USING ( planet_id , resource_name_id )
LEFT OUTER JOIN (
SELECT _emp_planet.empire_id , _emp_planet.planet_id ,
_emset.resource_name_id , pmc_weight ,
pmc_total , _happ.current AS happy_pop
FROM emp.planets _emp_planet
INNER JOIN emp.empires _emp
ON _emp_planet.empire_id = _emp.name_id
INNER JOIN emp.mining_settings _emset
USING ( empire_id )
INNER JOIN verse.planet_happiness _happ
USING ( planet_id )
INNER JOIN emp.scaled_mining_weights_view
USING ( planet_id , resource_name_id)
INNER JOIN emp.total_mining_weights_view
USING ( planet_id )
LEFT OUTER JOIN (
SELECT * FROM emp.planet_mining_settings
FOR SHARE
) AS _pmset
USING ( empire_id , planet_id , resource_name_id )
WHERE _emp_planet.planet_id = $1
FOR SHARE OF _emp_planet , _emp , _emset , _happ
) AS _owner
USING ( planet_id , resource_name_id )
WHERE _planet.name_id = $1
FOR UPDATE OF _resprov , _pres
FOR SHARE OF _planet ;
$mining_get_input$;
REVOKE EXECUTE
ON FUNCTION verse.mining_get_input( _planet INT )
FROM PUBLIC;
/*
* Get resource extraction input for a whole empire
* -------------------------------------------------
*
* This function retrieves all mining information for a whole empire. It is
* used to recompute extracted quantities when global settings are updated.
*
* Parameters:
* _empire The empire's identifier
*
* Returns:
* the set of emp.planet_mining_type records for the empire
*/
DROP FUNCTION IF EXISTS emp.mining_get_input( _empire INT );
CREATE FUNCTION emp.mining_get_input( _empire INT )
RETURNS SETOF emp.planet_mining_type
LANGUAGE SQL
STRICT VOLATILE
SECURITY INVOKER
AS $mining_get_input$
SELECT planet_id AS planet ,
resource_name_id AS resource,
resprov_quantity AS quantity ,
resprov_quantity_max AS quantity_max ,
resprov_difficulty AS difficulty ,
empire_id AS empire ,
_happ.current / _planet.population AS happiness ,
pmc_weight AS weight ,
pmc_total AS total_weight
FROM emp.planets _emp_planet
INNER JOIN emp.empires _emp
ON _emp_planet.empire_id = _emp.name_id
INNER JOIN emp.mining_settings _emset
USING ( empire_id )
INNER JOIN verse.planets _planet
ON _planet.name_id = _emp_planet.planet_id
INNER JOIN verse.resource_providers _resprov
USING ( planet_id , resource_name_id )
INNER JOIN verse.planet_resources _pres
USING ( planet_id , resource_name_id )
INNER JOIN verse.planet_happiness _happ
USING ( planet_id )
INNER JOIN emp.scaled_mining_weights_view
USING ( planet_id , resource_name_id )
INNER JOIN emp.total_mining_weights_view
USING ( planet_id )
LEFT OUTER JOIN (
SELECT * FROM emp.planet_mining_settings
FOR SHARE
) AS _pmset
USING ( empire_id , planet_id , resource_name_id )
WHERE _emp_planet.empire_id = $1
FOR UPDATE OF _resprov , _pres
FOR SHARE OF _emp_planet , _emp , _emset , _happ , _planet ;
$mining_get_input$;
REVOKE EXECUTE
ON FUNCTION emp.mining_get_input( _empire INT )
FROM PUBLIC;

View file

@ -205,6 +205,7 @@ BEGIN
FROM mset_update
LIMIT 1;
-- Delete then re-insert all settings for the planet
DELETE FROM emp.planet_mining_settings
WHERE empire_id = _empire AND planet_id = _planet;
INSERT INTO emp.planet_mining_settings (
@ -216,10 +217,22 @@ BEGIN
INNER JOIN defs.strings _str
ON _str.name = resource_name;
-- Update the planet's extraction
UPDATE verse.planet_resources
SET pres_income = emp.mining_compute_extraction( _update_row )
FROM verse.mining_get_input( _planet ) _update_row
WHERE planet_id = _update_row.planet
AND resource_name_id = _update_row.resource;
EXCEPTION
-- These are empire-wide settings
WHEN undefined_column THEN
-- Get empire identifier
SELECT INTO _empire empire_id
FROM mset_update LIMIT 1;
-- Update the empire's settings
UPDATE emp.mining_settings _settings
SET empmset_weight = _update.empmset_weight
FROM mset_update _update
@ -227,6 +240,14 @@ BEGIN
ON _str.name = _update.resource_name
WHERE _update.empire_id = _settings.empire_id
AND _str.id = _settings.resource_name_id;
-- Update extracted quantities for the whole empire
UPDATE verse.planet_resources
SET pres_income = emp.mining_compute_extraction( _update_row )
FROM emp.mining_get_input( _empire ) _update_row
WHERE planet_id = _update_row.planet
AND resource_name_id = _update_row.resource;
END;
RETURN TRUE;
@ -291,9 +312,20 @@ BEGIN
PERFORM 1 FROM emp.planet_mining_settings _pms
WHERE planet_id = _planet AND empire_id = _empire;
IF FOUND THEN
-- Remove planet-specific settings, then update extracted quantities
DELETE FROM emp.planet_mining_settings
WHERE planet_id = _planet AND empire_id = _empire;
UPDATE verse.planet_resources
SET pres_income = emp.mining_compute_extraction( _update_row )
FROM verse.mining_get_input( _planet ) _update_row
WHERE planet_id = _update_row.planet
AND resource_name_id = _update_row.resource;
ELSE
-- Create planet-specific settings using empire-wide values as the
-- defaults. Because of that, no extraction update is necessary.
INSERT INTO emp.planet_mining_settings(
empire_id , planet_id , resource_name_id , emppmset_weight
) SELECT empire_id , planet_id , resource_name_id , empmset_weight
@ -301,6 +333,7 @@ BEGIN
INNER JOIN emp.mining_settings
USING ( resource_name_id )
WHERE planet_id = _planet AND empire_id = _empire;
END IF;
RETURN TRUE;