Technology definition functions
* Added stored procedures which manipulate technology definitions themselves (defs.uoc_technology) or their dependencies (defs.techdep_add and defs.techdep_remove)
This commit is contained in:
parent
3b2ec4bb64
commit
af57e7d3b5
10 changed files with 704 additions and 2 deletions
|
@ -32,11 +32,11 @@ CREATE TABLE defs.technologies(
|
|||
technology_description_id INT NOT NULL ,
|
||||
|
||||
/* Monetary price of the technology - FIXME: will be removed later */
|
||||
technology_price INT NOT NULL
|
||||
technology_price BIGINT NOT NULL
|
||||
CHECK( technology_price > 0 ) ,
|
||||
|
||||
/* Cost of the technology in terms of research points */
|
||||
technology_points INT NOT NULL
|
||||
technology_points BIGINT NOT NULL
|
||||
CHECK( technology_points > 0 )
|
||||
);
|
||||
|
||||
|
|
|
@ -7,6 +7,327 @@
|
|||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
/*
|
||||
* Return type for technology management functions
|
||||
* ------------------------------------------------
|
||||
*
|
||||
* This enumerated type is used for the return values of all technology
|
||||
* management functions. This includes defs.uoc_technology() of course,
|
||||
* but also defs.techdep_add() and defs.techdep_remove().
|
||||
*/
|
||||
DROP TYPE IF EXISTS defs.technology_update_result CASCADE;
|
||||
CREATE TYPE defs.technology_update_result
|
||||
AS ENUM(
|
||||
/* The technology definition or dependency was created */
|
||||
'CREATED' ,
|
||||
|
||||
/* The technology definition was updated */
|
||||
'UPDATED' ,
|
||||
|
||||
/* The dependency was deleted */
|
||||
'DELETED' ,
|
||||
|
||||
/* The specified dependency does not exist */
|
||||
'MISSING' ,
|
||||
|
||||
/* One (or more) of the numeric parameters is invalid */
|
||||
'BAD_VALUE' ,
|
||||
|
||||
/* The name, description, discovery or category string identifiers
|
||||
* were not valid string identifiers.
|
||||
*/
|
||||
'BAD_STRINGS' ,
|
||||
|
||||
/* The specified description and/or discovery string was in use by
|
||||
* another technology.
|
||||
*/
|
||||
'DUP_STRING' ,
|
||||
|
||||
/* The dependency would cause a cycle */
|
||||
'CYCLE' ,
|
||||
|
||||
/* The dependency would be redundant */
|
||||
'REDUNDANT'
|
||||
);
|
||||
|
||||
|
||||
/*
|
||||
* Update or create a technology definition
|
||||
* -----------------------------------------
|
||||
*
|
||||
* This stored procedure can be used to update existing technology definitions
|
||||
* or create new records. It will not affect technology dependencies: no
|
||||
* depedencies will be added when creating a new technology, and existing
|
||||
* dependencies will be conserved when updating.
|
||||
*
|
||||
* If a technology already exists, check for empires researching that
|
||||
* technology, and scale their current progress accordingly.
|
||||
*
|
||||
* Parameters:
|
||||
* _name Text identifier of the name string
|
||||
* _category Text identifier of the category string
|
||||
* _discovery Text identifier of the discovery string
|
||||
* _description Text identifier of the description string
|
||||
* _price Monetary cost to implement the technology
|
||||
* _points Amount of points required to research teh technology
|
||||
*
|
||||
* Returns:
|
||||
* ? One of the following return codes: CREATED, UPDATED,
|
||||
* BAD_VALUE, BAD_STRINGS, DUP_STRING
|
||||
*/
|
||||
DROP FUNCTION IF EXISTS defs.uoc_technology(
|
||||
TEXT , TEXT , TEXT , TEXT , BIGINT , BIGINT ) CASCADE;
|
||||
CREATE FUNCTION defs.uoc_technology(
|
||||
_name TEXT ,
|
||||
_category TEXT ,
|
||||
_discovery TEXT ,
|
||||
_description TEXT ,
|
||||
_price BIGINT ,
|
||||
_points BIGINT )
|
||||
RETURNS defs.technology_update_result
|
||||
LANGUAGE PLPGSQL
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $uoc_technology$
|
||||
|
||||
DECLARE
|
||||
_name_id INT;
|
||||
_disc_id INT;
|
||||
_desc_id INT;
|
||||
_cat_id INT;
|
||||
_old_points BIGINT;
|
||||
_multi DOUBLE PRECISION;
|
||||
|
||||
BEGIN
|
||||
-- Get all string identifiers
|
||||
SELECT INTO _name_id id FROM defs.strings WHERE name = _name;
|
||||
IF NOT FOUND THEN
|
||||
RETURN 'BAD_STRINGS';
|
||||
END IF;
|
||||
SELECT INTO _desc_id id FROM defs.strings WHERE name = _description;
|
||||
IF NOT FOUND THEN
|
||||
RETURN 'BAD_STRINGS';
|
||||
END IF;
|
||||
SELECT INTO _disc_id id FROM defs.strings WHERE name = _discovery;
|
||||
IF NOT FOUND THEN
|
||||
RETURN 'BAD_STRINGS';
|
||||
END IF;
|
||||
SELECT INTO _cat_id id FROM defs.strings WHERE name = _category;
|
||||
IF NOT FOUND THEN
|
||||
RETURN 'BAD_STRINGS';
|
||||
END IF;
|
||||
|
||||
-- Try inserting the record
|
||||
BEGIN
|
||||
INSERT INTO defs.technologies (
|
||||
technology_name_id , technology_category_id ,
|
||||
technology_discovery_id , technology_description_id ,
|
||||
technology_price , technology_points
|
||||
) VALUES (
|
||||
_name_id , _cat_id ,
|
||||
_disc_id , _desc_id ,
|
||||
_price , _points
|
||||
);
|
||||
RETURN 'CREATED';
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
-- Continue, we can't determine which error this
|
||||
-- was about at this point.
|
||||
END;
|
||||
|
||||
-- Lock existing definition and empire research records
|
||||
PERFORM 1
|
||||
FROM defs.technologies _def
|
||||
LEFT OUTER JOIN (
|
||||
SELECT technology_name_id
|
||||
FROM emp.technologies_v2 _tech
|
||||
WHERE technology_name_id = _name_id
|
||||
AND emptech_state = 'RESEARCH'
|
||||
FOR UPDATE OF _tech
|
||||
) _emps USING ( technology_name_id )
|
||||
WHERE technology_name_id = _name_id
|
||||
FOR UPDATE OF _def;
|
||||
IF NOT FOUND THEN
|
||||
RETURN 'DUP_STRING';
|
||||
END IF;
|
||||
|
||||
-- Get old value for research points
|
||||
SELECT INTO _old_points technology_points
|
||||
FROM defs.technologies
|
||||
WHERE technology_name_id = _name_id;
|
||||
|
||||
-- Update the record
|
||||
BEGIN
|
||||
UPDATE defs.technologies
|
||||
SET technology_category_id = _cat_id ,
|
||||
technology_discovery_id = _disc_id ,
|
||||
technology_description_id = _desc_id ,
|
||||
technology_price = _price ,
|
||||
technology_points = _points
|
||||
WHERE technology_name_id = _name_id;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
RETURN 'DUP_STRING';
|
||||
END;
|
||||
|
||||
-- Update empire research if necessary
|
||||
IF _old_points <> _points THEN
|
||||
_multi := _points::DOUBLE PRECISION / _old_points::DOUBLE PRECISION;
|
||||
UPDATE emp.technologies_v2
|
||||
SET emptech_points = emptech_points * _multi
|
||||
WHERE technology_name_id = _name_id
|
||||
AND emptech_points IS NOT NULL;
|
||||
END IF;
|
||||
|
||||
RETURN 'UPDATED';
|
||||
|
||||
EXCEPTION
|
||||
WHEN check_violation THEN
|
||||
RETURN 'BAD_VALUE';
|
||||
|
||||
END;
|
||||
$uoc_technology$;
|
||||
|
||||
REVOKE EXECUTE
|
||||
ON FUNCTION defs.uoc_technology(
|
||||
TEXT , TEXT , TEXT , TEXT , BIGINT , BIGINT )
|
||||
FROM PUBLIC;
|
||||
GRANT EXECUTE
|
||||
ON FUNCTION defs.uoc_technology(
|
||||
TEXT , TEXT , TEXT , TEXT , BIGINT , BIGINT )
|
||||
TO :dbuser;
|
||||
|
||||
|
||||
|
||||
/*
|
||||
* Add a technology dependency
|
||||
* ----------------------------
|
||||
*
|
||||
* This stored procedure attempts to create a dependency between two
|
||||
* technologies by looking them up by name then inserting the pair in the
|
||||
* dependency table.
|
||||
*
|
||||
* Parameters:
|
||||
* _dependent The name of the dependent technology
|
||||
* _dependency The name of the dependency
|
||||
*
|
||||
* Returns:
|
||||
* ? One of the following return codes: CREATED,
|
||||
* BAD_STRINGS, CYCLE, REDUNDANT
|
||||
*/
|
||||
DROP FUNCTION IF EXISTS defs.techdep_add( TEXT , TEXT );
|
||||
CREATE FUNCTION defs.techdep_add( _dependent TEXT , _dependency TEXT )
|
||||
RETURNS defs.technology_update_result
|
||||
LANGUAGE PLPGSQL
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $techdep_add$
|
||||
|
||||
DECLARE
|
||||
_tech1_id INT;
|
||||
_tech2_id INT;
|
||||
|
||||
BEGIN
|
||||
|
||||
SELECT INTO _tech1_id , _tech2_id _str1.id , _str2.id
|
||||
FROM defs.strings _str1
|
||||
CROSS JOIN defs.strings _str2
|
||||
WHERE _str1.name = _dependent
|
||||
AND _str2.name = _dependency;
|
||||
IF NOT FOUND THEN
|
||||
RETURN 'BAD_STRINGS';
|
||||
END IF;
|
||||
|
||||
INSERT INTO defs.technology_dependencies (
|
||||
technology_name_id , technology_name_id_depends
|
||||
) VALUES ( _tech1_id , _tech2_id );
|
||||
RETURN 'CREATED';
|
||||
|
||||
EXCEPTION
|
||||
|
||||
WHEN foreign_key_violation THEN
|
||||
RETURN 'BAD_STRINGS';
|
||||
|
||||
WHEN unique_violation THEN
|
||||
RETURN 'REDUNDANT';
|
||||
|
||||
WHEN check_violation THEN
|
||||
IF SQLERRM LIKE '%Cycle detected%' THEN
|
||||
RETURN 'CYCLE';
|
||||
END IF;
|
||||
RETURN 'REDUNDANT';
|
||||
|
||||
END;
|
||||
$techdep_add$;
|
||||
|
||||
REVOKE EXECUTE
|
||||
ON FUNCTION defs.techdep_add( TEXT , TEXT )
|
||||
FROM PUBLIC;
|
||||
GRANT EXECUTE
|
||||
ON FUNCTION defs.techdep_add( TEXT , TEXT )
|
||||
TO :dbuser;
|
||||
|
||||
|
||||
|
||||
/*
|
||||
* Remove a technology dependency
|
||||
* -------------------------------
|
||||
*
|
||||
* This stored procedure removes a dependency from a technology to another.
|
||||
*
|
||||
* Parameters:
|
||||
* _dependent The name of the dependent technology
|
||||
* _dependency The name of the dependency
|
||||
*
|
||||
* Returns:
|
||||
* ? One of the following return codes: DELETED, MISSING
|
||||
*/
|
||||
DROP FUNCTION IF EXISTS defs.techdep_remove( TEXT , TEXT );
|
||||
CREATE FUNCTION defs.techdep_remove( _dependent TEXT , _dependency TEXT )
|
||||
RETURNS defs.technology_update_result
|
||||
LANGUAGE PLPGSQL
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $techdep_remove$
|
||||
|
||||
DECLARE
|
||||
_dep_id INT;
|
||||
|
||||
BEGIN
|
||||
|
||||
SELECT INTO _dep_id techdep_id
|
||||
FROM defs.technology_dependencies _td
|
||||
INNER JOIN defs.strings _str1
|
||||
ON _str1.id = _td.technology_name_id
|
||||
INNER JOIN defs.strings _str2
|
||||
ON _str2.id = _td.technology_name_id_depends
|
||||
WHERE _str1.name = _dependent
|
||||
AND _str2.name = _dependency
|
||||
FOR UPDATE OF _td;
|
||||
IF NOT FOUND THEN
|
||||
RETURN 'MISSING';
|
||||
END IF;
|
||||
|
||||
DELETE FROM defs.technology_dependencies
|
||||
WHERE techdep_id = _dep_id;
|
||||
RETURN 'DELETED';
|
||||
|
||||
END;
|
||||
$techdep_remove$;
|
||||
|
||||
REVOKE EXECUTE
|
||||
ON FUNCTION defs.techdep_remove( TEXT , TEXT )
|
||||
FROM PUBLIC;
|
||||
GRANT EXECUTE
|
||||
ON FUNCTION defs.techdep_remove( TEXT , TEXT )
|
||||
TO :dbuser;
|
||||
|
||||
|
||||
|
||||
-- ********************************************************
|
||||
-- OLD CODE BELOW
|
||||
-- ********************************************************
|
||||
|
||||
--
|
||||
-- "Basic" buildables view (buildables that do not depend on any technology)
|
||||
--
|
||||
|
|
|
@ -0,0 +1,86 @@
|
|||
/*
|
||||
* Test the defs.uoc_technology() function for new technologies
|
||||
*/
|
||||
BEGIN;
|
||||
\i utils/strings.sql
|
||||
|
||||
/*
|
||||
* We need a few test strings to play with. Each technology definition
|
||||
* uses four strings (name, category, discovery and description) so we'll
|
||||
* create 8.
|
||||
*/
|
||||
SELECT _create_test_strings( 8 , 's' );
|
||||
|
||||
/*
|
||||
* Manually insert an entry into the technologies table, using strings
|
||||
* 5-8 for the various fields.
|
||||
*/
|
||||
INSERT INTO defs.technologies (
|
||||
technology_name_id , technology_category_id ,
|
||||
technology_discovery_id , technology_description_id ,
|
||||
technology_price , technology_points
|
||||
) VALUES (
|
||||
_get_string( 's5' ) , _get_string( 's6' ) ,
|
||||
_get_string( 's7' ) , _get_string( 's8' ) ,
|
||||
1 , 1
|
||||
);
|
||||
|
||||
-- ***** TESTS BEGIN HERE *****
|
||||
SELECT plan( 10 );
|
||||
|
||||
SELECT diag_test_name( 'defs.uoc_technology() - Creation - Invalid name string' );
|
||||
SELECT is( defs.uoc_technology(
|
||||
'does not exist' , 's2' , 's3' , 's4' , 1 , 1
|
||||
)::TEXT , 'BAD_STRINGS' );
|
||||
|
||||
SELECT diag_test_name( 'defs.uoc_technology() - Creation - Invalid category string' );
|
||||
SELECT is( defs.uoc_technology(
|
||||
's1' , 'does not exist' , 's3' , 's4' , 1 , 1
|
||||
)::TEXT , 'BAD_STRINGS' );
|
||||
|
||||
SELECT diag_test_name( 'defs.uoc_technology() - Creation - Invalid discovery string' );
|
||||
SELECT is( defs.uoc_technology(
|
||||
's1' , 's2' , 'does not exist' , 's4' , 1 , 1
|
||||
)::TEXT , 'BAD_STRINGS' );
|
||||
|
||||
SELECT diag_test_name( 'defs.uoc_technology() - Creation - Invalid description string' );
|
||||
SELECT is( defs.uoc_technology(
|
||||
's1' , 's2' , 's3' , 'does not exist' , 1 , 1
|
||||
)::TEXT , 'BAD_STRINGS' );
|
||||
|
||||
SELECT diag_test_name( 'defs.uoc_technology() - Creation - Invalid price' );
|
||||
SELECT is( defs.uoc_technology(
|
||||
's1' , 's2' , 's3' , 's4' , 0 , 1
|
||||
)::TEXT , 'BAD_VALUE' );
|
||||
|
||||
SELECT diag_test_name( 'defs.uoc_technology() - Creation - Invalid research points' );
|
||||
SELECT is( defs.uoc_technology(
|
||||
's1' , 's2' , 's3' , 's4' , 1 , 0
|
||||
)::TEXT , 'BAD_VALUE' );
|
||||
|
||||
SELECT diag_test_name( 'defs.uoc_technology() - Creation - Duplicate description string' );
|
||||
SELECT is( defs.uoc_technology(
|
||||
's1' , 's2' , 's7' , 's4' , 1 , 1
|
||||
)::TEXT , 'DUP_STRING' );
|
||||
|
||||
SELECT diag_test_name( 'defs.uoc_technology() - Creation - Duplicate discovery string' );
|
||||
SELECT is( defs.uoc_technology(
|
||||
's1' , 's2' , 's3' , 's8' , 1 , 1
|
||||
)::TEXT , 'DUP_STRING' );
|
||||
|
||||
SELECT diag_test_name( 'defs.uoc_technology() - Creation - Success' );
|
||||
SELECT is( defs.uoc_technology(
|
||||
's1' , 's2' , 's3' , 's4' , 2 , 3
|
||||
)::TEXT , 'CREATED' );
|
||||
SELECT diag_test_name( 'defs.uoc_technology() - Creation - Row exists after success' );
|
||||
SELECT set_eq( $$
|
||||
SELECT * FROM defs.technologies
|
||||
WHERE technology_name_id = _get_string( 's1' )
|
||||
$$ , $$ VALUES(
|
||||
_get_string( 's1' ) , _get_string( 's2' ) ,
|
||||
_get_string( 's3' ) , _get_string( 's4' ) ,
|
||||
2 , 3
|
||||
) $$ );
|
||||
|
||||
SELECT * FROM finish( );
|
||||
ROLLBACK;
|
|
@ -0,0 +1,82 @@
|
|||
/*
|
||||
* Test the defs.uoc_technology() function for existing technologies
|
||||
*/
|
||||
BEGIN;
|
||||
\i utils/strings.sql
|
||||
|
||||
/*
|
||||
* We need a few test strings to play with. Each technology definition
|
||||
* uses four strings (name, category, discovery and description) so we'll
|
||||
* create 8.
|
||||
*/
|
||||
SELECT _create_test_strings( 8 , 's' );
|
||||
|
||||
/* Insert two entries. */
|
||||
INSERT INTO defs.technologies (
|
||||
technology_name_id , technology_category_id ,
|
||||
technology_discovery_id , technology_description_id ,
|
||||
technology_price , technology_points
|
||||
) VALUES (
|
||||
_get_string( 's1' ) , _get_string( 's2' ) ,
|
||||
_get_string( 's3' ) , _get_string( 's4' ) ,
|
||||
1 , 1
|
||||
) , (
|
||||
_get_string( 's5' ) , _get_string( 's6' ) ,
|
||||
_get_string( 's7' ) , _get_string( 's8' ) ,
|
||||
1 , 1
|
||||
);
|
||||
|
||||
-- ***** TESTS BEGIN HERE *****
|
||||
SELECT plan( 9 );
|
||||
|
||||
SELECT diag_test_name( 'defs.uoc_technology() - Update - Invalid category string' );
|
||||
SELECT is( defs.uoc_technology(
|
||||
's1' , 'does not exist' , 's3' , 's4' , 1 , 1
|
||||
)::TEXT , 'BAD_STRINGS' );
|
||||
|
||||
SELECT diag_test_name( 'defs.uoc_technology() - Update - Invalid discovery string' );
|
||||
SELECT is( defs.uoc_technology(
|
||||
's1' , 's2' , 'does not exist' , 's4' , 1 , 1
|
||||
)::TEXT , 'BAD_STRINGS' );
|
||||
|
||||
SELECT diag_test_name( 'defs.uoc_technology() - Update - Invalid description string' );
|
||||
SELECT is( defs.uoc_technology(
|
||||
's1' , 's2' , 's3' , 'does not exist' , 1 , 1
|
||||
)::TEXT , 'BAD_STRINGS' );
|
||||
|
||||
SELECT diag_test_name( 'defs.uoc_technology() - Update - Invalid price' );
|
||||
SELECT is( defs.uoc_technology(
|
||||
's1' , 's2' , 's3' , 's4' , 0 , 1
|
||||
)::TEXT , 'BAD_VALUE' );
|
||||
|
||||
SELECT diag_test_name( 'defs.uoc_technology() - Update - Invalid research points' );
|
||||
SELECT is( defs.uoc_technology(
|
||||
's1' , 's2' , 's3' , 's4' , 1 , 0
|
||||
)::TEXT , 'BAD_VALUE' );
|
||||
|
||||
SELECT diag_test_name( 'defs.uoc_technology() - Update - Duplicate description string' );
|
||||
SELECT is( defs.uoc_technology(
|
||||
's1' , 's2' , 's7' , 's4' , 1 , 1
|
||||
)::TEXT , 'DUP_STRING' );
|
||||
|
||||
SELECT diag_test_name( 'defs.uoc_technology() - Update - Duplicate discovery string' );
|
||||
SELECT is( defs.uoc_technology(
|
||||
's1' , 's2' , 's3' , 's8' , 1 , 1
|
||||
)::TEXT , 'DUP_STRING' );
|
||||
|
||||
SELECT diag_test_name( 'defs.uoc_technology() - Update - Success' );
|
||||
SELECT is( defs.uoc_technology(
|
||||
's1' , 's4' , 's2' , 's3' , 2 , 3
|
||||
)::TEXT , 'UPDATED' );
|
||||
SELECT diag_test_name( 'defs.uoc_technology() - Update - Row contents after success' );
|
||||
SELECT set_eq( $$
|
||||
SELECT * FROM defs.technologies
|
||||
WHERE technology_name_id = _get_string( 's1' )
|
||||
$$ , $$ VALUES(
|
||||
_get_string( 's1' ) , _get_string( 's4' ) ,
|
||||
_get_string( 's2' ) , _get_string( 's3' ) ,
|
||||
2 , 3
|
||||
) $$ );
|
||||
|
||||
SELECT * FROM finish( );
|
||||
ROLLBACK;
|
|
@ -0,0 +1,58 @@
|
|||
/*
|
||||
* Test the defs.uoc_technology() function when the points for a technology
|
||||
* are updated and empires are researching it.
|
||||
*/
|
||||
BEGIN;
|
||||
\i utils/strings.sql
|
||||
|
||||
/*
|
||||
* We need a few test strings to play with. Each technology definition
|
||||
* uses four strings (name, category, discovery and description) so we'll
|
||||
* create 4.
|
||||
*/
|
||||
SELECT _create_test_strings( 4 , 's' );
|
||||
|
||||
/* Insert one entry. */
|
||||
INSERT INTO defs.technologies (
|
||||
technology_name_id , technology_category_id ,
|
||||
technology_discovery_id , technology_description_id ,
|
||||
technology_price , technology_points
|
||||
) VALUES (
|
||||
_get_string( 's1' ) , _get_string( 's2' ) ,
|
||||
_get_string( 's3' ) , _get_string( 's4' ) ,
|
||||
1 , 100
|
||||
);
|
||||
|
||||
/* Remove foreign key to empires on empire technologies */
|
||||
ALTER TABLE emp.technologies_v2
|
||||
DROP CONSTRAINT fk_emptech_empire;
|
||||
|
||||
/* Insert records for the new technology, with different states */
|
||||
INSERT INTO emp.technologies_v2 (
|
||||
empire_id , technology_name_id , emptech_state ,
|
||||
emptech_points , emptech_priority
|
||||
) VALUES (
|
||||
1 , _get_string( 's1' ) , 'RESEARCH' , 50 , 2
|
||||
) , (
|
||||
2 , _get_string( 's1' ) , 'RESEARCH' , 0 , 2
|
||||
);
|
||||
|
||||
/* Now change the technology so it requires 1000 points */
|
||||
SELECT defs.uoc_technology( 's1' , 's2' , 's3' , 's4' , 1 , 1000 );
|
||||
|
||||
-- ***** TESTS BEGIN HERE *****
|
||||
SELECT no_plan( );
|
||||
|
||||
SELECT diag_test_name( 'defs.uoc_technology() - Update - Scaling of in-progress research' );
|
||||
SELECT set_eq( $$
|
||||
SELECT empire_id , ROUND( emptech_points )::INT
|
||||
FROM emp.technologies_v2
|
||||
WHERE emptech_state = 'RESEARCH'
|
||||
$$ , $$ VALUES(
|
||||
1 , 500
|
||||
) , (
|
||||
2 , 0
|
||||
) $$ );
|
||||
|
||||
SELECT * FROM finish( );
|
||||
ROLLBACK;
|
|
@ -0,0 +1,65 @@
|
|||
/*
|
||||
* Test the defs.techdep_add() function
|
||||
*/
|
||||
BEGIN;
|
||||
\i utils/strings.sql
|
||||
-- Make the columns we don't use in the technology definition table NULL-able
|
||||
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;
|
||||
|
||||
-- Create strings to use as the technologies' names
|
||||
SELECT _create_test_strings( 5 , 'tech' );
|
||||
|
||||
-- Insert the technologies
|
||||
INSERT INTO defs.technologies ( technology_name_id )
|
||||
VALUES ( _get_string( 'tech1' ) ) ,
|
||||
( _get_string( 'tech2' ) ) ,
|
||||
( _get_string( 'tech3' ) ) ,
|
||||
( _get_string( 'tech4' ) );
|
||||
|
||||
-- Add a few dependencies
|
||||
INSERT INTO defs.technology_dependencies(
|
||||
technology_name_id , technology_name_id_depends
|
||||
) VALUES ( _get_string( 'tech3' ) , _get_string( 'tech2' ) ) ,
|
||||
( _get_string( 'tech2' ) , _get_string( 'tech1' ) );
|
||||
|
||||
|
||||
-- ***** TESTS BEGIN HERE *****
|
||||
SELECT plan( 8 );
|
||||
|
||||
SELECT diag_test_name( 'defs.techdep_add() - Bad dependent technology name' );
|
||||
SELECT is( defs.techdep_add( 'does not exist' , 'tech2' )::TEXT , 'BAD_STRINGS' );
|
||||
|
||||
SELECT diag_test_name( 'defs.techdep_add() - Bad dependency name' );
|
||||
SELECT is( defs.techdep_add( 'tech1' , 'does not exist' )::TEXT , 'BAD_STRINGS' );
|
||||
|
||||
SELECT diag_test_name( 'defs.techdep_add() - Valid name that is not a technology' );
|
||||
SELECT is( defs.techdep_add( 'tech5' , 'tech2' )::TEXT , 'BAD_STRINGS' );
|
||||
|
||||
SELECT diag_test_name( 'defs.techdep_add() - Duplicate dependency' );
|
||||
SELECT is( defs.techdep_add( 'tech3' , 'tech2' )::TEXT , 'REDUNDANT' );
|
||||
|
||||
SELECT diag_test_name( 'defs.techdep_add() - Cyclic dependency' );
|
||||
SELECT is( defs.techdep_add( 'tech2' , 'tech3' )::TEXT , 'CYCLE' );
|
||||
|
||||
SELECT diag_test_name( 'defs.techdep_add() - Redundant dependency' );
|
||||
SELECT is( defs.techdep_add( 'tech3' , 'tech1' )::TEXT , 'REDUNDANT' );
|
||||
|
||||
SELECT diag_test_name( 'defs.techdep_add() - Success - Return value' );
|
||||
SELECT is( defs.techdep_add( 'tech4' , 'tech1' )::TEXT , 'CREATED' );
|
||||
|
||||
SELECT diag_test_name( 'defs.techdep_add() - Success - Table entries' );
|
||||
SELECT set_eq( $$
|
||||
SELECT technology_name_id_depends
|
||||
FROM defs.technology_dependencies
|
||||
WHERE technology_name_id = _get_string( 'tech4' );
|
||||
$$ , $$ VALUES(
|
||||
_get_string( 'tech1' )
|
||||
) $$ );
|
||||
|
||||
SELECT * FROM finish( );
|
||||
ROLLBACK;
|
|
@ -0,0 +1,51 @@
|
|||
/*
|
||||
* Test the defs.techdep_remove() function
|
||||
*/
|
||||
BEGIN;
|
||||
\i utils/strings.sql
|
||||
-- Make the columns we don't use in the technology definition table NULL-able
|
||||
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;
|
||||
|
||||
-- Create strings to use as the technologies' names
|
||||
SELECT _create_test_strings( 2 , 'tech' );
|
||||
|
||||
-- Insert the technologies
|
||||
INSERT INTO defs.technologies ( technology_name_id )
|
||||
VALUES ( _get_string( 'tech1' ) ) ,
|
||||
( _get_string( 'tech2' ) );
|
||||
|
||||
-- Add a dependency from tech2 to tech1
|
||||
INSERT INTO defs.technology_dependencies(
|
||||
technology_name_id , technology_name_id_depends
|
||||
) VALUES ( _get_string( 'tech2' ) , _get_string( 'tech1' ) );
|
||||
|
||||
|
||||
-- ***** TESTS BEGIN HERE *****
|
||||
SELECT plan( 5 );
|
||||
|
||||
SELECT diag_test_name( 'defs.techdep_remove() - Bad dependent technology name' );
|
||||
SELECT is( defs.techdep_remove( 'does not exist' , 'tech1' )::TEXT , 'MISSING' );
|
||||
|
||||
SELECT diag_test_name( 'defs.techdep_remove() - Bad dependency name' );
|
||||
SELECT is( defs.techdep_remove( 'tech2' , 'does not exist' )::TEXT , 'MISSING' );
|
||||
|
||||
SELECT diag_test_name( 'defs.techdep_remove() - Correct name but no dependency' );
|
||||
SELECT is( defs.techdep_remove( 'tech1' , 'tech2' )::TEXT , 'MISSING' );
|
||||
|
||||
SELECT diag_test_name( 'defs.techdep_remove() - Success - Return value' );
|
||||
SELECT is( defs.techdep_remove( 'tech2' , 'tech1' )::TEXT , 'DELETED' );
|
||||
|
||||
SELECT diag_test_name( 'defs.techdep_remove() - Success - Table contents' );
|
||||
SELECT is_empty($$
|
||||
SELECT * FROM defs.technology_dependencies
|
||||
WHERE technology_name_id = _get_string( 'tech2' )
|
||||
AND technology_name_id_depends = _get_string( 'tech1' );
|
||||
$$);
|
||||
|
||||
SELECT * FROM finish( );
|
||||
ROLLBACK;
|
|
@ -0,0 +1,13 @@
|
|||
/*
|
||||
* Test privileges on defs.uoc_technology()
|
||||
*/
|
||||
BEGIN;
|
||||
SELECT plan( 1 );
|
||||
|
||||
SELECT diag_test_name( 'defs.uoc_technology() - EXECUTE privilege' );
|
||||
SELECT lives_ok( $$
|
||||
SELECT defs.uoc_technology( '' , '' , '' , '' , 1 , 2 );
|
||||
$$ );
|
||||
|
||||
SELECT * FROM finish( );
|
||||
ROLLBACK;
|
|
@ -0,0 +1,13 @@
|
|||
/*
|
||||
* Test privileges on defs.techdep_add()
|
||||
*/
|
||||
BEGIN;
|
||||
SELECT plan( 1 );
|
||||
|
||||
SELECT diag_test_name( 'defs.techdep_add() - EXECUTE privilege' );
|
||||
SELECT lives_ok( $$
|
||||
SELECT defs.techdep_add( '' , '' );
|
||||
$$ );
|
||||
|
||||
SELECT * FROM finish( );
|
||||
ROLLBACK;
|
|
@ -0,0 +1,13 @@
|
|||
/*
|
||||
* Test privileges on defs.techdep_remove()
|
||||
*/
|
||||
BEGIN;
|
||||
SELECT plan( 1 );
|
||||
|
||||
SELECT diag_test_name( 'defs.techdep_remove() - EXECUTE privilege' );
|
||||
SELECT lives_ok( $$
|
||||
SELECT defs.techdep_remove( '' , '' );
|
||||
$$ );
|
||||
|
||||
SELECT * FROM finish( );
|
||||
ROLLBACK;
|
Reference in a new issue