Research priorities
* Added stored procedures meant to update research priorities.
This commit is contained in:
parent
b15acadc1b
commit
1dcde71dff
7 changed files with 424 additions and 1 deletions
|
@ -195,6 +195,162 @@ REVOKE EXECUTE
|
||||||
FROM PUBLIC;
|
FROM PUBLIC;
|
||||||
|
|
||||||
|
|
||||||
|
/*
|
||||||
|
* Initialise a research priorities update
|
||||||
|
* ----------------------------------------
|
||||||
|
*
|
||||||
|
* This stored procedure prepares a temporary table which is used to update
|
||||||
|
* an empire's research priorities.
|
||||||
|
*
|
||||||
|
* Parameters:
|
||||||
|
* _empire The empire's identifier
|
||||||
|
*
|
||||||
|
* Returns:
|
||||||
|
* ? TRUE if the empire exists, is not on vacation mode and has
|
||||||
|
* in-progress research, FALSE otherwise.
|
||||||
|
*/
|
||||||
|
DROP FUNCTION IF EXISTS emp.resprio_update_start( INT );
|
||||||
|
CREATE FUNCTION emp.resprio_update_start( _empire INT )
|
||||||
|
RETURNS BOOLEAN
|
||||||
|
LANGUAGE PLPGSQL
|
||||||
|
STRICT VOLATILE
|
||||||
|
SECURITY DEFINER
|
||||||
|
AS $resprio_update_start$
|
||||||
|
BEGIN
|
||||||
|
|
||||||
|
-- Create temporary table
|
||||||
|
CREATE TEMPORARY TABLE rprio_update(
|
||||||
|
_empire_id INT ,
|
||||||
|
_technology_name_id INT ,
|
||||||
|
_emptech_id TEXT ,
|
||||||
|
_emptech_priority INT
|
||||||
|
) ON COMMIT DROP;
|
||||||
|
|
||||||
|
-- Lock records and fill table
|
||||||
|
INSERT INTO rprio_update (
|
||||||
|
_empire_id , _technology_name_id , _emptech_id , _emptech_priority
|
||||||
|
) SELECT _emp.name_id , _tech.technology_name_id ,
|
||||||
|
emp.technology_make_identifier( empire_id , _str.name , emptech_visible ) ,
|
||||||
|
_etech.emptech_priority
|
||||||
|
FROM emp.empires _emp
|
||||||
|
INNER JOIN emp.technologies_v2 _etech
|
||||||
|
ON _etech.empire_id = _emp.name_id
|
||||||
|
AND _etech.emptech_state = 'RESEARCH'
|
||||||
|
INNER JOIN defs.technologies _tech
|
||||||
|
USING ( technology_name_id )
|
||||||
|
INNER JOIN emp.technology_visibility_view _vis
|
||||||
|
USING ( empire_id , technology_name_id )
|
||||||
|
INNER JOIN defs.strings _str
|
||||||
|
ON _str.id = _tech.technology_name_id
|
||||||
|
INNER JOIN naming.empire_names _ename
|
||||||
|
ON _ename.id = _emp.name_id
|
||||||
|
LEFT OUTER JOIN users.vacations _vac
|
||||||
|
ON _vac.account_id = _ename.owner_id
|
||||||
|
AND _vac.status = 'PROCESSED'
|
||||||
|
WHERE _emp.name_id = _empire AND _vac.account_id IS NULL
|
||||||
|
FOR UPDATE OF _emp , _etech
|
||||||
|
FOR SHARE OF _tech , _str , _ename;
|
||||||
|
|
||||||
|
RETURN FOUND;
|
||||||
|
END;
|
||||||
|
$resprio_update_start$;
|
||||||
|
|
||||||
|
REVOKE EXECUTE
|
||||||
|
ON FUNCTION emp.resprio_update_start( INT )
|
||||||
|
FROM PUBLIC;
|
||||||
|
|
||||||
|
GRANT EXECUTE
|
||||||
|
ON FUNCTION emp.resprio_update_start( INT )
|
||||||
|
TO :dbuser;
|
||||||
|
|
||||||
|
|
||||||
|
/*
|
||||||
|
* Set the priority of some research
|
||||||
|
* ----------------------------------
|
||||||
|
*
|
||||||
|
* This stored procedure updates the priority of some in-progress empire
|
||||||
|
* research. It will only function correctly if emp.resprio_update_start() was
|
||||||
|
* already executed.
|
||||||
|
*
|
||||||
|
* Parameters:
|
||||||
|
* _technology The client-side identifier of the technology, as
|
||||||
|
* returned by emp.technology_make_identifier()
|
||||||
|
* _priority The priority to assign to the technology
|
||||||
|
*
|
||||||
|
* Returns:
|
||||||
|
* ? TRUE if the technology was found, FALSE if it wasn't.
|
||||||
|
*/
|
||||||
|
DROP FUNCTION IF EXISTS emp.resprio_update_set( TEXT , INT );
|
||||||
|
CREATE FUNCTION emp.resprio_update_set( _technology TEXT , _priority INT )
|
||||||
|
RETURNS BOOLEAN
|
||||||
|
LANGUAGE PLPGSQL
|
||||||
|
STRICT VOLATILE
|
||||||
|
SECURITY DEFINER
|
||||||
|
AS $resprio_update_set$
|
||||||
|
BEGIN
|
||||||
|
|
||||||
|
UPDATE rprio_update
|
||||||
|
SET _emptech_priority = _priority
|
||||||
|
WHERE _emptech_id = _technology;
|
||||||
|
RETURN FOUND;
|
||||||
|
|
||||||
|
END;
|
||||||
|
$resprio_update_set$;
|
||||||
|
|
||||||
|
REVOKE EXECUTE
|
||||||
|
ON FUNCTION emp.resprio_update_set( TEXT , INT )
|
||||||
|
FROM PUBLIC;
|
||||||
|
|
||||||
|
GRANT EXECUTE
|
||||||
|
ON FUNCTION emp.resprio_update_set( TEXT , INT )
|
||||||
|
TO :dbuser;
|
||||||
|
|
||||||
|
|
||||||
|
/*
|
||||||
|
* Apply an update to research priorities
|
||||||
|
* ---------------------------------------
|
||||||
|
*
|
||||||
|
* This stored procedure applies changes listed in the temporary research
|
||||||
|
* priority table by updating the actual table with the new values.
|
||||||
|
*
|
||||||
|
* Returns:
|
||||||
|
* ? TRUE if the update was valid, FALSE if one of the updated
|
||||||
|
* values was incorrect
|
||||||
|
*/
|
||||||
|
DROP FUNCTION IF EXISTS emp.resprio_update_apply( );
|
||||||
|
CREATE FUNCTION emp.resprio_update_apply( )
|
||||||
|
RETURNS BOOLEAN
|
||||||
|
LANGUAGE PLPGSQL
|
||||||
|
STRICT VOLATILE
|
||||||
|
SECURITY DEFINER
|
||||||
|
AS $resprio_update_apply$
|
||||||
|
BEGIN
|
||||||
|
|
||||||
|
UPDATE emp.technologies_v2
|
||||||
|
SET emptech_priority = _emptech_priority
|
||||||
|
FROM rprio_update
|
||||||
|
WHERE _empire_id = empire_id
|
||||||
|
AND _technology_name_id = technology_name_id;
|
||||||
|
RETURN TRUE;
|
||||||
|
|
||||||
|
EXCEPTION
|
||||||
|
|
||||||
|
WHEN check_violation THEN
|
||||||
|
RETURN FALSE;
|
||||||
|
|
||||||
|
END;
|
||||||
|
$resprio_update_apply$;
|
||||||
|
|
||||||
|
REVOKE EXECUTE
|
||||||
|
ON FUNCTION emp.resprio_update_apply( )
|
||||||
|
FROM PUBLIC;
|
||||||
|
|
||||||
|
GRANT EXECUTE
|
||||||
|
ON FUNCTION emp.resprio_update_apply( )
|
||||||
|
TO :dbuser;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
--
|
--
|
||||||
-- Returns a planet owner's empire size
|
-- Returns a planet owner's empire size
|
||||||
--
|
--
|
||||||
|
@ -1041,4 +1197,4 @@ CREATE VIEW emp.technologies_v2_view
|
||||||
|
|
||||||
GRANT SELECT
|
GRANT SELECT
|
||||||
ON emp.technologies_v2_view
|
ON emp.technologies_v2_view
|
||||||
TO :dbuser;
|
TO :dbuser;
|
||||||
|
|
|
@ -0,0 +1,105 @@
|
||||||
|
/*
|
||||||
|
* Unit tests for emp.resprio_update_start()
|
||||||
|
*/
|
||||||
|
BEGIN;
|
||||||
|
\i utils/strings.sql
|
||||||
|
\i utils/accounts.sql
|
||||||
|
\i utils/naming.sql
|
||||||
|
|
||||||
|
/* Create two empires */
|
||||||
|
SELECT _create_emp_names( 2 , 'emp' );
|
||||||
|
INSERT INTO emp.empires ( name_id , cash )
|
||||||
|
SELECT id , 200.0 FROM naming.empire_names;
|
||||||
|
|
||||||
|
/* Create 3 technologies after disabling unused fields */
|
||||||
|
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_price DROP NOT NULL ,
|
||||||
|
ALTER technology_points DROP NOT NULL;
|
||||||
|
SELECT _create_test_strings( 3 , 'tech' );
|
||||||
|
INSERT INTO defs.technologies ( technology_name_id )
|
||||||
|
VALUES ( _get_string( 'tech1' ) ) ,
|
||||||
|
( _get_string( 'tech2' ) ) ,
|
||||||
|
( _get_string( 'tech3' ) );
|
||||||
|
|
||||||
|
/* Replace identifier function with something easier to check */
|
||||||
|
CREATE OR REPLACE FUNCTION emp.technology_make_identifier(
|
||||||
|
_empire INT , _technology TEXT , _visible BOOLEAN )
|
||||||
|
RETURNS TEXT
|
||||||
|
LANGUAGE SQL
|
||||||
|
STRICT IMMUTABLE
|
||||||
|
SECURITY DEFINER
|
||||||
|
AS $technology_make_identifier$
|
||||||
|
SELECT $1::TEXT || ',' || $2 || ',' || $3::TEXT;
|
||||||
|
$technology_make_identifier$;
|
||||||
|
|
||||||
|
/* Replace the visibility view with plain SELECT's from a table.
|
||||||
|
*/
|
||||||
|
CREATE TABLE _fake_visibility(
|
||||||
|
empire_id INT ,
|
||||||
|
technology_name_id INT ,
|
||||||
|
emptech_visible BOOLEAN
|
||||||
|
);
|
||||||
|
CREATE OR REPLACE VIEW emp.technology_visibility_view
|
||||||
|
AS SELECT * FROM _fake_visibility;
|
||||||
|
|
||||||
|
/* Insert empire state and data for fake views */
|
||||||
|
INSERT INTO emp.technologies_v2 (
|
||||||
|
empire_id , technology_name_id ,
|
||||||
|
emptech_state , emptech_points , emptech_priority
|
||||||
|
) VALUES (
|
||||||
|
_get_emp_name( 'emp1' ) , _get_string( 'tech1' ) ,
|
||||||
|
'KNOWN' , NULL , NULL
|
||||||
|
) , (
|
||||||
|
_get_emp_name( 'emp1' ) , _get_string( 'tech2' ) ,
|
||||||
|
'RESEARCH' , 123 , 0
|
||||||
|
) , (
|
||||||
|
_get_emp_name( 'emp1' ) , _get_string( 'tech3' ) ,
|
||||||
|
'RESEARCH' , 123 , 1
|
||||||
|
);
|
||||||
|
INSERT INTO _fake_visibility VALUES(
|
||||||
|
_get_emp_name( 'emp1' ) , _get_string( 'tech1' ) , TRUE
|
||||||
|
) , (
|
||||||
|
_get_emp_name( 'emp1' ) , _get_string( 'tech2' ) , TRUE
|
||||||
|
) , (
|
||||||
|
_get_emp_name( 'emp1' ) , _get_string( 'tech3' ) , FALSE
|
||||||
|
);
|
||||||
|
|
||||||
|
-- ***** TESTS BEGIN HERE *****
|
||||||
|
SELECT plan( 9 );
|
||||||
|
|
||||||
|
SELECT diag_test_name( 'emp.resprio_update_start() - Invalid empire - Return value' );
|
||||||
|
SELECT ok( NOT emp.resprio_update_start( _get_bad_emp_name() ) );
|
||||||
|
SELECT diag_test_name( 'emp.resprio_update_start() - Invalid empire - Temporary table exists' );
|
||||||
|
SELECT has_table( 'rprio_update' );
|
||||||
|
SELECT diag_test_name( 'emp.resprio_update_start() - Invalid empire - Temporary table is empty' );
|
||||||
|
SELECT is_empty( $$ SELECT * FROM rprio_update $$ );
|
||||||
|
DROP TABLE IF EXISTS rprio_update;
|
||||||
|
|
||||||
|
SELECT diag_test_name( 'emp.resprio_update_start() - Empire with no research - Return value' );
|
||||||
|
SELECT ok( NOT emp.resprio_update_start( _get_emp_name( 'emp2' ) ) );
|
||||||
|
SELECT diag_test_name( 'emp.resprio_update_start() - Empire with no research - Temporary table exists' );
|
||||||
|
SELECT has_table( 'rprio_update' );
|
||||||
|
SELECT diag_test_name( 'emp.resprio_update_start() - Empire with no research - Temporary table is empty' );
|
||||||
|
SELECT is_empty( $$ SELECT * FROM rprio_update $$ );
|
||||||
|
DROP TABLE IF EXISTS rprio_update;
|
||||||
|
|
||||||
|
SELECT diag_test_name( 'emp.resprio_update_start() - Empire with in-progress research - Return value' );
|
||||||
|
SELECT ok( emp.resprio_update_start( _get_emp_name( 'emp1' ) ) );
|
||||||
|
SELECT diag_test_name( 'emp.resprio_update_start() - Empire with in-progress research - Temporary table exists' );
|
||||||
|
SELECT has_table( 'rprio_update' );
|
||||||
|
SELECT diag_test_name( 'emp.resprio_update_start() - Empire with in-progress research - Temporary table contents' );
|
||||||
|
SELECT set_eq( $$
|
||||||
|
SELECT _empire_id , _technology_name_id , _emptech_id , _emptech_priority
|
||||||
|
FROM rprio_update
|
||||||
|
$$ , $$ VALUES(
|
||||||
|
_get_emp_name( 'emp1' ) , _get_string( 'tech2' ) , _get_emp_name( 'emp1' ) || ',tech2,true' , 0
|
||||||
|
) , (
|
||||||
|
_get_emp_name( 'emp1' ) , _get_string( 'tech3' ) , _get_emp_name( 'emp1' ) || ',tech3,false' , 1
|
||||||
|
) $$ );
|
||||||
|
DROP TABLE IF EXISTS rprio_update;
|
||||||
|
|
||||||
|
SELECT * FROM finish( );
|
||||||
|
ROLLBACK;
|
|
@ -0,0 +1,37 @@
|
||||||
|
/*
|
||||||
|
* Unit tests for emp.resprio_update_set( )
|
||||||
|
*/
|
||||||
|
BEGIN;
|
||||||
|
/* Create a fake temporary table and insert some values */
|
||||||
|
CREATE TEMPORARY TABLE rprio_update(
|
||||||
|
_empire_id INT ,
|
||||||
|
_technology_name_id INT ,
|
||||||
|
_emptech_id TEXT ,
|
||||||
|
_emptech_priority INT
|
||||||
|
) ON COMMIT DROP;
|
||||||
|
INSERT INTO rprio_update
|
||||||
|
VALUES ( 1 , 1 , 'test' , 2 );
|
||||||
|
|
||||||
|
-- ***** TESTS BEGIN HERE *****
|
||||||
|
SELECT plan( 4 );
|
||||||
|
|
||||||
|
SELECT diag_test_name( 'emp.resprio_update_set() - Using a bad identifier - Return value' );
|
||||||
|
SELECT ok( NOT emp.resprio_update_set( 'bad identifier' , 3 ) );
|
||||||
|
SELECT diag_test_name( 'emp.resprio_update_set() - Using a bad identifier - Table contents' );
|
||||||
|
SELECT set_eq( $$
|
||||||
|
SELECT * FROM rprio_update
|
||||||
|
$$ , $$ VALUES(
|
||||||
|
1 , 1 , 'test' , 2
|
||||||
|
) $$ );
|
||||||
|
|
||||||
|
SELECT diag_test_name( 'emp.resprio_update_set() - Using a valid identifier - Return value' );
|
||||||
|
SELECT ok( emp.resprio_update_set( 'test' , 3 ) );
|
||||||
|
SELECT diag_test_name( 'emp.resprio_update_set() - Using a bad identifier - Table contents' );
|
||||||
|
SELECT set_eq( $$
|
||||||
|
SELECT * FROM rprio_update
|
||||||
|
$$ , $$ VALUES(
|
||||||
|
1 , 1 , 'test' , 3
|
||||||
|
) $$ );
|
||||||
|
|
||||||
|
SELECT * FROM finish( );
|
||||||
|
ROLLBACK;
|
|
@ -0,0 +1,82 @@
|
||||||
|
/*
|
||||||
|
* Unit tests for emp.resprio_update_apply()
|
||||||
|
*/
|
||||||
|
BEGIN;
|
||||||
|
\i utils/strings.sql
|
||||||
|
\i utils/accounts.sql
|
||||||
|
\i utils/naming.sql
|
||||||
|
|
||||||
|
/* Create a pair of empires, a technology, and some empire
|
||||||
|
* research & technology records.
|
||||||
|
*/
|
||||||
|
SELECT _create_emp_names( 2 , 'emp' );
|
||||||
|
INSERT INTO emp.empires ( name_id , cash )
|
||||||
|
SELECT id , 200.0 FROM naming.empire_names;
|
||||||
|
|
||||||
|
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_price DROP NOT NULL ,
|
||||||
|
ALTER technology_points DROP NOT NULL;
|
||||||
|
SELECT _create_test_strings( 1 , 'tech' );
|
||||||
|
INSERT INTO defs.technologies ( technology_name_id )
|
||||||
|
VALUES ( _get_string( 'tech1' ) );
|
||||||
|
|
||||||
|
INSERT INTO emp.technologies_v2(
|
||||||
|
empire_id , technology_name_id ,
|
||||||
|
emptech_state , emptech_points , emptech_priority
|
||||||
|
) VALUES (
|
||||||
|
_get_emp_name( 'emp1' ) , _get_string( 'tech1' ) ,
|
||||||
|
'RESEARCH' , 12 , 2
|
||||||
|
) , (
|
||||||
|
_get_emp_name( 'emp2' ) , _get_string( 'tech1' ) ,
|
||||||
|
'RESEARCH' , 12 , 2
|
||||||
|
);
|
||||||
|
|
||||||
|
/* Create a fake temporary table */
|
||||||
|
CREATE TEMPORARY TABLE rprio_update(
|
||||||
|
_empire_id INT ,
|
||||||
|
_technology_name_id INT ,
|
||||||
|
_emptech_id TEXT ,
|
||||||
|
_emptech_priority INT
|
||||||
|
) ON COMMIT DROP;
|
||||||
|
|
||||||
|
-- ***** TESTS BEGIN HERE *****
|
||||||
|
SELECT plan( 4 );
|
||||||
|
|
||||||
|
INSERT INTO rprio_update
|
||||||
|
VALUES ( _get_emp_name( 'emp1' ) , _get_string( 'tech1' ) , 'ignored' , 1 );
|
||||||
|
SELECT diag_test_name( 'emp.resprio_update_apply() - Applying a valid update - Return value' );
|
||||||
|
SELECT ok( emp.resprio_update_apply( ) );
|
||||||
|
SELECT diag_test_name( 'emp.resprio_update_apply() - Applying a valid update - Table contents' );
|
||||||
|
SELECT set_eq( $$
|
||||||
|
SELECT empire_id , emptech_priority
|
||||||
|
FROM emp.technologies_v2
|
||||||
|
WHERE technology_name_id = _get_string( 'tech1' );
|
||||||
|
$$ , $$ VALUES(
|
||||||
|
_get_emp_name( 'emp1' ) , 1
|
||||||
|
) , (
|
||||||
|
_get_emp_name( 'emp2' ) , 2
|
||||||
|
) $$ );
|
||||||
|
DELETE FROM rprio_update;
|
||||||
|
UPDATE emp.technologies_v2
|
||||||
|
SET emptech_priority = 2
|
||||||
|
WHERE technology_name_id = _get_string( 'tech1' );
|
||||||
|
|
||||||
|
INSERT INTO rprio_update
|
||||||
|
VALUES ( _get_emp_name( 'emp1' ) , _get_string( 'tech1' ) , 'ignored' , 15 );
|
||||||
|
SELECT diag_test_name( 'emp.resprio_update_apply() - Applying an invalid update - Return value' );
|
||||||
|
SELECT ok( NOT emp.resprio_update_apply( ) );
|
||||||
|
SELECT diag_test_name( 'emp.resprio_update_apply() - Applying an invalid update - Table contents' );
|
||||||
|
SELECT set_eq( $$
|
||||||
|
SELECT empire_id , emptech_priority
|
||||||
|
FROM emp.technologies_v2
|
||||||
|
$$ , $$ VALUES(
|
||||||
|
_get_emp_name( 'emp1' ) , 2
|
||||||
|
) , (
|
||||||
|
_get_emp_name( 'emp2' ) , 2
|
||||||
|
) $$ );
|
||||||
|
|
||||||
|
SELECT * FROM finish( );
|
||||||
|
ROLLBACK;
|
|
@ -0,0 +1,13 @@
|
||||||
|
/*
|
||||||
|
* Test privileges on emp.resprio_update_start()
|
||||||
|
*/
|
||||||
|
BEGIN;
|
||||||
|
SELECT plan( 1 );
|
||||||
|
|
||||||
|
SELECT diag_test_name( 'emp.resprio_update_start() - EXECUTE privilege' );
|
||||||
|
SELECT lives_ok( $$
|
||||||
|
SELECT emp.resprio_update_start( 1 );
|
||||||
|
$$ );
|
||||||
|
|
||||||
|
SELECT * FROM finish( );
|
||||||
|
ROLLBACK;
|
|
@ -0,0 +1,15 @@
|
||||||
|
/*
|
||||||
|
* Test privileges on emp.resprio_update_set()
|
||||||
|
*/
|
||||||
|
BEGIN;
|
||||||
|
SELECT emp.resprio_update_start( 1 );
|
||||||
|
|
||||||
|
SELECT plan( 1 );
|
||||||
|
|
||||||
|
SELECT diag_test_name( 'emp.resprio_update_set() - EXECUTE privilege' );
|
||||||
|
SELECT lives_ok( $$
|
||||||
|
SELECT emp.resprio_update_set( '' , 1 );
|
||||||
|
$$ );
|
||||||
|
|
||||||
|
SELECT * FROM finish( );
|
||||||
|
ROLLBACK;
|
|
@ -0,0 +1,15 @@
|
||||||
|
/*
|
||||||
|
* Test privileges on emp.resprio_update_apply()
|
||||||
|
*/
|
||||||
|
BEGIN;
|
||||||
|
SELECT emp.resprio_update_start( 1 );
|
||||||
|
|
||||||
|
SELECT plan( 1 );
|
||||||
|
|
||||||
|
SELECT diag_test_name( 'emp.resprio_update_apply() - EXECUTE privilege' );
|
||||||
|
SELECT lives_ok( $$
|
||||||
|
SELECT emp.resprio_update_apply( );
|
||||||
|
$$ );
|
||||||
|
|
||||||
|
SELECT * FROM finish( );
|
||||||
|
ROLLBACK;
|
Reference in a new issue