287 lines
8.4 KiB
MySQL
287 lines
8.4 KiB
MySQL
|
-- LegacyWorlds Beta 6
|
||
|
-- PostgreSQL database scripts
|
||
|
--
|
||
|
-- Game updates - planet mining computations
|
||
|
--
|
||
|
-- Copyright(C) 2004-2012, DeepClone Development
|
||
|
-- --------------------------------------------------------
|
||
|
|
||
|
|
||
|
/*
|
||
|
* 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 sys.gu_pmc_weights_view CASCADE;
|
||
|
CREATE VIEW sys.gu_pmc_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 sys.gu_pmc_totals_view CASCADE;
|
||
|
CREATE VIEW sys.gu_pmc_totals_view
|
||
|
AS SELECT planet_id , SUM( pmc_weight ) AS pmc_total
|
||
|
FROM sys.gu_pmc_weights_view
|
||
|
GROUP BY planet_id;
|
||
|
|
||
|
|
||
|
/*
|
||
|
* 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 sys.gu_pmc_data_type CASCADE;
|
||
|
CREATE TYPE sys.gu_pmc_data_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
|
||
|
);
|
||
|
|
||
|
|
||
|
|
||
|
/*
|
||
|
* Lock the rows and access the data used by the mining update
|
||
|
*
|
||
|
* This function executes a single query which serves the dual purpose of
|
||
|
* locking all rows from various tables used by the planet mining update
|
||
|
* and returning the data needed by the computation.
|
||
|
*
|
||
|
* As far as locking is concerned, the following tables are locked:
|
||
|
* - Update records are already locked, so we don't care.
|
||
|
* - Planets with resource providers are locked for share.
|
||
|
* - Resource providers and corresponding resource records are locked
|
||
|
* for update
|
||
|
* - Resource definitions are locked for share.
|
||
|
* - Owning empires, as well as their mining settings and any set of
|
||
|
* planet-specific settings for one of the planets we're inspecting,
|
||
|
* are locked for share.
|
||
|
*
|
||
|
* The data itself is returned as a set of rows using sys.gu_pmc_data_type
|
||
|
*
|
||
|
* Parameters:
|
||
|
* _tick The identifier of the current game update
|
||
|
*/
|
||
|
DROP FUNCTION IF EXISTS sys.gu_pmc_get_data( BIGINT );
|
||
|
CREATE FUNCTION sys.gu_pmc_get_data( _tick BIGINT )
|
||
|
RETURNS SETOF sys.gu_pmc_data_type
|
||
|
STRICT VOLATILE
|
||
|
SECURITY INVOKER
|
||
|
AS $gu_pmc_get_data$
|
||
|
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 ,
|
||
|
happiness ,
|
||
|
pmc_weight AS weight ,
|
||
|
pmc_total AS total_weight
|
||
|
|
||
|
FROM sys.updates _upd_sys
|
||
|
INNER JOIN verse.updates _upd_verse
|
||
|
ON _upd_sys.id = _upd_verse.update_id
|
||
|
INNER JOIN verse.planets _planet
|
||
|
ON _planet.name_id = _upd_verse.planet_id
|
||
|
INNER JOIN verse.resource_providers _resprov
|
||
|
USING ( planet_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 happiness
|
||
|
|
||
|
FROM sys.updates _upd_sys
|
||
|
INNER JOIN verse.updates _upd_verse
|
||
|
ON _upd_sys.id = _upd_verse.update_id
|
||
|
INNER JOIN emp.planets _emp_planet
|
||
|
USING ( planet_id )
|
||
|
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 sys.gu_pmc_weights_view
|
||
|
USING ( planet_id , resource_name_id)
|
||
|
INNER JOIN sys.gu_pmc_totals_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 _upd_sys.last_tick = $1
|
||
|
AND _upd_sys.status = 'PROCESSING'
|
||
|
AND _upd_sys.gu_type = 'PLANET_MINING'
|
||
|
|
||
|
FOR SHARE OF _emp_planet , _emp , _emset , _happ
|
||
|
) AS _owner
|
||
|
USING ( planet_id , resource_name_id )
|
||
|
|
||
|
WHERE _upd_sys.last_tick = $1
|
||
|
AND _upd_sys.status = 'PROCESSING'
|
||
|
AND _upd_sys.gu_type = 'PLANET_MINING'
|
||
|
|
||
|
FOR UPDATE OF _resprov , _pres
|
||
|
FOR SHARE OF _planet ;
|
||
|
$gu_pmc_get_data$ LANGUAGE SQL;
|
||
|
|
||
|
|
||
|
REVOKE EXECUTE
|
||
|
ON FUNCTION sys.gu_pmc_get_data( BIGINT )
|
||
|
FROM PUBLIC;
|
||
|
|
||
|
|
||
|
|
||
|
/*
|
||
|
* Update a planet's resource provider and corresponding resource record
|
||
|
*
|
||
|
* This function will compute the amount of resources extracted from a
|
||
|
* provider, and update both the provider itself and the corresponding
|
||
|
* resource record (setting the income to whatever quantity was extracted).
|
||
|
*
|
||
|
* Parameters:
|
||
|
* _input Data about the resource provider to update
|
||
|
*/
|
||
|
DROP FUNCTION IF EXISTS sys.gu_pmc_update_resource( sys.gu_pmc_data_type );
|
||
|
CREATE FUNCTION sys.gu_pmc_update_resource( _input sys.gu_pmc_data_type )
|
||
|
RETURNS VOID
|
||
|
STRICT VOLATILE
|
||
|
SECURITY INVOKER
|
||
|
AS $gu_pmc_update_resource$
|
||
|
|
||
|
DECLARE
|
||
|
_extraction DOUBLE PRECISION;
|
||
|
_allocation DOUBLE PRECISION;
|
||
|
_production DOUBLE PRECISION;
|
||
|
_quantity DOUBLE PRECISION;
|
||
|
|
||
|
BEGIN
|
||
|
|
||
|
_extraction := _input.quantity * 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!
|
||
|
|
||
|
RAISE NOTICE 'Extraction % , allocation % , production %' , _extraction , _allocation , _production;
|
||
|
_quantity := _allocation * _production * _extraction;
|
||
|
IF _quantity > _input.quantity THEN
|
||
|
_quantity := _input.quantity;
|
||
|
END IF;
|
||
|
|
||
|
UPDATE verse.resource_providers
|
||
|
SET resprov_quantity = resprov_quantity - _quantity
|
||
|
WHERE planet_id = _input.planet
|
||
|
AND resource_name_id = _input.resource;
|
||
|
UPDATE verse.planet_resources
|
||
|
SET pres_income = _quantity
|
||
|
WHERE planet_id = _input.planet
|
||
|
AND resource_name_id = _input.resource;
|
||
|
|
||
|
END;
|
||
|
$gu_pmc_update_resource$ LANGUAGE PLPGSQL;
|
||
|
|
||
|
REVOKE EXECUTE
|
||
|
ON FUNCTION sys.gu_pmc_update_resource( sys.gu_pmc_data_type )
|
||
|
FROM PUBLIC;
|
||
|
|
||
|
|
||
|
|
||
|
/*
|
||
|
* Planet mining game update
|
||
|
*
|
||
|
* Obtains all records to update for the current batch, then either set the
|
||
|
* income to 0 without modifying the resource provider if the planet is
|
||
|
* neutral, or call gu_pmc_update_resource() if there is an owner.
|
||
|
*
|
||
|
* Parameters:
|
||
|
* _tick The current tick's identifier
|
||
|
*/
|
||
|
DROP FUNCTION IF EXISTS sys.process_planet_mining_updates( BIGINT );
|
||
|
CREATE FUNCTION sys.process_planet_mining_updates( _tick BIGINT )
|
||
|
RETURNS VOID
|
||
|
STRICT VOLATILE
|
||
|
SECURITY INVOKER
|
||
|
AS $process_planet_mining_updates$
|
||
|
|
||
|
DECLARE
|
||
|
_row sys.gu_pmc_data_type;
|
||
|
|
||
|
BEGIN
|
||
|
FOR _row IN SELECT * FROM sys.gu_pmc_get_data( _tick )
|
||
|
LOOP
|
||
|
IF _row.empire IS NULL THEN
|
||
|
-- Set resource income to 0 on neutrals
|
||
|
UPDATE verse.planet_resources
|
||
|
SET pres_income = 0
|
||
|
WHERE planet_id = _row.planet
|
||
|
AND resource_name_id = _row.resource;
|
||
|
ELSE
|
||
|
PERFORM sys.gu_pmc_update_resource( _row );
|
||
|
END IF;
|
||
|
|
||
|
END LOOP;
|
||
|
END;
|
||
|
$process_planet_mining_updates$ LANGUAGE PLPGSQL;
|
||
|
|
||
|
|
||
|
REVOKE EXECUTE
|
||
|
ON FUNCTION sys.process_planet_mining_updates( BIGINT )
|
||
|
FROM PUBLIC;
|