diff --git a/legacyworlds-server-data/db-structure/parts/040-functions/040-empire.sql b/legacyworlds-server-data/db-structure/parts/040-functions/040-empire.sql index cb30603..a49c0d6 100644 --- a/legacyworlds-server-data/db-structure/parts/040-functions/040-empire.sql +++ b/legacyworlds-server-data/db-structure/parts/040-functions/040-empire.sql @@ -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; diff --git a/legacyworlds-server-data/db-structure/parts/040-functions/145-resource-providers.sql b/legacyworlds-server-data/db-structure/parts/040-functions/145-resource-providers.sql index 74b758b..ebab70b 100644 --- a/legacyworlds-server-data/db-structure/parts/040-functions/145-resource-providers.sql +++ b/legacyworlds-server-data/db-structure/parts/040-functions/145-resource-providers.sql @@ -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; diff --git a/legacyworlds-server-data/db-structure/parts/040-functions/045-empire-mining.sql b/legacyworlds-server-data/db-structure/parts/040-functions/147-empire-mining.sql similarity index 86% rename from legacyworlds-server-data/db-structure/parts/040-functions/045-empire-mining.sql rename to legacyworlds-server-data/db-structure/parts/040-functions/147-empire-mining.sql index 8704d68..c2c0096 100644 --- a/legacyworlds-server-data/db-structure/parts/040-functions/045-empire-mining.sql +++ b/legacyworlds-server-data/db-structure/parts/040-functions/147-empire-mining.sql @@ -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; diff --git a/legacyworlds-server-data/db-structure/parts/050-updates/120-planet-mining.sql b/legacyworlds-server-data/db-structure/parts/050-updates/120-planet-mining.sql index 6f9c53f..1a6ae31 100644 --- a/legacyworlds-server-data/db-structure/parts/050-updates/120-planet-mining.sql +++ b/legacyworlds-server-data/db-structure/parts/050-updates/120-planet-mining.sql @@ -7,87 +7,6 @@ -- -------------------------------------------------------- -/* - * 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 * @@ -105,14 +24,14 @@ CREATE TYPE sys.gu_pmc_data_type AS ( * 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 + * The data itself is returned as a set of rows using emp.planet_mining_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 + RETURNS SETOF emp.planet_mining_type STRICT VOLATILE SECURITY INVOKER AS $gu_pmc_get_data$ @@ -122,7 +41,7 @@ AS $gu_pmc_get_data$ resprov_quantity_max AS quantity_max , resprov_difficulty AS difficulty , empire_id AS empire , - happiness , + ( happy_pop / _planet.population ) AS happiness , pmc_weight AS weight , pmc_total AS total_weight @@ -137,8 +56,8 @@ AS $gu_pmc_get_data$ 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 + _emset.resource_name_id , pmc_weight , pmc_total , + _happ.current AS happy_pop FROM sys.updates _upd_sys INNER JOIN verse.planets_updates _upd_verse @@ -151,9 +70,9 @@ AS $gu_pmc_get_data$ USING ( empire_id ) INNER JOIN verse.planet_happiness _happ USING ( planet_id ) - INNER JOIN sys.gu_pmc_weights_view + INNER JOIN emp.scaled_mining_weights_view USING ( planet_id , resource_name_id) - INNER JOIN sys.gu_pmc_totals_view + INNER JOIN emp.total_mining_weights_view USING ( planet_id ) LEFT OUTER JOIN ( SELECT * FROM emp.planet_mining_settings @@ -182,69 +101,14 @@ REVOKE EXECUTE -/* - * 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 := 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! - - PERFORM sys.write_sql_log( 'MiningUpdate' , 'TRACE' , 'Resource #' || _input.resource - || ' @ planet #' || _input.planet || ': extraction ' || _extraction - || ', allocation ' || _allocation || ', production ' || _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 + * -------------------------- + * + * Lock all records involved with the update, then update the quantity of + * resources in resource providers depending on what was mined this turn. + * Finally update all extraction quantities. * * 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 @@ -255,30 +119,35 @@ REVOKE EXECUTE */ 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$ + RETURNS VOID + LANGUAGE SQL + STRICT VOLATILE + SECURITY INVOKER +AS $process_planet_mining_updates$ + -- Lock all rows + SELECT 1 FROM sys.gu_pmc_get_data( $1 ); -DECLARE - _row sys.gu_pmc_data_type; + -- Execute the actual mining + UPDATE verse.resource_providers _resprov + SET resprov_quantity = resprov_quantity - _pres.pres_income + FROM sys.updates _upd_sys + INNER JOIN verse.planets_updates _upd_verse + USING ( update_id , updtype_id , updtgt_id ) + INNER JOIN verse.planet_resources _pres + ON _pres.planet_id = _upd_verse.name_id + WHERE _upd_sys.update_last = $1 + AND _upd_sys.update_state = 'PROCESSING' + AND _pres.planet_id = _resprov.planet_id + AND _pres.resource_name_id = _resprov.resource_name_id; -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; + -- Update extraction data + UPDATE verse.planet_resources + SET pres_income = emp.mining_compute_extraction( _update_row ) + FROM sys.gu_pmc_get_data( $1 ) _update_row + WHERE planet_id = _update_row.planet + AND resource_name_id = _update_row.resource; - END LOOP; -END; -$process_planet_mining_updates$ LANGUAGE PLPGSQL; +$process_planet_mining_updates$; REVOKE EXECUTE diff --git a/legacyworlds-server-data/db-structure/tests/admin/040-functions/040-empire/010-create-empire.sql b/legacyworlds-server-data/db-structure/tests/admin/040-functions/040-empire/010-create-empire.sql index 6520694..5aa570b 100644 --- a/legacyworlds-server-data/db-structure/tests/admin/040-functions/040-empire/010-create-empire.sql +++ b/legacyworlds-server-data/db-structure/tests/admin/040-functions/040-empire/010-create-empire.sql @@ -3,7 +3,7 @@ */ BEGIN; /* We need a pair of natural resources, a basic resource, a planet - * and an empire name. + * and an empire name. We add a resource provider to the planet. */ \i utils/strings.sql \i utils/resources.sql @@ -14,9 +14,42 @@ BEGIN; SELECT _create_resources( 1 , 'basicRes' ); SELECT _create_raw_planets( 1 , 'testPlanet' ); SELECT _create_emp_names( 1 , 'testEmp' ); + + INSERT INTO verse.planet_resources( planet_id , resource_name_id ) + SELECT name_id , resource_name_id + FROM verse.planets CROSS JOIN defs.resources; + + INSERT INTO verse.resource_providers ( + planet_id , resource_name_id , resprov_quantity_max , + resprov_quantity , resprov_difficulty , resprov_recovery + ) VALUES ( + _get_map_name( 'testPlanet1' ) , _get_string( 'natRes1' ) , 100 , + 100 , 0.2 , 0.5 + ); + + /* We replace the emp.mining_get_input() and emp.mining_compute_extraction() + * functions with something we control fully. + */ + CREATE OR REPLACE FUNCTION emp.mining_get_input( _empire INT ) + RETURNS SETOF emp.planet_mining_type + LANGUAGE SQL + AS $$ + SELECT _get_map_name( 'testPlanet1' ) AS planet , + _get_string( 'natRes1' ) AS resource , + NULL::DOUBLE PRECISION AS quantity , NULL::DOUBLE PRECISION AS quantity_max , + NULL::DOUBLE PRECISION AS difficulty , NULL::INT AS empire , + NULL::REAL AS happiness , NULL::DOUBLE PRECISION AS weight , + NULL::DOUBLE PRECISION AS total_weight; + $$; + + CREATE OR REPLACE FUNCTION emp.mining_compute_extraction( _input emp.planet_mining_type ) + RETURNS DOUBLE PRECISION LANGUAGE SQL + AS $$ + SELECT 42::DOUBLE PRECISION; + $$; /***** TESTS BEGIN HERE *****/ - SELECT plan( 7 ); + SELECT plan( 8 ); SELECT emp.create_empire( _get_emp_name( 'testEmp1' ) , _get_map_name( 'testPlanet1' ) , @@ -25,10 +58,12 @@ BEGIN; SELECT diag_test_name( 'emp.create_empire() - Empire exists' ); SELECT is( COUNT(*)::INT , 1 ) FROM emp.empires WHERE name_id = _get_emp_name( 'testEmp1' ); - SELECT diag_test_name( 'emp.create_empire() - Empire cash' ); + + SELECT diag_test_name( 'emp.create_empire() - Empire cash set' ); SELECT is( cash , 200.0::REAL ) FROM emp.empires WHERE name_id = _get_emp_name( 'testEmp1' ); - SELECT diag_test_name( 'emp.create_empire() - Empire debt' ); + + SELECT diag_test_name( 'emp.create_empire() - Empire debt set' ); SELECT is( debt , 0.0::REAL ) FROM emp.empires WHERE name_id = _get_emp_name( 'testEmp1' ); @@ -57,5 +92,11 @@ BEGIN; FROM emp.resources WHERE empire_id = _get_emp_name( 'testEmp1' ); + SELECT diag_test_name( 'emp.create_empire() - Resource mining has been updated' ); + SELECT is( pres_income::DOUBLE PRECISION , 42::DOUBLE PRECISION ) + FROM verse.planet_resources + WHERE planet_id = _get_map_name( 'testPlanet1' ) + AND resource_name_id = _get_string( 'natRes1' ); + SELECT * FROM finish( ); ROLLBACK; \ No newline at end of file diff --git a/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/010-gu-pmc-weights-view.sql b/legacyworlds-server-data/db-structure/tests/admin/040-functions/145-resource-providers/050-scaled-mining-weights-view.sql similarity index 76% rename from legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/010-gu-pmc-weights-view.sql rename to legacyworlds-server-data/db-structure/tests/admin/040-functions/145-resource-providers/050-scaled-mining-weights-view.sql index d32e62f..3ab6c0f 100644 --- a/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/010-gu-pmc-weights-view.sql +++ b/legacyworlds-server-data/db-structure/tests/admin/040-functions/145-resource-providers/050-scaled-mining-weights-view.sql @@ -1,5 +1,5 @@ /* - * Test sys.gu_pmc_weights_view + * Test emp.scaled_mining_weights_view */ BEGIN; /* Create a table which will server as an alternate source for @@ -28,14 +28,14 @@ BEGIN; /***** TESTS BEGIN HERE *****/ SELECT plan( 2 ); - SELECT diag_test_name( 'sys.gu_pmc_weights_view - Rows present' ); + SELECT diag_test_name( 'emp.scaled_mining_weights_view - Rows present' ); SELECT isnt( COUNT(*)::INT , 0 ) - FROM sys.gu_pmc_weights_view; + FROM emp.scaled_mining_weights_view; - SELECT diag_test_name( 'sys.gu_pmc_weights_view - weight = game.resources.weightBase ^ setting' ); + SELECT diag_test_name( 'emp.scaled_mining_weights_view - weight = game.resources.weightBase ^ setting' ); SELECT sys.uoc_constant( 'game.resources.weightBase' , '(test)' , 'Resources' , 10.0 ); SELECT is_empty( $$ - SELECT * FROM sys.gu_pmc_weights_view + SELECT * FROM emp.scaled_mining_weights_view WHERE pmc_weight IS NULL OR pmc_weight <> POW( 10 , resource_name_id ) $$ ); diff --git a/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/020-gu-pmc-totals-view.sql b/legacyworlds-server-data/db-structure/tests/admin/040-functions/145-resource-providers/060-total-mining-weights-view.sql similarity index 73% rename from legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/020-gu-pmc-totals-view.sql rename to legacyworlds-server-data/db-structure/tests/admin/040-functions/145-resource-providers/060-total-mining-weights-view.sql index e1cfa4c..91e6ef8 100644 --- a/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/020-gu-pmc-totals-view.sql +++ b/legacyworlds-server-data/db-structure/tests/admin/040-functions/145-resource-providers/060-total-mining-weights-view.sql @@ -1,9 +1,9 @@ /* - * Test sys.gu_pmc_totals_view + * Test emp.total_mining_weights_view */ BEGIN; /* Create a table which will server as an alternate source for - * sys.gu_pmc_weights_view ; the table is not temporary (PostgreSQL + * emp.scaled_mining_weights_view ; the table is not temporary (PostgreSQL * won't allow replacing the view otherwise), but will be dropped * on rollback anyway. */ @@ -13,7 +13,7 @@ BEGIN; pmc_weight DOUBLE PRECISION ); - CREATE OR REPLACE VIEW sys.gu_pmc_weights_view + CREATE OR REPLACE VIEW emp.scaled_mining_weights_view AS SELECT * FROM fake_mining_weights; /* Insert fake records for two different planets */ @@ -27,7 +27,7 @@ BEGIN; SELECT plan( 1 ); SELECT set_eq( - $$ SELECT * FROM sys.gu_pmc_totals_view $$ , + $$ SELECT * FROM emp.total_mining_weights_view $$ , $$ VALUES ( 1 , 3.0 ) , ( 2 , 9.0 ) $$ ); diff --git a/legacyworlds-server-data/db-structure/tests/admin/040-functions/145-resource-providers/070-mining-compute-extraction.sql b/legacyworlds-server-data/db-structure/tests/admin/040-functions/145-resource-providers/070-mining-compute-extraction.sql new file mode 100644 index 0000000..8748a59 --- /dev/null +++ b/legacyworlds-server-data/db-structure/tests/admin/040-functions/145-resource-providers/070-mining-compute-extraction.sql @@ -0,0 +1,135 @@ +/* + * Test the emp.mining_compute_extraction() function + */ +BEGIN; + + /* Define the necessary constant */ + SELECT sys.uoc_constant( 'game.resources.extraction' , '(test)' , 'Resources' , 10 ); + SELECT sys.uoc_constant( 'game.happiness.strike' , '(test)' , 'Resources' , 0.5 ); + + /* Make sure the functions are not immutable during the tests */ + ALTER FUNCTION sys.get_constant( TEXT ) VOLATILE; + ALTER FUNCTION emp.mining_compute_extraction( emp.planet_mining_type ) VOLATILE; + + /* Replace verse.get_raw_production() with a function that returns a + * value from a "temporary" table. + */ + CREATE TABLE fake_mining_production( production REAL ); + CREATE OR REPLACE FUNCTION verse.get_raw_production( pid INT , pt building_output_type ) + RETURNS REAL LANGUAGE SQL VOLATILE AS 'SELECT production FROM fake_mining_production'; + INSERT INTO fake_mining_production VALUES ( 100 ); + + /* Create a table that is used as the input for tests */ + CREATE TABLE tests_input OF emp.planet_mining_type; + + -- ***** TESTS BEGIN HERE ***** + SELECT plan( 9 ); + + INSERT INTO tests_input VALUES + ( 0 , 0 , 1000 , 1000 , 0 , NULL , NULL , NULL , NULL ) , + ( 1 , 1 , 10000 , 10000 , 0 , NULL , NULL , NULL , NULL ) , + ( 2 , 2 , 100000 , 100000 , 0 , NULL , NULL , NULL , NULL ); + + SELECT diag_test_name( 'emp.mining_compute_extraction() - No empire -> no extraction' ); + SELECT is_empty( $$ + SELECT * + FROM tests_input + WHERE emp.mining_compute_extraction( ROW( + planet , resource , quantity , quantity_max , + difficulty , empire , happiness , weight , + total_weight ) ) + <> 0 $$ ); + + DELETE FROM tests_input; + INSERT INTO tests_input VALUES + ( 0 , 0 , 1000 , 1000 , 0 , 1 , 1 , 1 , 1 ) , + ( 1 , 1 , 10000 , 10000 , 0 , 1 , 1 , 1 , 1 ) , + ( 2 , 2 , 100000 , 100000 , 0 , 1 , 1 , 1 , 1 ); + + SELECT diag_test_name( 'emp.mining_compute_extraction() - Extracted quantity > 0 if empire and resources are present' ); + SELECT is_empty( $$ + SELECT * + FROM tests_input + WHERE emp.mining_compute_extraction( ROW( + planet , resource , quantity , quantity_max , + difficulty , empire , happiness , weight , + total_weight ) ) + = 0 $$ ); + + SELECT diag_test_name( 'emp.mining_compute_extraction() - Extracted quantity does not change for same initial ratio' ); + SELECT is( COUNT( DISTINCT emp.mining_compute_extraction( ROW( + planet , resource , quantity , quantity_max , + difficulty , empire , happiness , weight , + total_weight ) ) + )::INT , 1 ) FROM tests_input; + + UPDATE tests_input SET weight = 1 + planet , total_weight = 3; + SELECT diag_test_name( 'emp.mining_compute_extraction() - Result increases when weight/total weight ratio increases' ); + SELECT set_eq( + $$ SELECT rank() OVER ( ORDER BY weight ) AS r1 , + rank() OVER( ORDER BY emp.mining_compute_extraction( ROW( + planet , resource , quantity , quantity_max , + difficulty , empire , happiness , weight , + total_weight ) ) ) AS r2 + FROM tests_input $$ , + $$ VALUES ( 1 , 1 ) , ( 2 , 2 ) , ( 3 , 3 ) $$ + ); + + UPDATE tests_input SET weight = total_weight , happiness = 0.5 + 0.25 * planet; + SELECT diag_test_name( 'emp.mining_compute_extraction() - Happiness does not affect result when greater than strike level' ); + SELECT is( COUNT( DISTINCT emp.mining_compute_extraction( ROW( + planet , resource , quantity , quantity_max , + difficulty , empire , happiness , weight , + total_weight ) ) + )::INT , 1 ) FROM tests_input; + + UPDATE tests_input SET weight = total_weight , happiness = 0.2 * planet; + SELECT diag_test_name( 'emp.mining_compute_extraction() - Result increases with happiness when lower than strike level' ); + SELECT set_eq( + $$ SELECT rank() OVER ( ORDER BY happiness ) AS r1 , + rank() OVER( ORDER BY emp.mining_compute_extraction( ROW( + planet , resource , quantity , quantity_max , + difficulty , empire , happiness , weight , + total_weight ) ) ) AS r2 + FROM tests_input $$ , + $$ VALUES ( 1 , 1 ) , ( 2 , 2 ) , ( 3 , 3 ) $$ + ); + + UPDATE fake_mining_production SET production = 10000; + UPDATE tests_input SET quantity = 1 , quantity_max = 1 , happiness = 1; + SELECT diag_test_name( 'emp.mining_compute_extraction() - Result <= quantity' ); + SELECT is_empty( + $$ SELECT * FROM tests_input + WHERE quantity < emp.mining_compute_extraction( ROW( + planet , resource , quantity , quantity_max , + difficulty , empire , happiness , weight , + total_weight ) ) $$ + ); + + UPDATE fake_mining_production SET production = 1; + UPDATE tests_input SET quantity = 100 * planet , quantity_max = 200; + SELECT diag_test_name( 'emp.mining_compute_extraction() - Result decreases when quantity/capacity ratio decreases' ); + SELECT set_eq( + $$ SELECT rank() OVER ( ORDER BY quantity ) AS r1 , + rank() OVER( ORDER BY emp.mining_compute_extraction( ROW( + planet , resource , quantity , quantity_max , + difficulty , empire , happiness , weight , + total_weight ) ) ) AS r2 + FROM tests_input $$ , + $$ VALUES ( 1 , 1 ) , ( 2 , 2 ) , ( 3 , 3 ) $$ + ); + + UPDATE tests_input SET quantity = quantity_max , difficulty = 0.33 * planet; + SELECT diag_test_name( 'emp.mining_compute_extraction() - Result decreases when difficulty increases' ); + SELECT set_eq( + $$ SELECT rank() OVER ( ORDER BY difficulty DESC ) AS r1 , + rank() OVER( ORDER BY emp.mining_compute_extraction( ROW( + planet , resource , quantity , quantity_max , + difficulty , empire , happiness , weight , + total_weight ) ) ) AS r2 + FROM tests_input $$ , + $$ VALUES ( 1 , 1 ) , ( 2 , 2 ) , ( 3 , 3 ) $$ + ); + + SELECT * FROM finish( ); +ROLLBACK; \ No newline at end of file diff --git a/legacyworlds-server-data/db-structure/tests/admin/040-functions/145-resource-providers/080-verse-mining-get-input.sql b/legacyworlds-server-data/db-structure/tests/admin/040-functions/145-resource-providers/080-verse-mining-get-input.sql new file mode 100644 index 0000000..89b9639 --- /dev/null +++ b/legacyworlds-server-data/db-structure/tests/admin/040-functions/145-resource-providers/080-verse-mining-get-input.sql @@ -0,0 +1,88 @@ +/* + * Tests for the verse.mining_get_input() function + */ +BEGIN; + \i utils/common-setup/setup-gu-pmc-get-data-test.sql + + SELECT plan( 9 ); + + SELECT diag_test_name( 'verse.mining_get_input() - Neutral planet without resource providers -> no rows' ); + SELECT is_empty( $$ SELECT * FROM verse.mining_get_input( _get_map_name( 'planet1' ) ) $$ ); + + CREATE TEMPORARY TABLE test_results + AS SELECT * FROM verse.mining_get_input( _get_map_name( 'planet2' ) ); + SELECT diag_test_name( 'verse.mining_get_input() - Neutral planet with resource providers - Rows included' ); + SELECT is( COUNT(*)::INT , 2) + FROM test_results + WHERE planet = _get_map_name ( 'planet2' ) + AND difficulty = 0.2 AND empire IS NULL + AND happiness IS NULL AND weight IS NULL + AND total_weight IS NULL; + SELECT diag_test_name( 'verse.mining_get_input() - Neutral planet with resource providers - No extra rows' ); + SELECT is_empty( $$ + SELECT * FROM test_results + WHERE NOT ( planet = _get_map_name ( 'planet2' ) + AND difficulty = 0.2 AND empire IS NULL + AND happiness IS NULL AND weight IS NULL + AND total_weight IS NULL ); + $$ ); + DROP TABLE test_results; + + CREATE TEMPORARY TABLE test_results + AS SELECT * FROM verse.mining_get_input( _get_map_name( 'planet3' ) ); + SELECT diag_test_name( 'verse.mining_get_input() - Planet using empire settings - Rows included' ); + SELECT is( COUNT(*)::INT , 2) + FROM test_results + WHERE planet = _get_map_name ( 'planet3' ) AND difficulty = 0.3 + AND empire = _get_emp_name( 'empire1' ) + AND happiness IS NOT NULL AND weight = 100 + AND total_weight = 200; + SELECT diag_test_name( 'verse.mining_get_input() - Planet using empire settings - No extra rows' ); + SELECT is_empty( $$ + SELECT * FROM test_results + WHERE NOT ( planet = _get_map_name ( 'planet3' ) + AND difficulty = 0.3 + AND empire = _get_emp_name( 'empire1' ) + AND happiness IS NOT NULL + AND weight = 100 AND total_weight = 200 ); + $$ ); + DROP TABLE test_results; + + CREATE TEMPORARY TABLE test_results + AS SELECT * FROM verse.mining_get_input( _get_map_name( 'planet4' ) ); + SELECT diag_test_name( 'verse.mining_get_input() - Planet using specific settings - Rows included' ); + SELECT is( COUNT(*)::INT , 2) + FROM test_results + WHERE planet = _get_map_name ( 'planet4' ) AND difficulty = 0.4 + AND empire = _get_emp_name( 'empire2' ) + AND happiness IS NOT NULL AND ( + ( resource = _get_string( 'resource1' ) AND weight = 10 ) + OR ( resource = _get_string( 'resource2' ) AND weight = 1000 ) ) + AND total_weight = 1010; + SELECT diag_test_name( 'verse.mining_get_input() - Planet using specific settings - No extra rows' ); + SELECT is_empty( $$ + SELECT * FROM test_results + WHERE NOT ( planet = _get_map_name ( 'planet4' ) + AND difficulty = 0.4 AND empire = _get_emp_name( 'empire2' ) + AND happiness IS NOT NULL AND total_weight = 1010 + AND ( ( resource = _get_string( 'resource1' ) AND weight = 10 ) + OR ( resource = _get_string( 'resource2' ) AND weight = 1000 ) ) ); + $$ ); + DROP TABLE test_results; + + SELECT diag_test_name( 'verse.mining_get_input() - Owned planet without resource providers -> no rows' ); + SELECT is_empty( $$ SELECT * FROM verse.mining_get_input( _get_map_name( 'planet5' ) ) $$ ); + + CREATE TEMPORARY TABLE test_results + AS SELECT * FROM verse.mining_get_input( _get_map_name( 'planet6' ) ); + SELECT diag_test_name( 'verse.mining_get_input() - Selects planets independently of update state' ); + SELECT is( COUNT(*)::INT , 2) + FROM test_results + WHERE planet = _get_map_name ( 'planet6' ) AND difficulty = 0.6 + AND empire = _get_emp_name( 'empire4' ) + AND happiness IS NOT NULL AND weight = 100 + AND total_weight = 200; + DROP TABLE test_results; + + SELECT * FROM finish( ); +ROLLBACK; \ No newline at end of file diff --git a/legacyworlds-server-data/db-structure/tests/admin/040-functions/145-resource-providers/090-emp-mining-get-input.sql b/legacyworlds-server-data/db-structure/tests/admin/040-functions/145-resource-providers/090-emp-mining-get-input.sql new file mode 100644 index 0000000..bc5736a --- /dev/null +++ b/legacyworlds-server-data/db-structure/tests/admin/040-functions/145-resource-providers/090-emp-mining-get-input.sql @@ -0,0 +1,69 @@ +/* + * Tests for the emp.mining_get_input() function + */ +BEGIN; + \i utils/common-setup/setup-gu-pmc-get-data-test.sql + + SELECT plan( 7 ); + + CREATE TEMPORARY TABLE test_results + AS SELECT * FROM emp.mining_get_input( _get_emp_name( 'empire1' ) ); + SELECT diag_test_name( 'emp.mining_get_input() - Empire with a planet using empire settings - Rows included' ); + SELECT is( COUNT(*)::INT , 2) + FROM test_results + WHERE planet = _get_map_name ( 'planet3' ) AND difficulty = 0.3 + AND empire = _get_emp_name( 'empire1' ) + AND happiness IS NOT NULL AND weight = 100 + AND total_weight = 200; + SELECT diag_test_name( 'emp.mining_get_input() - Empire with a planet using empire settings - No extra rows' ); + SELECT is_empty( $$ + SELECT * FROM test_results + WHERE NOT ( planet = _get_map_name ( 'planet3' ) + AND difficulty = 0.3 + AND empire = _get_emp_name( 'empire1' ) + AND happiness IS NOT NULL + AND weight = 100 AND total_weight = 200 ); + $$ ); + DROP TABLE test_results; + + CREATE TEMPORARY TABLE test_results + AS SELECT * FROM emp.mining_get_input( _get_emp_name( 'empire2' ) ); + SELECT diag_test_name( 'emp.mining_get_input() - Empire with a planet using specific settings - Rows included' ); + SELECT is( COUNT(*)::INT , 2) + FROM test_results + WHERE planet = _get_map_name ( 'planet4' ) AND difficulty = 0.4 + AND empire = _get_emp_name( 'empire2' ) + AND happiness IS NOT NULL AND ( + ( resource = _get_string( 'resource1' ) AND weight = 10 ) + OR ( resource = _get_string( 'resource2' ) AND weight = 1000 ) ) + AND total_weight = 1010; + SELECT diag_test_name( 'emp.mining_get_input() - Empire with a planet using specific settings - No extra rows' ); + SELECT is_empty( $$ + SELECT * FROM test_results + WHERE NOT ( planet = _get_map_name ( 'planet4' ) + AND difficulty = 0.4 AND empire = _get_emp_name( 'empire2' ) + AND happiness IS NOT NULL AND total_weight = 1010 + AND ( ( resource = _get_string( 'resource1' ) AND weight = 10 ) + OR ( resource = _get_string( 'resource2' ) AND weight = 1000 ) ) ); + $$ ); + DROP TABLE test_results; + + SELECT diag_test_name( 'emp.mining_get_input() - Owned planet without resource providers -> no rows' ); + SELECT is_empty( $$ SELECT * FROM emp.mining_get_input( _get_emp_name( 'empire3' ) ) $$ ); + + CREATE TEMPORARY TABLE test_results + AS SELECT * FROM emp.mining_get_input( _get_emp_name( 'empire4' ) ); + SELECT diag_test_name( 'emp.mining_get_input() - Selects planets independently of update state' ); + SELECT is( COUNT(*)::INT , 2) + FROM test_results + WHERE planet = _get_map_name ( 'planet6' ) AND difficulty = 0.6 + AND empire = _get_emp_name( 'empire4' ) + AND happiness IS NOT NULL AND weight = 100 + AND total_weight = 200; + DROP TABLE test_results; + + SELECT diag_test_name( 'emp.mining_get_input() - Empire with no planets -> no rows' ); + SELECT is_empty( $$ SELECT * FROM emp.mining_get_input( _get_emp_name( 'empire5' ) ) $$ ); + + SELECT * FROM finish( ); +ROLLBACK; \ No newline at end of file diff --git a/legacyworlds-server-data/db-structure/tests/admin/040-functions/045-empire-mining/010-mset-update-start.sql b/legacyworlds-server-data/db-structure/tests/admin/040-functions/147-empire-mining/010-mset-update-start.sql similarity index 100% rename from legacyworlds-server-data/db-structure/tests/admin/040-functions/045-empire-mining/010-mset-update-start.sql rename to legacyworlds-server-data/db-structure/tests/admin/040-functions/147-empire-mining/010-mset-update-start.sql diff --git a/legacyworlds-server-data/db-structure/tests/admin/040-functions/045-empire-mining/015-mset-update-start-planet.sql b/legacyworlds-server-data/db-structure/tests/admin/040-functions/147-empire-mining/015-mset-update-start-planet.sql similarity index 100% rename from legacyworlds-server-data/db-structure/tests/admin/040-functions/045-empire-mining/015-mset-update-start-planet.sql rename to legacyworlds-server-data/db-structure/tests/admin/040-functions/147-empire-mining/015-mset-update-start-planet.sql diff --git a/legacyworlds-server-data/db-structure/tests/admin/040-functions/045-empire-mining/020-mset-update-set.sql b/legacyworlds-server-data/db-structure/tests/admin/040-functions/147-empire-mining/020-mset-update-set.sql similarity index 100% rename from legacyworlds-server-data/db-structure/tests/admin/040-functions/045-empire-mining/020-mset-update-set.sql rename to legacyworlds-server-data/db-structure/tests/admin/040-functions/147-empire-mining/020-mset-update-set.sql diff --git a/legacyworlds-server-data/db-structure/tests/admin/040-functions/045-empire-mining/030-mset-update-apply.sql b/legacyworlds-server-data/db-structure/tests/admin/040-functions/147-empire-mining/030-mset-update-apply.sql similarity index 100% rename from legacyworlds-server-data/db-structure/tests/admin/040-functions/045-empire-mining/030-mset-update-apply.sql rename to legacyworlds-server-data/db-structure/tests/admin/040-functions/147-empire-mining/030-mset-update-apply.sql diff --git a/legacyworlds-server-data/db-structure/tests/admin/040-functions/045-empire-mining/040-mset-toggle-source.sql b/legacyworlds-server-data/db-structure/tests/admin/040-functions/147-empire-mining/040-mset-toggle-source.sql similarity index 100% rename from legacyworlds-server-data/db-structure/tests/admin/040-functions/045-empire-mining/040-mset-toggle-source.sql rename to legacyworlds-server-data/db-structure/tests/admin/040-functions/147-empire-mining/040-mset-toggle-source.sql diff --git a/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/030-gu-pmc-get-data.sql b/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/010-gu-pmc-get-data.sql similarity index 100% rename from legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/030-gu-pmc-get-data.sql rename to legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/010-gu-pmc-get-data.sql diff --git a/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/020-process-planet-mining-updates.sql b/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/020-process-planet-mining-updates.sql new file mode 100644 index 0000000..3aabf15 --- /dev/null +++ b/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/020-process-planet-mining-updates.sql @@ -0,0 +1,89 @@ +/* + * Test the sys.process_planet_mining_updates() function + */ +BEGIN; + /* Disable other update types */ + DELETE FROM sys.update_types + WHERE updtype_name <> 'PlanetMining'; + + /* We need two planets with identicals resource records and resource providers. */ + \i utils/strings.sql + \i utils/resources.sql + \i utils/accounts.sql + \i utils/naming.sql + \i utils/universe.sql + + SELECT _create_natural_resources( 1 , 'resource' ); + SELECT _create_raw_planets( 2 , 'planet' ); + + 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' ) , 100 , + 100 , 0.2 , 0.5 + ) , ( + _get_map_name( 'planet2' ) , _get_string( 'resource1' ) , 100 , + 100 , 0.2 , 0.5 + ); + + INSERT INTO verse.planet_resources ( planet_id , resource_name_id , pres_income , pres_upkeep ) + SELECT p.name_id , r.resource_name_id , 50 , 0 + FROM verse.planets p CROSS JOIN defs.resources r; + + /* First planet will be updated, second will not */ + UPDATE sys.updates su + SET update_state = 'PROCESSING' , update_last = 0 + FROM verse.planets_updates vu + WHERE vu.update_id = su.update_id + AND vu.name_id = _get_map_name( 'planet1' ); + UPDATE sys.updates su + SET update_state = 'PROCESSED' , update_last = 0 + FROM verse.planets_updates vu + WHERE vu.update_id = su.update_id + AND vu.name_id = _get_map_name( 'planet2' ); + + /* Replace sys.gu_pmc_get_data() and emp.mining_compute_extraction(); both + * functions will write to temporary tables. + */ + CREATE TABLE _get_data_calls( tick BIGINT ); + CREATE OR REPLACE FUNCTION sys.gu_pmc_get_data( _tick BIGINT ) + RETURNS SETOF emp.planet_mining_type LANGUAGE SQL + AS $$ + INSERT INTO _get_data_calls VALUES ( $1 ); + SELECT _get_map_name( 'planet1' ) AS planet , + _get_string( 'resource1' ) AS resource , + NULL::DOUBLE PRECISION AS quantity , NULL::DOUBLE PRECISION AS quantity_max , + NULL::DOUBLE PRECISION AS difficulty , NULL::INT AS empire , + NULL::REAL AS happiness , NULL::DOUBLE PRECISION AS weight , + NULL::DOUBLE PRECISION AS total_weight; + $$; + + CREATE OR REPLACE FUNCTION emp.mining_compute_extraction( _input emp.planet_mining_type ) + RETURNS DOUBLE PRECISION LANGUAGE SQL + AS $$ + SELECT 42::DOUBLE PRECISION; + $$; + + /***** TESTS BEGIN HERE *****/ + SELECT plan( 3 ); + + SELECT sys.process_planet_mining_updates( 0 ); + + SELECT diag_test_name( 'sys.process_planet_mining_updates() - Resource providers updated' ); + SELECT set_eq( + $$ SELECT planet_id , resprov_quantity FROM verse.resource_providers $$ , + $$ VALUES ( _get_map_name( 'planet1' ) , 50 ) , ( _get_map_name( 'planet2' ) , 100 ) $$ + ); + + SELECT diag_test_name( 'sys.process_planet_mining_updates() - Planet resources updated' ); + SELECT set_eq( + $$ SELECT planet_id , pres_income FROM verse.planet_resources $$ , + $$ VALUES ( _get_map_name( 'planet1' ) , 42 ) , ( _get_map_name( 'planet2' ) , 50 ) $$ + ); + + SELECT diag_test_name( 'sys.process_planet_mining_updates() - Two calls to gu_pmc_get_data()' ); + SELECT is( COUNT(*)::INT , 2 ) FROM _get_data_calls; + + SELECT * FROM finish( ); +ROLLBACK; diff --git a/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/040-gu-pmc-update-resource.sql b/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/040-gu-pmc-update-resource.sql deleted file mode 100644 index f25019f..0000000 --- a/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/040-gu-pmc-update-resource.sql +++ /dev/null @@ -1,91 +0,0 @@ -/* - * Test the sys.gu_pmc_update_resource() function - */ -BEGIN; - /* - * We need to create a set of both resource providers and planet resource - * records that will be updated by the function when it is called. We - * disable foreign keys on both tables, as it makes things simpler. We - * also replace verse.get_raw_production(), verse.get_extraction_factor( ) - * and verse.adjust_production() so that they return fixed values, and we - * need to set the game.resources.extraction constant. - */ - ALTER TABLE verse.resource_providers - DROP CONSTRAINT fk_resprov_planet , - DROP CONSTRAINT fk_resprov_resource; - ALTER TABLE verse.planet_resources - DROP CONSTRAINT fk_pres_planet , - DROP CONSTRAINT fk_pres_resource; - - INSERT INTO verse.resource_providers( - planet_id , resource_name_id , resprov_quantity_max, resprov_quantity , - resprov_difficulty , resprov_recovery - ) VALUES ( - 1 , 1 , 1000 , 1000 , 0 , 0.5 - ); - - INSERT INTO verse.planet_resources( - planet_id , resource_name_id , pres_income , pres_upkeep - ) VALUES ( - 1 , 1 , 0 , 0 - ); - - CREATE OR REPLACE FUNCTION verse.get_raw_production( pid INT , pt building_output_type ) - RETURNS REAL - AS $$ - SELECT 1.0::REAL; - $$ LANGUAGE SQL; - - CREATE OR REPLACE FUNCTION verse.adjust_production( prod REAL , happiness REAL ) - RETURNS REAL - AS $$ - SELECT 1.0::REAL; - $$ LANGUAGE SQL; - - CREATE OR REPLACE FUNCTION verse.get_extraction_factor( _fill_ratio DOUBLE PRECISION , _difficulty DOUBLE PRECISION ) - RETURNS DOUBLE PRECISION - AS $$ - SELECT ( CASE WHEN $1 = 1.0 AND $2 = 0 THEN 0.002 ELSE 0.0 END )::DOUBLE PRECISION; - $$ LANGUAGE SQL; - - SELECT sys.uoc_constant( 'game.resources.extraction' , '(test)' , 'Resources' , 1440.0 ); - ALTER FUNCTION sys.get_constant( TEXT ) VOLATILE; - - - /***** TESTS BEGIN HERE *****/ - SELECT plan( 4 ); - - SELECT sys.gu_pmc_update_resource( ROW( - 1 , 1 , 1000.0 , 1000.0 , 0.0 , NULL , 1.0 , 0.5 , 1.0 - ) ); - - SELECT diag_test_name( 'sys.gu_pmc_update_resource( ) - Provider udpated' ); - SELECT is( resprov_quantity , 999.999::DOUBLE PRECISION ) - FROM verse.resource_providers - WHERE planet_id = 1 AND resource_name_id = 1; - - SELECT diag_test_name( 'sys.gu_pmc_update_resource( ) - Planet resources income udpated' ); - SELECT is( pres_income , 0.001::DOUBLE PRECISION ) - FROM verse.planet_resources - WHERE planet_id = 1 AND resource_name_id = 1; - - UPDATE verse.resource_providers SET resprov_quantity = resprov_quantity_max; - UPDATE sys.constant_definitions - SET c_value = 14400000.0 - WHERE name = 'game.resources.extraction'; - SELECT sys.gu_pmc_update_resource( ROW( - 1 , 1 , 1000.0 , 1000.0 , 0.0 , NULL , 1.0 , 0.5 , 1.0 - ) ); - - SELECT diag_test_name( 'sys.gu_pmc_update_resource( ) - Bounded extraction quantity (1/2)' ); - SELECT is( resprov_quantity , 990.0::DOUBLE PRECISION ) - FROM verse.resource_providers - WHERE planet_id = 1 AND resource_name_id = 1; - - SELECT diag_test_name( 'sys.gu_pmc_update_resource( ) - Bounded extraction quantity (2/2)' ); - SELECT is( pres_income , 10.0::DOUBLE PRECISION ) - FROM verse.planet_resources - WHERE planet_id = 1 AND resource_name_id = 1; - - SELECT * FROM finish( ); -ROLLBACK; \ No newline at end of file diff --git a/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/050-process-planet-mining-updates.sql b/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/050-process-planet-mining-updates.sql deleted file mode 100644 index 19da05c..0000000 --- a/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/050-process-planet-mining-updates.sql +++ /dev/null @@ -1,58 +0,0 @@ -/* - * Test the sys.process_planet_mining_updates() function - */ -BEGIN; - /* - * Create a fake planet resource record which will be updated by the - * function (dropping the foreign key is therefore needed). - */ - 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 , 42 , 0 - ); - - /* - * Create a table which contains the values which will be returned by - * the fake sys.gu_pmc_get_data( ). - */ - CREATE TABLE _fake_update_data OF sys.gu_pmc_data_type; - INSERT INTO _fake_update_data VALUES ( - 1 , 1 , 1000.0 , 1000.0 , 0.5 , NULL , NULL , NULL , NULL ) , - ( 2 , 1 , 1000.0 , 1000.0 , 0.5 , 1 , 0.5 , 1.0 , 1.0 ); - CREATE OR REPLACE FUNCTION sys.gu_pmc_get_data( _tick BIGINT ) - RETURNS SETOF sys.gu_pmc_data_type - AS $$ - SELECT * FROM _fake_update_data; - $$ LANGUAGE SQL; - - /* - * Replace sys.gu_pmc_update_resource() so it deletes records from the - * table. - */ - CREATE OR REPLACE FUNCTION sys.gu_pmc_update_resource( _input sys.gu_pmc_data_type ) - RETURNS VOID - AS $$ - DELETE FROM _fake_update_data WHERE planet = $1.planet AND resource = $1.resource; - $$ LANGUAGE SQL; - - - /***** TESTS BEGIN HERE *****/ - SELECT plan( 2 ); - - SELECT sys.process_planet_mining_updates( 0 ); - - SELECT diag_test_name( 'sys.process_planet_mining_updates() - Neutral planets updated' ); - SELECT is( pres_income , 0::DOUBLE PRECISION ) FROM verse.planet_resources; - - SELECT diag_test_name( 'sys.process_planet_mining_updates() - Owned planets updated' ); - SELECT is_empty( - $$ SELECT * FROM _fake_update_data WHERE planet = 2 $$ - ); - - SELECT * FROM finish( ); -ROLLBACK; diff --git a/legacyworlds-server-data/db-structure/tests/user/040-functions/145-resource-providers/050-scaled-mining-weights-view.sql b/legacyworlds-server-data/db-structure/tests/user/040-functions/145-resource-providers/050-scaled-mining-weights-view.sql new file mode 100644 index 0000000..76f2b0e --- /dev/null +++ b/legacyworlds-server-data/db-structure/tests/user/040-functions/145-resource-providers/050-scaled-mining-weights-view.sql @@ -0,0 +1,11 @@ +/* + * Test privileges on emp.scaled_mining_weights_view + */ +BEGIN; + SELECT plan( 1 ); + + SELECT diag_test_name( 'emp.scaled_mining_weights_view - No SELECT privilege' ); + SELECT throws_ok( 'SELECT * FROM emp.scaled_mining_weights_view' , 42501 ); + + SELECT * FROM finish( ); +ROLLBACK; \ No newline at end of file diff --git a/legacyworlds-server-data/db-structure/tests/user/040-functions/145-resource-providers/060-total-mining-weights-view.sql b/legacyworlds-server-data/db-structure/tests/user/040-functions/145-resource-providers/060-total-mining-weights-view.sql new file mode 100644 index 0000000..5d0f0ae --- /dev/null +++ b/legacyworlds-server-data/db-structure/tests/user/040-functions/145-resource-providers/060-total-mining-weights-view.sql @@ -0,0 +1,11 @@ +/* + * Test privileges on emp.total_mining_weights_view + */ +BEGIN; + SELECT plan( 1 ); + + SELECT diag_test_name( 'emp.total_mining_weights_view - No SELECT privilege' ); + SELECT throws_ok( 'SELECT * FROM emp.total_mining_weights_view' , 42501 ); + + SELECT * FROM finish( ); +ROLLBACK; \ No newline at end of file diff --git a/legacyworlds-server-data/db-structure/tests/user/040-functions/145-resource-providers/070-mining-compute-extraction.sql b/legacyworlds-server-data/db-structure/tests/user/040-functions/145-resource-providers/070-mining-compute-extraction.sql new file mode 100644 index 0000000..64a95e3 --- /dev/null +++ b/legacyworlds-server-data/db-structure/tests/user/040-functions/145-resource-providers/070-mining-compute-extraction.sql @@ -0,0 +1,13 @@ +/* + * Test privileges on emp.mining_compute_extraction() + */ +BEGIN; + SELECT plan( 1 ); + + SELECT diag_test_name( 'emp.mining_compute_extraction() - No EXECUTE privilege' ); + SELECT throws_ok( $$ + SELECT emp.mining_compute_extraction( ROW( 1 , 2 , 3 , 4 , 5 , NULL , NULL , NULL , NULL ) ) + $$ , 42501 ); + + SELECT * FROM finish( ); +ROLLBACK; \ No newline at end of file diff --git a/legacyworlds-server-data/db-structure/tests/user/040-functions/145-resource-providers/080-verse-mining-get-input.sql b/legacyworlds-server-data/db-structure/tests/user/040-functions/145-resource-providers/080-verse-mining-get-input.sql new file mode 100644 index 0000000..95a1561 --- /dev/null +++ b/legacyworlds-server-data/db-structure/tests/user/040-functions/145-resource-providers/080-verse-mining-get-input.sql @@ -0,0 +1,13 @@ +/* + * Test privileges on verse.mining_get_input() + */ +BEGIN; + SELECT plan( 1 ); + + SELECT diag_test_name( 'verse.mining_get_input() - No EXECUTE privilege' ); + SELECT throws_ok( $$ + SELECT verse.mining_get_input( 1 ) + $$ , 42501 ); + + SELECT * FROM finish( ); +ROLLBACK; \ No newline at end of file diff --git a/legacyworlds-server-data/db-structure/tests/user/040-functions/145-resource-providers/090-emp-mining-get-input.sql b/legacyworlds-server-data/db-structure/tests/user/040-functions/145-resource-providers/090-emp-mining-get-input.sql new file mode 100644 index 0000000..ac77387 --- /dev/null +++ b/legacyworlds-server-data/db-structure/tests/user/040-functions/145-resource-providers/090-emp-mining-get-input.sql @@ -0,0 +1,13 @@ +/* + * Test privileges on emp.mining_get_input() + */ +BEGIN; + SELECT plan( 1 ); + + SELECT diag_test_name( 'emp.mining_get_input() - No EXECUTE privilege' ); + SELECT throws_ok( $$ + SELECT emp.mining_get_input( 1 ) + $$ , 42501 ); + + SELECT * FROM finish( ); +ROLLBACK; \ No newline at end of file diff --git a/legacyworlds-server-data/db-structure/tests/user/040-functions/045-empire-mining/010-mset-update-start.sql b/legacyworlds-server-data/db-structure/tests/user/040-functions/147-empire-mining/010-mset-update-start.sql similarity index 100% rename from legacyworlds-server-data/db-structure/tests/user/040-functions/045-empire-mining/010-mset-update-start.sql rename to legacyworlds-server-data/db-structure/tests/user/040-functions/147-empire-mining/010-mset-update-start.sql diff --git a/legacyworlds-server-data/db-structure/tests/user/040-functions/045-empire-mining/015-mset-update-start-planet.sql b/legacyworlds-server-data/db-structure/tests/user/040-functions/147-empire-mining/015-mset-update-start-planet.sql similarity index 100% rename from legacyworlds-server-data/db-structure/tests/user/040-functions/045-empire-mining/015-mset-update-start-planet.sql rename to legacyworlds-server-data/db-structure/tests/user/040-functions/147-empire-mining/015-mset-update-start-planet.sql diff --git a/legacyworlds-server-data/db-structure/tests/user/040-functions/045-empire-mining/020-mset-update-set.sql b/legacyworlds-server-data/db-structure/tests/user/040-functions/147-empire-mining/020-mset-update-set.sql similarity index 100% rename from legacyworlds-server-data/db-structure/tests/user/040-functions/045-empire-mining/020-mset-update-set.sql rename to legacyworlds-server-data/db-structure/tests/user/040-functions/147-empire-mining/020-mset-update-set.sql diff --git a/legacyworlds-server-data/db-structure/tests/user/040-functions/045-empire-mining/030-mset-update-apply.sql b/legacyworlds-server-data/db-structure/tests/user/040-functions/147-empire-mining/030-mset-update-apply.sql similarity index 100% rename from legacyworlds-server-data/db-structure/tests/user/040-functions/045-empire-mining/030-mset-update-apply.sql rename to legacyworlds-server-data/db-structure/tests/user/040-functions/147-empire-mining/030-mset-update-apply.sql diff --git a/legacyworlds-server-data/db-structure/tests/user/040-functions/045-empire-mining/040-mset-toggle-source.sql b/legacyworlds-server-data/db-structure/tests/user/040-functions/147-empire-mining/040-mset-toggle-source.sql similarity index 100% rename from legacyworlds-server-data/db-structure/tests/user/040-functions/045-empire-mining/040-mset-toggle-source.sql rename to legacyworlds-server-data/db-structure/tests/user/040-functions/147-empire-mining/040-mset-toggle-source.sql diff --git a/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/030-gu-pmc-get-data.sql b/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/010-gu-pmc-get-data.sql similarity index 100% rename from legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/030-gu-pmc-get-data.sql rename to legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/010-gu-pmc-get-data.sql diff --git a/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/010-gu-pmc-weights-view.sql b/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/010-gu-pmc-weights-view.sql deleted file mode 100644 index adb0975..0000000 --- a/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/010-gu-pmc-weights-view.sql +++ /dev/null @@ -1,11 +0,0 @@ -/* - * Test privileges on sys.gu_pmc_weights_view - */ -BEGIN; - SELECT plan( 1 ); - - SELECT diag_test_name( 'sys.gu_pmc_weights_view - Privileges' ); - SELECT throws_ok( 'SELECT * FROM sys.gu_pmc_weights_view' , 42501 ); - - SELECT * FROM finish( ); -ROLLBACK; \ No newline at end of file diff --git a/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/020-gu-pmc-totals-view.sql b/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/020-gu-pmc-totals-view.sql deleted file mode 100644 index f4d2b70..0000000 --- a/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/020-gu-pmc-totals-view.sql +++ /dev/null @@ -1,11 +0,0 @@ -/* - * Test privileges on sys.gu_pmc_totals_view - */ -BEGIN; - SELECT plan( 1 ); - - SELECT diag_test_name( 'sys.gu_pmc_totals_view - Privileges' ); - SELECT throws_ok( 'SELECT * FROM sys.gu_pmc_totals_view' , 42501 ); - - SELECT * FROM finish( ); -ROLLBACK; \ No newline at end of file diff --git a/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/050-process-planet-mining-updates.sql b/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/020-process-planet-mining-updates.sql similarity index 100% rename from legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/050-process-planet-mining-updates.sql rename to legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/020-process-planet-mining-updates.sql diff --git a/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/040-gu-pmc-update-resource.sql b/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/040-gu-pmc-update-resource.sql deleted file mode 100644 index 7de5605..0000000 --- a/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/040-gu-pmc-update-resource.sql +++ /dev/null @@ -1,13 +0,0 @@ -/* - * Test privileges on sys.gu_pmc_update_resource( ) - */ -BEGIN; - SELECT plan( 1 ); - - SELECT diag_test_name( 'sys.gu_pmc_update_resource - Privileges' ); - SELECT throws_ok( $$ - SELECT * FROM sys.gu_pmc_update_resource( ROW( NULL , NULL , NULL , NULL , NULL , NULL , NULL , NULL , NULL ) ); - $$ , 42501 ); - - SELECT * FROM finish( ); -ROLLBACK; \ No newline at end of file diff --git a/legacyworlds-server-data/db-structure/tests/utils/common-setup/setup-gu-pmc-get-data-test.sql b/legacyworlds-server-data/db-structure/tests/utils/common-setup/setup-gu-pmc-get-data-test.sql index 57d62d3..11bb7b4 100644 --- a/legacyworlds-server-data/db-structure/tests/utils/common-setup/setup-gu-pmc-get-data-test.sql +++ b/legacyworlds-server-data/db-structure/tests/utils/common-setup/setup-gu-pmc-get-data-test.sql @@ -37,7 +37,7 @@ DELETE FROM sys.update_types SELECT sys.uoc_constant( 'game.resources.weightBase' , '(test)' , 'Resources' , 10.0 ); SELECT _create_natural_resources( 2 , 'resource' ); SELECT _create_raw_planets( 6 , 'planet' ); -SELECT _create_emp_names( 4 , 'empire' ); +SELECT _create_emp_names( 5 , 'empire' ); INSERT INTO emp.empires ( name_id , cash ) SELECT id , 0 FROM naming.empire_names;