Technology dependencies caching and integrity checks

* Added table that will contain the cached technology dependencies.

* Implemented trigger functions that update the cache and make sure
there are no cycles or redundancies in the technology graph.

* The following SQL files need to be (re-)executed:
  -> 030-data/080-techs.sql (for the defs.techdep_cache table)
  -> 040-functions/026-technology-dependencies.sql (new file)
This commit is contained in:
Emmanuel BENOîT 2012-02-16 18:30:58 +01:00
parent b90491ca73
commit 4f083830f2
11 changed files with 749 additions and 0 deletions

View file

@ -0,0 +1,49 @@
/*
* Make sure that inserting new technologies create corresponding dependency
* cache entries, and that these entries are deleted along with the
* technologies.
*/
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 a string to use as the technology's name
SELECT _create_test_strings( 1 , 'tech' );
-- Insert the new technology
INSERT INTO defs.technologies ( technology_name_id )
VALUES ( _get_string( 'tech1' ) );
-- ***** TESTS BEGIN HERE *****
SELECT plan( 2 );
SELECT diag_test_name( 'defs.technologies - Inserting creates cache entries' );
SELECT set_eq( $$
SELECT tdcache_reverse , ( tdcache_id_parent IS NULL ) AS no_parent ,
tdcache_depth , technology_name_id_copyof ,
( tdcache_id_copyof IS NULL ) AS not_a_copy ,
( techdep_id IS NULL ) AS not_a_dependency
FROM defs.techdep_cache
WHERE technology_name_id = _get_string( 'tech1' );
$$ , $$ VALUES (
FALSE , TRUE , 0 , _get_string( 'tech1' ) , TRUE , TRUE
) , (
TRUE , TRUE , 0 , _get_string( 'tech1' ) , TRUE , TRUE
) $$ );
SELECT diag_test_name( 'defs.technologies - Cache entries are deleted along with technologies' );
DELETE FROM defs.technologies WHERE technology_name_id = _get_string( 'tech1' );
SELECT is_empty( $$
SELECT * FROM defs.techdep_cache
WHERE technology_name_id = _get_string( 'tech1' );
$$ );
SELECT * FROM finish( );
ROLLBACK;

View file

@ -0,0 +1,115 @@
/*
* Make sure that inserting technology dependencies results in new entries in
* the cache, and that the amount of entries in the cache grows according to
* predictions.
*/
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 a string to use as the technologies' names
SELECT _create_test_strings( 4 , 'tech' );
-- Insert the technologies
INSERT INTO defs.technologies ( technology_name_id )
VALUES ( _get_string( 'tech1' ) ) , ( _get_string( 'tech2' ) ) ,
( _get_string( 'tech3' ) ) , ( _get_string( 'tech4' ) );
-- ***** TESTS BEGIN HERE *****
SELECT plan( 3 );
INSERT INTO defs.technology_dependencies ( technology_name_id , technology_name_id_depends )
VALUES ( _get_string( 'tech2' ) , _get_string( 'tech1' ) );
SELECT diag_test_name( 'defs.technology_dependencies - Dependencies create cache entries' );
SELECT set_eq( $$
SELECT technology_name_id , tdcache_reverse ,
( tdcache_id_parent IS NULL ) AS no_parent ,
tdcache_depth , technology_name_id_copyof ,
( tdcache_id_copyof IS NULL ) AS not_a_copy ,
( techdep_id IS NULL ) AS not_a_dependency
FROM defs.techdep_cache
WHERE technology_name_id IN ( _get_string( 'tech1' ) , _get_string( 'tech2' ) );
$$ , $$ VALUES (
_get_string( 'tech1' ) , FALSE , TRUE , 0 , _get_string( 'tech1' ) , TRUE , TRUE
) , (
_get_string( 'tech1' ) , TRUE , TRUE , 0 , _get_string( 'tech1' ) , TRUE , TRUE
) , (
_get_string( 'tech1' ) , TRUE , FALSE , 1 , _get_string( 'tech2' ) , FALSE , FALSE
) , (
_get_string( 'tech2' ) , TRUE , TRUE , 0 , _get_string( 'tech2' ) , TRUE , TRUE
) , (
_get_string( 'tech2' ) , FALSE , TRUE , 0 , _get_string( 'tech2' ) , TRUE , TRUE
) , (
_get_string( 'tech2' ) , FALSE , FALSE , 1 , _get_string( 'tech1' ) , FALSE , FALSE
) $$ );
DELETE FROM defs.technology_dependencies WHERE technology_name_id = _get_string( 'tech2' );
SELECT diag_test_name( 'defs.technologies - Cache entries are deleted along with dependencies' );
SELECT is_empty( $$
SELECT * FROM defs.techdep_cache
WHERE technology_name_id IN ( _get_string( 'tech1' ) , _get_string( 'tech2' ) )
AND tdcache_depth > 0;
$$ );
/* Now insert the following dependencies:
* tech4 -> {tech3 , tech2}
* tech3 -> {tech1}
* tech2 -> {tech1}
*/
INSERT INTO defs.technology_dependencies ( technology_name_id , technology_name_id_depends )
VALUES ( _get_string( 'tech4' ) , _get_string( 'tech3' ) ) ,
( _get_string( 'tech4' ) , _get_string( 'tech2' ) ) ,
( _get_string( 'tech3' ) , _get_string( 'tech1' ) ) ,
( _get_string( 'tech2' ) , _get_string( 'tech1' ) );
/* Then check the amount of cache entries, as described below:
*
* technology reverse entries / copies
* ------------------------------------------------
* tech1 yes 5 / 4
* tech1 no 1 / 0
* tech2 yes 2 / 1
* tech2 no 2 / 1
* tech3 yes 2 / 1
* tech3 no 2 / 1
* tech4 yes 1 / 0
* tech4 no 5 / 4
*/
SELECT set_eq( $$
SELECT technology_name_id , tdcache_reverse ,
COUNT(*) AS total , COUNT( tdcache_id_copyof ) AS copies
FROM defs.techdep_cache
WHERE technology_name_id IN (
_get_string( 'tech1' ) , _get_string( 'tech2' ) ,
_get_string( 'tech3' ) , _get_string( 'tech4' )
)
GROUP BY technology_name_id , tdcache_reverse;
$$ , $$ VALUES (
_get_string( 'tech1' ) , TRUE , 5 , 4
) , (
_get_string( 'tech1' ) , FALSE , 1 , 0
) , (
_get_string( 'tech2' ) , TRUE , 2 , 1
) , (
_get_string( 'tech2' ) , FALSE , 2 , 1
) , (
_get_string( 'tech3' ) , TRUE , 2 , 1
) , (
_get_string( 'tech3' ) , FALSE , 2 , 1
) , (
_get_string( 'tech4' ) , TRUE , 1 , 0
) , (
_get_string( 'tech4' ) , FALSE , 5 , 4
) $$ );
SELECT * FROM finish( );
ROLLBACK;

View file

@ -0,0 +1,49 @@
/*
* Make sure that it is not possible to create cycles in dependencies.
*/
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( 3 , 'tech' );
-- Insert the technologies
INSERT INTO defs.technologies ( technology_name_id )
VALUES ( _get_string( 'tech1' ) ) ,
( _get_string( 'tech2' ) ) ,
( _get_string( 'tech3' ) );
-- ***** TESTS BEGIN HERE *****
SELECT plan( 3 );
SELECT diag_test_name( 'defs.technology_dependencies - Dependency from A to A is rejected' );
SELECT throws_ok( $$
INSERT INTO defs.technology_dependencies ( technology_name_id , technology_name_id_depends )
VALUES ( _get_string( 'tech1' ) , _get_string( 'tech1' ) );
$$ , 23514 );
SELECT diag_test_name( 'defs.technology_dependencies - Direct dependency from A to B to A is rejected' );
INSERT INTO defs.technology_dependencies ( technology_name_id , technology_name_id_depends )
VALUES ( _get_string( 'tech2' ) , _get_string( 'tech1' ) );
SELECT throws_ok( $$
INSERT INTO defs.technology_dependencies ( technology_name_id , technology_name_id_depends )
VALUES ( _get_string( 'tech1' ) , _get_string( 'tech2' ) );
$$ , 23514 );
SELECT diag_test_name( 'defs.technology_dependencies - Indirect dependency from A to B to A is rejected' );
INSERT INTO defs.technology_dependencies ( technology_name_id , technology_name_id_depends )
VALUES ( _get_string( 'tech3' ) , _get_string( 'tech2' ) );
SELECT throws_ok( $$
INSERT INTO defs.technology_dependencies ( technology_name_id , technology_name_id_depends )
VALUES ( _get_string( 'tech1' ) , _get_string( 'tech3' ) );
$$ , 23514 );
SELECT * FROM finish( );
ROLLBACK;

View file

@ -0,0 +1,79 @@
/*
* Make sure that it is not possible to create redundant dependencies
*/
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( 3 , 'tech' );
-- Insert the technologies
INSERT INTO defs.technologies ( technology_name_id )
VALUES ( _get_string( 'tech1' ) ) ,
( _get_string( 'tech2' ) ) ,
( _get_string( 'tech3' ) );
-- ***** TESTS BEGIN HERE *****
SELECT plan( 5 );
/*
* Assuming we have tech2 -> {tech1} and tech3 -> {tech1}, it shouldn't be
* possible to add dependencies between tech2 and tech3.
*/
INSERT INTO defs.technology_dependencies ( technology_name_id , technology_name_id_depends )
VALUES ( _get_string( 'tech2' ) , _get_string( 'tech1' ) ) ,
( _get_string( 'tech3' ) , _get_string( 'tech1' ) );
SELECT diag_test_name( 'defs.technology_dependencies - B -> A and C -> A, adding B -> C is redundant' );
SELECT throws_ok( $$
INSERT INTO defs.technology_dependencies ( technology_name_id , technology_name_id_depends )
VALUES ( _get_string( 'tech2' ) , _get_string( 'tech3' ) );
$$ , 23514 );
SELECT diag_test_name( 'defs.technology_dependencies - B -> A and C -> A, adding C -> B is redundant' );
SELECT throws_ok( $$
INSERT INTO defs.technology_dependencies ( technology_name_id , technology_name_id_depends )
VALUES ( _get_string( 'tech3' ) , _get_string( 'tech2' ) );
$$ , 23514 );
DELETE FROM defs.technology_dependencies;
/*
* Assuming we have tech3 -> {tech2,tech1}, trying to add a dependency
* between tech2 and tech1 would cause a redundancy.
*/
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' ) );
SELECT diag_test_name( 'defs.technology_dependencies - C -> A and C -> B, adding A -> B is redundant' );
SELECT throws_ok( $$
INSERT INTO defs.technology_dependencies ( technology_name_id , technology_name_id_depends )
VALUES ( _get_string( 'tech1' ) , _get_string( 'tech2' ) );
$$ , 23514 );
SELECT diag_test_name( 'defs.technology_dependencies - C -> A and C -> B, adding B -> A is redundant' );
SELECT throws_ok( $$
INSERT INTO defs.technology_dependencies ( technology_name_id , technology_name_id_depends )
VALUES ( _get_string( 'tech2' ) , _get_string( 'tech1' ) );
$$ , 23514 );
DELETE FROM defs.technology_dependencies;
/*
* Assuming we have tech3 -> {tech2} and tech2 -> {tech1}, trying to add a
* dependency from tech3 to tech1 would cause a redundancy.
*/
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' ) );
SELECT diag_test_name( 'defs.technology_dependencies - C -> B and B -> A, adding C -> A is redundant' );
SELECT throws_ok( $$
INSERT INTO defs.technology_dependencies ( technology_name_id , technology_name_id_depends )
VALUES ( _get_string( 'tech3' ) , _get_string( 'tech1' ) );
$$ , 23514 );
DELETE FROM defs.technology_dependencies;
SELECT * FROM finish( );
ROLLBACK;

View file

@ -0,0 +1,14 @@
/*
* Test privileges on defs.tdcache_copy_tree( )
*/
BEGIN;
SELECT plan( 1 );
SELECT diag_test_name( 'defs.tdcache_copy_tree( ) - No EXECUTE privilege' );
SELECT throws_ok( $$
SELECT defs.tdcache_copy_tree( FALSE , 1 , 2 , 3 , 4 , 5 );
$$ , 42501 );
SELECT * FROM finish( );
ROLLBACK;

View file

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

View file

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

View file

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

View file

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