From f4e38e49435d21f27545db28fa544af114cdd8d4 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Emmanuel=20Beno=C3=AEt?= Date: Tue, 28 Feb 2012 16:15:02 +0100 Subject: [PATCH] Technology implementation * A stored procedure which implements technologies has been added. It will mark a pending technology as implemented and remove the corresponding quantity of money from the empire, then add any newly available research items to the empire's research. --- .../parts/040-functions/040-empire.sql | 88 +++++++++++++- .../040-empire/015-technology-implement.sql | 110 ++++++++++++++++++ .../040-empire/015-technology-implement.sql | 13 +++ 3 files changed, 210 insertions(+), 1 deletion(-) create mode 100644 legacyworlds-server-data/db-structure/tests/admin/040-functions/040-empire/015-technology-implement.sql create mode 100644 legacyworlds-server-data/db-structure/tests/user/040-functions/040-empire/015-technology-implement.sql 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 1c1defa..bc4e640 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 @@ -68,6 +68,92 @@ REVOKE EXECUTE FROM PUBLIC; +/* + * Implements a technology + * ------------------------ + * + * This stored procedure is called when an empire attempts to implement a + * technology. It will check the empire's resources and the technology itself, + * then mark it as implemented if necessary. It will also add new research + * entries if necessary. + * + * Parameters: + * _empire The empire's identifier + * _technology The string identifier for the technology to implement + */ +DROP FUNCTION emp.technology_implement( INT , TEXT ); +CREATE FUNCTION emp.technology_implement( _empire INT , _technology TEXT ) + RETURNS BOOLEAN + LANGUAGE PLPGSQL + STRICT VOLATILE + SECURITY DEFINER + AS $technology_implement$ + +DECLARE + _impl_data RECORD; + +BEGIN + + -- Access and lock the records + SELECT INTO _impl_data + technology_name_id , technology_price + FROM emp.empires _emp + INNER JOIN emp.technologies_v2 _tech + ON _tech.empire_id = _emp.name_id + INNER JOIN defs.technologies _def + USING ( technology_name_id ) + INNER JOIN defs.strings _name + ON _def.technology_name_id = _name.id + WHERE _emp.name_id = _empire + AND _name.name = _technology + AND _tech.emptech_state = 'PENDING' + AND _emp.cash >= _def.technology_price + FOR UPDATE OF _emp , _tech + FOR SHARE OF _def; + IF NOT FOUND THEN + RETURN FALSE; + END IF; + + -- Implement the technology + UPDATE emp.empires + SET cash = cash - _impl_data.technology_price + WHERE name_id = _empire; + UPDATE emp.technologies_v2 + SET emptech_state = 'KNOWN' + WHERE empire_id = _empire + AND technology_name_id = _impl_data.technology_name_id; + + -- Insert new research + INSERT INTO emp.technologies_v2 ( empire_id , technology_name_id ) + SELECT _empire , _valid.technology_name_id + FROM ( SELECT _tech.technology_name_id , + ( COUNT(*) = COUNT(_emptech.emptech_state) ) AS emptech_has_dependencies + FROM defs.technologies _tech + INNER JOIN defs.technology_dependencies _deps + USING ( technology_name_id ) + LEFT OUTER JOIN emp.technologies_v2 _emptech + ON _emptech.technology_name_id = _deps.technology_name_id_depends + AND _emptech.emptech_state = 'KNOWN' + AND _emptech.empire_id = _empire + GROUP BY _tech.technology_name_id ) _valid + LEFT OUTER JOIN emp.technologies_v2 _emptech + ON _emptech.empire_id = _empire + AND _emptech.technology_name_id = _valid.technology_name_id + WHERE _emptech.empire_id IS NULL AND _valid.emptech_has_dependencies; + + RETURN TRUE; +END; +$technology_implement$; + +REVOKE EXECUTE + ON FUNCTION emp.technology_implement( INT , TEXT ) + FROM PUBLIC; + +GRANT EXECUTE + ON FUNCTION emp.technology_implement( INT , TEXT ) + TO :dbuser; + + -- -- Returns a planet owner's empire size @@ -107,7 +193,7 @@ GRANT EXECUTE ON FUNCTION emp.get_current( INT ) TO :dbuser; -- --- Implements a technology +-- Implements a technology (OLD VERSION) -- CREATE OR REPLACE FUNCTION emp.implement_tech( e_id INT , l_id INT ) diff --git a/legacyworlds-server-data/db-structure/tests/admin/040-functions/040-empire/015-technology-implement.sql b/legacyworlds-server-data/db-structure/tests/admin/040-functions/040-empire/015-technology-implement.sql new file mode 100644 index 0000000..8479524 --- /dev/null +++ b/legacyworlds-server-data/db-structure/tests/admin/040-functions/040-empire/015-technology-implement.sql @@ -0,0 +1,110 @@ +/* + * Unit tests for emp.technology_implement() + */ +BEGIN; + \i utils/strings.sql + \i utils/resources.sql + \i utils/accounts.sql + \i utils/naming.sql + \i utils/universe.sql + + /* + * Create empires + */ + SELECT _create_emp_names( 4 , 'emp' ); + INSERT INTO emp.empires ( name_id , cash ) + SELECT id , 200 FROM naming.empire_names; + + /* + * We also need 3 technologies (tech1, tech2 and tech3), and some + * dependencies between them: tech3 -> {tech2, tech1}). Disabling + * unused fields in defs.technologies makes things easier. + */ + ALTER TABLE defs.technologies + ALTER technology_category_id DROP NOT NULL , + ALTER technology_discovery_id DROP NOT NULL , + ALTER technology_description_id DROP NOT NULL , + ALTER technology_points DROP NOT NULL; + SELECT _create_test_strings( 3 , 'tech' ); + INSERT INTO defs.technologies ( technology_name_id , technology_price ) + VALUES ( _get_string( 'tech1' ) , 200 ) , + ( _get_string( 'tech2' ) , 200 ) , + ( _get_string( 'tech3' ) , 300 ); + INSERT INTO defs.technology_dependencies( + technology_name_id , technology_name_id_depends + ) VALUES ( _get_string( 'tech3' ) , _get_string( 'tech1' ) ) , + ( _get_string( 'tech3' ) , _get_string( 'tech2' ) ); + + /* Empire "emp1" has only in-progress research. */ + INSERT INTO emp.technologies_v2 ( empire_id , technology_name_id ) + VALUES( _get_emp_name( 'emp1' ) , _get_string( 'tech1' ) ); + + /* Empire "emp2" has a pending technology. */ + INSERT INTO emp.technologies_v2 ( empire_id , technology_name_id , emptech_state , emptech_points , emptech_priority ) + VALUES( _get_emp_name( 'emp2' ) , _get_string( 'tech1' ) , 'PENDING' , NULL , NULL ); + + /* Empire "emp3" has implemented 'tech1' and has 'tech2' as pending. */ + INSERT INTO emp.technologies_v2 ( empire_id , technology_name_id , emptech_state , emptech_points , emptech_priority ) + VALUES( _get_emp_name( 'emp3' ) , _get_string( 'tech1' ) , 'KNOWN' , NULL , NULL ) , + ( _get_emp_name( 'emp3' ) , _get_string( 'tech2' ) , 'PENDING' , NULL , NULL ); + + /* Empire "emp4" has implemented 'tech1' and 'tech2' and has 'tech3' as pending. */ + INSERT INTO emp.technologies_v2 ( empire_id , technology_name_id , emptech_state , emptech_points , emptech_priority ) + VALUES( _get_emp_name( 'emp4' ) , _get_string( 'tech1' ) , 'KNOWN' , NULL , NULL ) , + ( _get_emp_name( 'emp4' ) , _get_string( 'tech2' ) , 'KNOWN' , NULL , NULL ) , + ( _get_emp_name( 'emp4' ) , _get_string( 'tech3' ) , 'PENDING' , NULL , NULL ); + + -- ***** TESTS BEGIN HERE ***** + SELECT plan( 10 ); + + SELECT diag_test_name( 'emp.technology_implement() - Call on in-progress research' ); + SELECT ok( NOT emp.technology_implement( _get_emp_name( 'emp1' ) , 'tech1' ) ); + + SELECT diag_test_name( 'emp.technology_implement() - Call on unknown technology' ); + SELECT ok( NOT emp.technology_implement( _get_emp_name( 'emp1' ) , 'tech2' ) ); + + SELECT diag_test_name( 'emp.technology_implement() - Call on implemented technology' ); + SELECT ok( NOT emp.technology_implement( _get_emp_name( 'emp3' ) , 'tech1' ) ); + + SELECT diag_test_name( 'emp.technology_implement() - Call on pending technology - No new research - Return value' ); + SELECT ok( emp.technology_implement( _get_emp_name( 'emp2' ) , 'tech1' ) ); + + SELECT diag_test_name( 'emp.technology_implement() - Call on pending technology - No new research - Table contents' ); + SELECT set_eq( $$ + SELECT technology_name_id , emptech_state::TEXT + FROM emp.technologies_v2 + WHERE empire_id = _get_emp_name( 'emp2' ) + $$ , $$ VALUES( + _get_string( 'tech1' ) , 'KNOWN' + ) $$ ); + + SELECT diag_test_name( 'emp.technology_implement() - Call on pending technology - No new research - Empire cash' ); + SELECT is( cash , 0.0::REAL ) FROM emp.empires + WHERE name_id = _get_emp_name( 'emp2' ); + + SELECT diag_test_name( 'emp.technology_implement() - Call on pending technology - New research - Return value' ); + SELECT ok( emp.technology_implement( _get_emp_name( 'emp3' ) , 'tech2' ) ); + + SELECT diag_test_name( 'emp.technology_implement() - Call on pending technology - New research - Table contents' ); + SELECT set_eq( $$ + SELECT technology_name_id , emptech_state::TEXT + FROM emp.technologies_v2 + WHERE empire_id = _get_emp_name( 'emp3' ) + $$ , $$ VALUES( + _get_string( 'tech1' ) , 'KNOWN' + ) , ( + _get_string( 'tech2' ) , 'KNOWN' + ) , ( + _get_string( 'tech3' ) , 'RESEARCH' + ) $$ ); + + SELECT diag_test_name( 'emp.technology_implement() - Call on pending technology - New research - Empire cash' ); + SELECT is( cash , 0.0::REAL ) FROM emp.empires + WHERE name_id = _get_emp_name( 'emp3' ); + + + SELECT diag_test_name( 'emp.technology_implement() - Call on pending technology when empire cash is too low' ); + SELECT ok( NOT emp.technology_implement( _get_emp_name( 'emp4' ) , 'tech3' ) ); + + SELECT * FROM finish( ); +ROLLBACK; \ No newline at end of file diff --git a/legacyworlds-server-data/db-structure/tests/user/040-functions/040-empire/015-technology-implement.sql b/legacyworlds-server-data/db-structure/tests/user/040-functions/040-empire/015-technology-implement.sql new file mode 100644 index 0000000..57097ce --- /dev/null +++ b/legacyworlds-server-data/db-structure/tests/user/040-functions/040-empire/015-technology-implement.sql @@ -0,0 +1,13 @@ +/* + * Test privileges on emp.technology_implement() + */ +BEGIN; + SELECT plan( 1 ); + + SELECT diag_test_name( 'emp.technology_implement() - EXECUTE privilege' ); + SELECT lives_ok( $$ + SELECT emp.technology_implement( 1 , '' ); + $$ ); + + SELECT * FROM finish( ); +ROLLBACK; \ No newline at end of file