This repository has been archived on 2025-01-04. You can view files and clone it, but cannot push or open issues or pull requests.
lwb6/legacyworlds-server-data/db-structure/parts/040-functions/145-resource-providers.sql

278 lines
8.1 KiB
MySQL
Raw Normal View History

-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Resource providers functions
--
-- Copyright(C) 2004-2012, DeepClone Development
-- --------------------------------------------------------
/*
* Compute resource provider regeneration
*
* This function computes the quantity in a resource provider after it has
* been regenerated.
*
* Parameters:
* _quantity The current quantity of resources in the provider
* _max The maximal amount of resources supported by the
* provider
* _recovery_rate The provider's recovery rate
*
* Returns:
* ? The new quantity of resources.
*/
CREATE OR REPLACE FUNCTION verse.compute_provider_regeneration(
_quantity DOUBLE PRECISION ,
_max DOUBLE PRECISION ,
_recovery_rate DOUBLE PRECISION )
RETURNS DOUBLE PRECISION
STRICT IMMUTABLE
SECURITY INVOKER
AS $compute_provider_regeneration$
DECLARE
_uc_recovery DOUBLE PRECISION;
_uc_dampening DOUBLE PRECISION;
_uc_ticks DOUBLE PRECISION;
_result DOUBLE PRECISION;
BEGIN
_uc_recovery := sys.get_constant( 'game.resources.recovery' );
_uc_dampening := sys.get_constant( 'game.resources.recoveryDampening' );
_uc_ticks := 1440; -- FIXME: this should be a constant
_result := ( 1 - _quantity / _max ) ^ _uc_dampening;
_result := _quantity + _result * _recovery_rate * _uc_recovery / _uc_ticks;
IF _result > _max THEN
_result := _max;
END IF;
RETURN _result;
END;
$compute_provider_regeneration$ LANGUAGE PLPGSQL;
REVOKE EXECUTE
ON FUNCTION verse.compute_provider_regeneration(
DOUBLE PRECISION , DOUBLE PRECISION ,
DOUBLE PRECISION )
FROM PUBLIC;
/*
* Mining settings view
* ---------------------
*
* This view lists mining settings being used on planets owned by empires
* for each resource providers. The settings are taken from planet-specific
* settings if they are available, or from empire-wide settings.
*
* Columns:
*
* planet_id The planet's identifier
* resource_name_id The type of resources
* mset_weight The setting to use for mining priorities
* mset_specific True if the settings are specific for this planet,
* false if empire-wise settings are in use.
*/
DROP VIEW IF EXISTS emp.mining_settings_view CASCADE;
CREATE VIEW emp.mining_settings_view
AS SELECT planet_id , resource_name_id ,
( CASE
WHEN _pl_settings.planet_id IS NULL THEN
_emp_settings.empmset_weight
ELSE
_pl_settings.emppmset_weight
END ) AS mset_weight ,
( _pl_settings.planet_id IS NOT NULL ) AS mset_specific
FROM verse.resource_providers
INNER JOIN emp.planets
USING ( planet_id )
INNER JOIN emp.mining_settings _emp_settings
USING ( empire_id , resource_name_id )
LEFT OUTER JOIN emp.planet_mining_settings _pl_settings
USING ( planet_id , empire_id , resource_name_id );
GRANT SELECT
ON emp.mining_settings_view
TO :dbuser;
/*
* Compute a resource provider's extraction factor
*
* This function computes the extraction factor - a multiplier which makes
* mining more costly if the difficulty is high or if a provider is almost
* empty - based on a provider's fill ratio and difficulty.
*
* The complete formula can be read on the Wiki:
* https://wiki.legacyworlds.com/wiki/Mining#Resource_provider_extraction
*
* Parameters:
* _fill_ratio The ratio between the provider's current and maximal
* quantities
* _difficulty The provider's extraction difficulty.
*
* Returns:
* ? The provider's extraction factor
*/
DROP FUNCTION IF EXISTS verse.get_extraction_factor(
DOUBLE PRECISION , DOUBLE PRECISION );
CREATE FUNCTION verse.get_extraction_factor(
_fill_ratio DOUBLE PRECISION ,
_difficulty DOUBLE PRECISION )
RETURNS DOUBLE PRECISION
STRICT IMMUTABLE
SECURITY INVOKER
AS $get_extraction_factor$
SELECT ( 1 - $2 * 0.5 ) * POW( $1 , 1.5 + 2 * $2 );
$get_extraction_factor$ LANGUAGE SQL;
REVOKE EXECUTE
ON FUNCTION verse.get_extraction_factor(
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;