Empire technology views

* Added new research-related constants

* Added set of views and functions to list empires' technologies. This
includes a view which determines the visibility of an in-progress
research's details, and a main list view.
This commit is contained in:
Emmanuel BENOîT 2012-03-01 09:50:20 +01:00
parent e01eab9c09
commit b15acadc1b
8 changed files with 476 additions and 0 deletions

View file

@ -126,6 +126,21 @@ public class ConstantsRegistrarBean
cDesc = "Proportion of queue investments that is recovered when flushing the queue.";
defs.add( new ConstantDefinition( wcNames[ 7 ] , cat , cDesc , 0.1 , 0.01 , 1.0 ) );
// Research
String[] rcNames = {
"basePoints" , "visibility.points" , "visibility.ratio"
};
for ( int i = 0 ; i < wcNames.length ; i++ ) {
rcNames[ i ] = "game.research." + rcNames[ i ];
}
cat = "Research & technologies";
cDesc = "Research points per population unit.";
defs.add( new ConstantDefinition( rcNames[ 0 ] , cat , cDesc , 0.50 , 0.01 , true ) );
cDesc = "Points above which a technology becomes visible.";
defs.add( new ConstantDefinition( rcNames[ 1 ] , cat , cDesc , 2500.0 , 0.01 , true ) );
cDesc = "Completion ratio above which a technology becomes visible.";
defs.add( new ConstantDefinition( rcNames[ 2 ] , cat , cDesc , 0.10 , 0.01 , 0.99 ) );
// Vacation mode
cDesc = "Initial vacation credits.";
defs.add( new ConstantDefinition( "vacation.initial" , "Vacation mode" , cDesc , 4320.0 , 0.0 , true ) );

View file

@ -154,6 +154,46 @@ GRANT EXECUTE
TO :dbuser;
/*
* Compute a technology identifier
* --------------------------------
*
* This function returns the identifier of a technology as seen from the
* player's side. The identifier is either the string identifier for the
* technology's name, or a MD5 hash including both the empire's identifier
* and the string identifier for "unknown" technologies.
*
* Parameters:
* _empire The empire's identifier
* _technology The technology's string identifier
* _visible TRUE if the technology is supposed to be visible, FALSE
* otherwise
*
* Returns:
* ? The technology's client-side identifier
*/
DROP FUNCTION IF EXISTS emp.technology_make_identifier( INT , TEXT , BOOLEAN );
CREATE FUNCTION emp.technology_make_identifier(
_empire INT , _technology TEXT , _visible BOOLEAN )
RETURNS TEXT
LANGUAGE SQL
STRICT IMMUTABLE
SECURITY DEFINER
AS $technology_make_identifier$
SELECT ( CASE
WHEN $3 THEN
$2
ELSE
md5( $1::TEXT || ' (making hash less obvious) ' || $2 )
END );
$technology_make_identifier$;
REVOKE EXECUTE
ON FUNCTION emp.technology_make_identifier( INT , TEXT , BOOLEAN )
FROM PUBLIC;
--
-- Returns a planet owner's empire size
@ -878,3 +918,127 @@ CREATE VIEW emp.resources_view
GRANT SELECT
ON emp.resources_view
TO :dbuser;
/*
* Technology visibility view
* ---------------------------
*
* This view can be used to determine whether entries from empires' research
* and technologies table are fully visible or only displayed as "unknown
* technologies".
*
* Columns:
* empire_id The empire's identifier
* technology_name_id The technology's identifier
* emptech_visible TRUE if the technology's details are visible,
* FALSE if they should be hidden
*/
DROP VIEW IF EXISTS emp.technology_visibility_view CASCADE;
CREATE VIEW emp.technology_visibility_view
AS SELECT empire_id , technology_name_id ,
( emptech_state <> 'RESEARCH'
OR emptech_points >= sys.get_constant( 'game.research.visibility.points' )
OR emptech_points / technology_points::DOUBLE PRECISION >= sys.get_constant( 'game.research.visibility.ratio' )
) AS emptech_visible
FROM emp.technologies_v2
INNER JOIN defs.technologies
USING ( technology_name_id );
/*
* Empire research and technologies
* ---------------------------------
*
* This view lists empires' research and technologies, along with their
* current state.
*
* Columns:
* empire_id The empire's identifier
* emptech_id An identifier for the technology, which is either
* the string identifier of the technology's name
* or a MD5 hash if the technology is not
* supposed to be visible
* emptech_state The state of the technology, straight from the
* empire technology table
* emptech_visible Whether the technology is supposed to be visible
* or not
* technology_category The string identifier of the technology's category
* technology_name The string identifier of the technology's name,
* or NULL if the technology is not supposed to
* be visible
* technology_description The string identifier of the technology's name,
* or NULL if the technology is not supposed
* to be visible
* emptech_points The amount of points accumulated while researching
* the technology, or NULL if the technology is
* not supposed to be visible
* emptech_priority The current research priority, or NULL if the
* technology is no longer being researched
* emptech_ratio The percentage of points accumulated while
* researching the technology, or NULL if the
* technology is no longer being researched
* technology_price The monetary price of the technology, or NULL if
* the technology is not supposed to be visible
* technology_dependencies The technology's dependencies from the
* dependencies view
*/
DROP VIEW IF EXISTS emp.technologies_v2_view CASCADE;
CREATE VIEW emp.technologies_v2_view
AS SELECT empire_id ,
emp.technology_make_identifier( empire_id , _name_str.name , emptech_visible ) AS emptech_id ,
emptech_state ,
emptech_visible ,
_cat_str.name AS technology_category ,
( CASE
WHEN emptech_visible THEN
_name_str.name
ELSE
NULL::TEXT
END ) AS technology_name ,
( CASE
WHEN emptech_visible THEN
_descr_str.name
ELSE
NULL::TEXT
END ) AS technology_description ,
( CASE
WHEN emptech_state <> 'RESEARCH' then
technology_points
WHEN emptech_visible THEN
FLOOR( emptech_points )::BIGINT
ELSE
NULL::BIGINT
END ) AS emptech_points ,
emptech_priority ,
( CASE
WHEN emptech_state = 'RESEARCH' THEN
FLOOR( 100.0 * emptech_points / technology_points::DOUBLE PRECISION )::INT
ELSE
NULL::INT
END ) AS emptech_ratio ,
( CASE
WHEN emptech_visible THEN
technology_price
ELSE
NULL::INT
END ) AS technology_price ,
technology_dependencies
FROM emp.technologies_v2
INNER JOIN emp.technology_visibility_view
USING ( technology_name_id , empire_id )
INNER JOIN defs.technologies _tech
USING ( technology_name_id )
INNER JOIN defs.technology_dependencies_view
USING ( technology_name_id )
INNER JOIN defs.strings _name_str
ON _name_str.id = _tech.technology_name_id
INNER JOIN defs.strings _cat_str
ON _cat_str.id = _tech.technology_category_id
INNER JOIN defs.strings _descr_str
ON _descr_str.id = _tech.technology_description_id;
GRANT SELECT
ON emp.technologies_v2_view
TO :dbuser;

View file

@ -0,0 +1,17 @@
/*
* Unit tests for emp.technology_make_identifier()
*/
BEGIN;
SELECT no_plan( );
SELECT diag_test_name( 'emp.technology_make_identifier() - Identifier of visible technologies' );
SELECT is( emp.technology_make_identifier( 1 , 'test-string' , TRUE ) , 'test-string' );
SELECT diag_test_name( 'emp.technology_make_identifier() - Identifier of unknown technologies - 32 characters' );
SELECT is( length( emp.technology_make_identifier( 1 , 'test-string' , FALSE ) ) , 32 );
SELECT diag_test_name( 'emp.technology_make_identifier() - Identifier of unknown technologies - Contains hex value' );
SELECT ok( emp.technology_make_identifier( 1 , 'test-string' , FALSE ) !~ '[^a-f0-9]' );
SELECT * FROM finish( );
ROLLBACK;

View file

@ -0,0 +1,111 @@
/*
* Unit tests for emp.technology_visibility_view
*/
BEGIN;
\i utils/strings.sql
\i utils/accounts.sql
\i utils/naming.sql
/* Create a single empire */
SELECT _create_emp_names( 1 , 'emp' );
INSERT INTO emp.empires ( name_id , cash )
VALUES ( _get_emp_name( 'emp1' ) , 200 );
/*
* Set visibility thresholds to either 50% or 100 points.
*/
SELECT sys.uoc_constant( 'game.research.visibility.points' , '(test)' , 'Test' , 100.0 );
SELECT sys.uoc_constant( 'game.research.visibility.ratio' , '(test)' , 'Test' , 0.5 );
/* Create 6 technology definitions that will be used to test various
* states: pending, known, 4 variants of research in progress (points
* and ratio below thresholds, points below threshold, ratio below
* threshold, both points and ratio above thresholds).
*
* Disable all unused fields from the definition table.
*/
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;
SELECT _create_test_strings( 6 , 'tech' );
INSERT INTO defs.technologies( technology_name_id , technology_points )
VALUES ( _get_string( 'tech1' ) , 100 ) ,
( _get_string( 'tech2' ) , 100 ) ,
( _get_string( 'tech3' ) , 100 ) ,
( _get_string( 'tech4' ) , 100 ) ,
( _get_string( 'tech5' ) , 1000 ) ,
( _get_string( 'tech6' ) , 1000 );
/* Insert empire state */
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' ) ,
'PENDING' , NULL , NULL
) , (
_get_emp_name( 'emp1' ) , _get_string( 'tech3' ) ,
'RESEARCH' , 10.0 , 2
) , (
_get_emp_name( 'emp1' ) , _get_string( 'tech4' ) ,
'RESEARCH' , 51.0 , 2
) , (
_get_emp_name( 'emp1' ) , _get_string( 'tech5' ) ,
'RESEARCH' , 101.0 , 2
) , (
_get_emp_name( 'emp1' ) , _get_string( 'tech6' ) ,
'RESEARCH' , 501.0 , 2
);
-- ***** TESTS BEGIN HERE *****
SELECT plan( 7 );
SELECT diag_test_name( 'emp.technology_visibility_view - All technologies are listed' );
SELECT is( COUNT( * )::INT , 6 )
FROM emp.technology_visibility_view
WHERE empire_id = _get_emp_name( 'emp1' );
SELECT diag_test_name( 'emp.technology_visibility_view - Known technologies are visible' );
SELECT ok( emptech_visible )
FROM emp.technology_visibility_view
WHERE technology_name_id = _get_string( 'tech1' )
AND empire_id = _get_emp_name( 'emp1' );
SELECT diag_test_name( 'emp.technology_visibility_view - Pending technologies are visible' );
SELECT ok( emptech_visible )
FROM emp.technology_visibility_view
WHERE technology_name_id = _get_string( 'tech2' )
AND empire_id = _get_emp_name( 'emp1' );
SELECT diag_test_name( 'emp.technology_visibility_view - In-progress technologies with both points and ratios below thresholds are not visible' );
SELECT ok( NOT emptech_visible )
FROM emp.technology_visibility_view
WHERE technology_name_id = _get_string( 'tech3' )
AND empire_id = _get_emp_name( 'emp1' );
SELECT diag_test_name( 'emp.technology_visibility_view - In-progress technologies with points below threshold are visible' );
SELECT ok( emptech_visible )
FROM emp.technology_visibility_view
WHERE technology_name_id = _get_string( 'tech4' )
AND empire_id = _get_emp_name( 'emp1' );
SELECT diag_test_name( 'emp.technology_visibility_view - In-progress technologies with ratio below threshold are visible' );
SELECT ok( emptech_visible )
FROM emp.technology_visibility_view
WHERE technology_name_id = _get_string( 'tech5' )
AND empire_id = _get_emp_name( 'emp1' );
SELECT diag_test_name( 'emp.technology_visibility_view - In-progress technologies with both points and ratios above threshold are visible' );
SELECT ok( emptech_visible )
FROM emp.technology_visibility_view
WHERE technology_name_id = _get_string( 'tech6' )
AND empire_id = _get_emp_name( 'emp1' );
SELECT * FROM finish( );
ROLLBACK;

View file

@ -0,0 +1,125 @@
/*
* Unit tests for emp.technologies_v2_view
*/
BEGIN;
\i utils/strings.sql
\i utils/accounts.sql
\i utils/naming.sql
/* Create three empires (easier to use as keys) */
SELECT _create_emp_names( 3 , 'emp' );
INSERT INTO emp.empires ( name_id , cash )
SELECT id , 200.0 FROM naming.empire_names;
/* Create a technology after disabling unused fields */
ALTER TABLE defs.technologies
ALTER technology_discovery_id DROP NOT NULL;
SELECT _create_test_strings( 1 , 'tech' );
SELECT _create_test_strings( 1 , 'techCategory' );
SELECT _create_test_strings( 1 , 'techDescription' );
INSERT INTO defs.technologies (
technology_name_id , technology_category_id , technology_description_id ,
technology_price , technology_points
) VALUES (
_get_string( 'tech1' ) , _get_string( 'techCategory1' ) , _get_string( 'techDescription1' ) ,
123 , 456
);
/* 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 both the visibility and dependencies views with plain SELECT's
* from tables.
*/
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;
CREATE TABLE _fake_deps(
technology_name_id INT ,
technology_dependencies TEXT
);
CREATE OR REPLACE VIEW defs.technology_dependencies_view
AS SELECT * FROM _fake_deps;
/* Insert empire states 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( 'emp2' ) , _get_string( 'tech1' ) ,
'RESEARCH' , 228.9 , 0
) , (
_get_emp_name( 'emp3' ) , _get_string( 'tech1' ) ,
'RESEARCH' , 114 , 1
);
INSERT INTO _fake_visibility VALUES(
_get_emp_name( 'emp1' ) , _get_string( 'tech1' ) , TRUE
) , (
_get_emp_name( 'emp2' ) , _get_string( 'tech1' ) , TRUE
) , (
_get_emp_name( 'emp3' ) , _get_string( 'tech1' ) , FALSE
);
INSERT INTO _fake_deps VALUES( _get_string( 'tech1' ) , 'deps are here' );
-- ***** TESTS BEGIN HERE *****
SELECT plan( 3 );
SELECT diag_test_name( 'emp.technologies_v2_view - Known technology' );
SELECT set_eq( $$
SELECT emptech_id , emptech_state::TEXT , emptech_visible ,
technology_category , technology_name , technology_description ,
emptech_points , emptech_priority IS NULL AS ep_null ,
emptech_ratio IS NULL AS er_null ,
technology_price , technology_dependencies
FROM emp.technologies_v2_view
WHERE empire_id = _get_emp_name( 'emp1' )
$$ , $$ VALUES(
_get_emp_name( 'emp1' ) || ',tech1,true' , 'KNOWN' , TRUE ,
'techCategory1' , 'tech1' , 'techDescription1' ,
456 , TRUE , TRUE , 123 , 'deps are here'
) $$ );
SELECT diag_test_name( 'emp.technologies_v2_view - In-progress, visible technology' );
SELECT set_eq( $$
SELECT emptech_id , emptech_state::TEXT , emptech_visible ,
technology_category , technology_name , technology_description ,
emptech_points , emptech_priority , emptech_ratio ,
technology_price , technology_dependencies
FROM emp.technologies_v2_view
WHERE empire_id = _get_emp_name( 'emp2' )
$$ , $$ VALUES(
_get_emp_name( 'emp2' ) || ',tech1,true' , 'RESEARCH' , TRUE ,
'techCategory1' , 'tech1' , 'techDescription1' ,
228 , 0 , 50 , 123 , 'deps are here'
) $$ );
SELECT diag_test_name( 'emp.technologies_v2_view - In-progress, unknown technology' );
SELECT set_eq( $$
SELECT emptech_id , emptech_state::TEXT , emptech_visible ,
technology_category , technology_name IS NULL AS n1 , technology_description IS NULL AS n2 ,
emptech_points IS NULL AS n3 , emptech_priority , emptech_ratio ,
technology_price IS NULL AS n4, technology_dependencies
FROM emp.technologies_v2_view
WHERE empire_id = _get_emp_name( 'emp3' )
$$ , $$ VALUES(
_get_emp_name( 'emp3' ) || ',tech1,false' , 'RESEARCH' , FALSE ,
'techCategory1' , TRUE, TRUE ,
TRUE , 1 , 25 , TRUE , 'deps are here'
) $$ );
SELECT * FROM finish( );
ROLLBACK;

View file

@ -0,0 +1,14 @@
/*
* Test privileges on emp.technology_make_identifier()
*/
BEGIN;
SELECT plan( 1 );
SELECT diag_test_name( 'emp.technology_make_identifier() - No EXECUTE privilege' );
SELECT throws_ok( $$
SELECT emp.technology_make_identifier( 1 , '' , FALSE );
$$ , 42501 );
SELECT * FROM finish( );
ROLLBACK;

View file

@ -0,0 +1,15 @@
/*
* Test privileges on emp.technology_visibility_view
*/
BEGIN;
\i utils/strings.sql
SELECT plan( 1 );
SELECT diag_test_name( 'emp.technology_visibility_view - No SELECT privilege' );
SELECT throws_ok( $$
SELECT * FROM emp.technology_visibility_view;
$$ , 42501 );
SELECT * FROM finish( );
ROLLBACK;

View file

@ -0,0 +1,15 @@
/*
* Test privileges on emp.technologies_v2_view
*/
BEGIN;
\i utils/strings.sql
SELECT plan( 1 );
SELECT diag_test_name( 'emp.technologies_v2_view - SELECT privilege' );
SELECT lives_ok( $$
SELECT * FROM emp.technologies_v2_view;
$$ );
SELECT * FROM finish( );
ROLLBACK;