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
legacyworlds-server-data/db-structure/parts/040-functions

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;