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:
parent
b90491ca73
commit
4f083830f2
11 changed files with 749 additions and 0 deletions
|
@ -89,6 +89,79 @@ ALTER TABLE defs.technology_dependencies
|
||||||
FOREIGN KEY ( technology_name_id_depends ) REFERENCES defs.technologies;
|
FOREIGN KEY ( technology_name_id_depends ) REFERENCES defs.technologies;
|
||||||
|
|
||||||
|
|
||||||
|
/*
|
||||||
|
* Technology dependencies graph cache
|
||||||
|
* ------------------------------------
|
||||||
|
*
|
||||||
|
* This table is a cache of all dependency relationships between technologies.
|
||||||
|
* It serves two purposes. First, it allows dependencies to be checked to
|
||||||
|
* maintain the graph's integrity. Second, it allows all dependencies or
|
||||||
|
* reverse dependencies of a technology to be looked up in one single SELECT
|
||||||
|
* statement.
|
||||||
|
*
|
||||||
|
* It works by maintaining, for each node of the graph, a set of trees which
|
||||||
|
* correspond to the dependencies or reverse dependencies. Each part of a
|
||||||
|
* tree that is not determined solely by the dependency itself is a copy of
|
||||||
|
* another tree. Because of that, multiple copies of the same tree may exist
|
||||||
|
* in the records for a single technology.
|
||||||
|
*
|
||||||
|
* Technologies which have no dependencies or reverse dependencies are also
|
||||||
|
* present in the table, as it makes things easier when dependencies are added.
|
||||||
|
*/
|
||||||
|
CREATE TABLE defs.techdep_cache(
|
||||||
|
/* Identifier of the technology represented by this node */
|
||||||
|
technology_name_id INT NOT NULL,
|
||||||
|
|
||||||
|
/* Whether the node is part of a forward or reverse dependencies tree */
|
||||||
|
tdcache_reverse BOOLEAN NOT NULL ,
|
||||||
|
|
||||||
|
/* Identifier of the cache entry itself */
|
||||||
|
tdcache_id SERIAL NOT NULL ,
|
||||||
|
|
||||||
|
/* Identifier of the parent cache entry, if any */
|
||||||
|
tdcache_id_parent INT ,
|
||||||
|
|
||||||
|
/* Depth of the dependency relationship */
|
||||||
|
tdcache_depth INT NOT NULL ,
|
||||||
|
|
||||||
|
/* Identifier of the technology of the entry this entry is a copy of */
|
||||||
|
technology_name_id_copyof INT NOT NULL ,
|
||||||
|
|
||||||
|
/* Identifier of the entry this entry is a copy of */
|
||||||
|
tdcache_id_copyof INT ,
|
||||||
|
|
||||||
|
/* Identifier of the dependency because of which the entry exists, or
|
||||||
|
* NULL if the entry exists because of a technology definition.
|
||||||
|
*/
|
||||||
|
techdep_id INT ,
|
||||||
|
|
||||||
|
PRIMARY KEY( technology_name_id , tdcache_reverse , tdcache_id )
|
||||||
|
);
|
||||||
|
|
||||||
|
CREATE INDEX idx_tdcache_reversetechs
|
||||||
|
ON defs.techdep_cache ( tdcache_reverse , tdcache_id_parent );
|
||||||
|
CREATE INDEX idx_tdcache_copyof
|
||||||
|
ON defs.techdep_cache ( technology_name_id_copyof );
|
||||||
|
CREATE INDEX idx_tdcache_techdep
|
||||||
|
ON defs.techdep_cache ( techdep_id );
|
||||||
|
|
||||||
|
ALTER TABLE defs.techdep_cache
|
||||||
|
ADD CONSTRAINT fk_tdcache_technology
|
||||||
|
FOREIGN KEY ( technology_name_id ) REFERENCES defs.technologies
|
||||||
|
ON DELETE CASCADE ,
|
||||||
|
ADD CONSTRAINT fk_tdcache_techdep
|
||||||
|
FOREIGN KEY ( techdep_id ) REFERENCES defs.technology_dependencies
|
||||||
|
ON DELETE CASCADE ,
|
||||||
|
ADD CONSTRAINT fk_tdcache_copyof
|
||||||
|
FOREIGN KEY( technology_name_id_copyof , tdcache_reverse , tdcache_id_copyof )
|
||||||
|
REFERENCES defs.techdep_cache( technology_name_id , tdcache_reverse , tdcache_id )
|
||||||
|
ON DELETE CASCADE ,
|
||||||
|
ADD CONSTRAINT fk_tdcache_parent
|
||||||
|
FOREIGN KEY( technology_name_id , tdcache_reverse , tdcache_id_parent )
|
||||||
|
REFERENCES defs.techdep_cache( technology_name_id , tdcache_reverse , tdcache_id )
|
||||||
|
ON DELETE CASCADE;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
/*
|
/*
|
||||||
* Old B6M1 research system below.
|
* Old B6M1 research system below.
|
||||||
|
|
|
@ -0,0 +1,314 @@
|
||||||
|
-- LegacyWorlds Beta 6
|
||||||
|
-- PostgreSQL database scripts
|
||||||
|
--
|
||||||
|
-- Functions and triggers that maintain the technology
|
||||||
|
-- dependency cache and, generally speaking, the integrity
|
||||||
|
-- of the technology graph.
|
||||||
|
--
|
||||||
|
-- Copyright(C) 2004-2012, DeepClone Development
|
||||||
|
-- --------------------------------------------------------
|
||||||
|
|
||||||
|
|
||||||
|
/*
|
||||||
|
* Dependency tree copy function
|
||||||
|
* ------------------------------
|
||||||
|
*
|
||||||
|
* This function is used when a dependency is added. It allows a dependency
|
||||||
|
* tree to be copied as the child of another node on a different tree.
|
||||||
|
*
|
||||||
|
* Parameters:
|
||||||
|
* _reverse Whether the tree being copied is a reverse or
|
||||||
|
* forward dependency tree
|
||||||
|
* _src Identifier of the source tree
|
||||||
|
* _dest Identifier of the destination tree
|
||||||
|
* _cache Identifier of the cache entry to use as a parent
|
||||||
|
* _depth Depth of the parent node
|
||||||
|
* _dependency Identifier of the dependency being added
|
||||||
|
*/
|
||||||
|
DROP FUNCTION IF EXISTS defs.tdcache_copy_tree(
|
||||||
|
BOOLEAN , INT , INT , INT , INT , INT ) CASCADE;
|
||||||
|
CREATE FUNCTION defs.tdcache_copy_tree(
|
||||||
|
_reverse BOOLEAN ,
|
||||||
|
_src INT ,
|
||||||
|
_dest INT ,
|
||||||
|
_cache INT ,
|
||||||
|
_depth INT ,
|
||||||
|
_dependency INT )
|
||||||
|
RETURNS VOID
|
||||||
|
LANGUAGE PLPGSQL
|
||||||
|
STRICT VOLATILE
|
||||||
|
AS $tdcache_copy_tree$
|
||||||
|
|
||||||
|
DECLARE
|
||||||
|
_record RECORD;
|
||||||
|
_new_entry INT;
|
||||||
|
|
||||||
|
BEGIN
|
||||||
|
CREATE TEMPORARY TABLE tdcache_copy_ids(
|
||||||
|
old_id INT ,
|
||||||
|
new_id INT
|
||||||
|
);
|
||||||
|
|
||||||
|
FOR _record IN
|
||||||
|
SELECT * FROM defs.techdep_cache
|
||||||
|
WHERE technology_name_id = _src
|
||||||
|
AND tdcache_reverse = _reverse
|
||||||
|
ORDER BY tdcache_depth ASC
|
||||||
|
LOOP
|
||||||
|
-- Set source of copy
|
||||||
|
IF _record.tdcache_id_copyof IS NULL THEN
|
||||||
|
_record.technology_name_id_copyof := _src;
|
||||||
|
_record.tdcache_id_copyof := _record.tdcache_id;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
IF _record.tdcache_id_parent IS NULL THEN
|
||||||
|
-- Set parent and dependency if there is none
|
||||||
|
_record.tdcache_id_parent := _cache;
|
||||||
|
_record.techdep_id := _dependency;
|
||||||
|
ELSE
|
||||||
|
-- Remap child nodes to the tree's copy
|
||||||
|
SELECT INTO _record.tdcache_id_parent new_id
|
||||||
|
FROM tdcache_copy_ids
|
||||||
|
WHERE old_id = _record.tdcache_id_parent;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Set depth
|
||||||
|
_record.tdcache_depth := _record.tdcache_depth + _depth;
|
||||||
|
|
||||||
|
-- Insert new cache entry and add mapping to temporary table
|
||||||
|
INSERT INTO defs.techdep_cache(
|
||||||
|
technology_name_id , tdcache_reverse , tdcache_id_parent ,
|
||||||
|
tdcache_depth , technology_name_id_copyof ,
|
||||||
|
tdcache_id_copyof , techdep_id
|
||||||
|
) VALUES (
|
||||||
|
_dest , _reverse , _record.tdcache_id_parent ,
|
||||||
|
_record.tdcache_depth , _record.technology_name_id_copyof ,
|
||||||
|
_record.tdcache_id_copyof , _record.techdep_id
|
||||||
|
) RETURNING tdcache_id INTO _new_entry;
|
||||||
|
|
||||||
|
INSERT INTO tdcache_copy_ids
|
||||||
|
VALUES ( _record.tdcache_id , _new_entry );
|
||||||
|
END LOOP;
|
||||||
|
|
||||||
|
DROP TABLE tdcache_copy_ids;
|
||||||
|
END;
|
||||||
|
$tdcache_copy_tree$;
|
||||||
|
|
||||||
|
REVOKE EXECUTE
|
||||||
|
ON FUNCTION defs.tdcache_copy_tree(
|
||||||
|
BOOLEAN , INT , INT , INT , INT , INT )
|
||||||
|
FROM PUBLIC;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
/*
|
||||||
|
* Add a sub-tree to all copies of some node
|
||||||
|
* ------------------------------------------
|
||||||
|
*
|
||||||
|
* This function copies a source tree to all copies for a given technology and
|
||||||
|
* direction.
|
||||||
|
*
|
||||||
|
* Parameters:
|
||||||
|
* _reverse Whether the tree being copied represents reverse or
|
||||||
|
* forward dependencies
|
||||||
|
* _src The identifier of the technology whose dependency tree
|
||||||
|
* needs to be copied
|
||||||
|
* _dest The identifier of the technology onto which the source
|
||||||
|
* tree is to be grafted
|
||||||
|
* _dependency The identifier of the dependency because of which the
|
||||||
|
* copy is being carried out
|
||||||
|
*/
|
||||||
|
DROP FUNCTION IF EXISTS defs.tdcache_set_child( BOOLEAN , INT , INT , INT );
|
||||||
|
CREATE FUNCTION defs.tdcache_set_child(
|
||||||
|
_reverse BOOLEAN ,
|
||||||
|
_src INT ,
|
||||||
|
_dest INT ,
|
||||||
|
_dependency INT )
|
||||||
|
RETURNS VOID
|
||||||
|
LANGUAGE PLPGSQL
|
||||||
|
STRICT VOLATILE
|
||||||
|
AS $tdcache_set_child$
|
||||||
|
|
||||||
|
DECLARE
|
||||||
|
_tree INT;
|
||||||
|
_entry INT;
|
||||||
|
_depth INT;
|
||||||
|
|
||||||
|
BEGIN
|
||||||
|
FOR _tree , _entry , _depth IN
|
||||||
|
SELECT technology_name_id , tdcache_id , tdcache_depth + 1
|
||||||
|
FROM defs.techdep_cache
|
||||||
|
WHERE tdcache_reverse = _reverse
|
||||||
|
AND technology_name_id_copyof = _dest
|
||||||
|
LOOP
|
||||||
|
PERFORM defs.tdcache_copy_tree( _reverse , _src , _tree , _entry , _depth , _dependency );
|
||||||
|
END LOOP;
|
||||||
|
|
||||||
|
END;
|
||||||
|
$tdcache_set_child$;
|
||||||
|
|
||||||
|
REVOKE EXECUTE
|
||||||
|
ON FUNCTION defs.tdcache_set_child( BOOLEAN , INT , INT , INT )
|
||||||
|
FROM PUBLIC;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
/*
|
||||||
|
* Trigger function that handles new technology definitions
|
||||||
|
* ---------------------------------------------------------
|
||||||
|
*
|
||||||
|
* When a new technology definition is added, a pair of records needs to be
|
||||||
|
* inserted into the dependency cache. These records correspond to the root
|
||||||
|
* of the trees for the technology for both forward and reverse dependencies.
|
||||||
|
*/
|
||||||
|
DROP FUNCTION IF EXISTS defs.tgf_technologies_ai( ) CASCADE;
|
||||||
|
CREATE FUNCTION defs.tgf_technologies_ai( )
|
||||||
|
RETURNS TRIGGER
|
||||||
|
LANGUAGE PLPGSQL
|
||||||
|
STRICT VOLATILE
|
||||||
|
SECURITY DEFINER
|
||||||
|
AS $tgf_technologies_ai$
|
||||||
|
BEGIN
|
||||||
|
|
||||||
|
INSERT INTO defs.techdep_cache (
|
||||||
|
technology_name_id , tdcache_reverse , tdcache_depth , technology_name_id_copyof
|
||||||
|
) VALUES (
|
||||||
|
NEW.technology_name_id , FALSE , 0 , NEW.technology_name_id
|
||||||
|
) , (
|
||||||
|
NEW.technology_name_id , TRUE , 0 , NEW.technology_name_id
|
||||||
|
);
|
||||||
|
RETURN NEW;
|
||||||
|
|
||||||
|
END;
|
||||||
|
$tgf_technologies_ai$;
|
||||||
|
|
||||||
|
REVOKE EXECUTE
|
||||||
|
ON FUNCTION defs.tgf_technologies_ai()
|
||||||
|
FROM PUBLIC;
|
||||||
|
|
||||||
|
CREATE TRIGGER tg_technologies_ai
|
||||||
|
AFTER INSERT ON defs.technologies
|
||||||
|
FOR EACH ROW EXECUTE PROCEDURE defs.tgf_technologies_ai( );
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
/*
|
||||||
|
* Trigger function that verifies new dependencies
|
||||||
|
* ------------------------------------------------
|
||||||
|
*
|
||||||
|
* This trigger function locks all related trees, then check that the new
|
||||||
|
* dependency does not lead to cycles or redundant dependencies.
|
||||||
|
*/
|
||||||
|
DROP FUNCTION IF EXISTS defs.tgf_techdeps_bi( ) CASCADE;
|
||||||
|
CREATE FUNCTION defs.tgf_techdeps_bi( )
|
||||||
|
RETURNS TRIGGER
|
||||||
|
LANGUAGE PLPGSQL
|
||||||
|
STRICT VOLATILE
|
||||||
|
SECURITY DEFINER
|
||||||
|
AS $tgf_techdeps_bi$
|
||||||
|
BEGIN
|
||||||
|
-- Lock all trees
|
||||||
|
PERFORM 1
|
||||||
|
FROM defs.techdep_cache n1
|
||||||
|
INNER JOIN defs.techdep_cache n2
|
||||||
|
USING ( technology_name_id )
|
||||||
|
WHERE n1.technology_name_id_copyof IN (
|
||||||
|
NEW.technology_name_id , NEW.technology_name_id_depends )
|
||||||
|
FOR UPDATE OF n2;
|
||||||
|
|
||||||
|
-- Check for cycles
|
||||||
|
PERFORM 1 FROM defs.techdep_cache
|
||||||
|
WHERE technology_name_id = NEW.technology_name_id
|
||||||
|
AND technology_name_id_copyof = NEW.technology_name_id_depends
|
||||||
|
AND tdcache_reverse;
|
||||||
|
IF FOUND THEN
|
||||||
|
RAISE EXCEPTION 'Cycle detected'
|
||||||
|
USING ERRCODE = 'check_violation';
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Check for redundant dependencies
|
||||||
|
PERFORM 1
|
||||||
|
FROM defs.techdep_cache n1
|
||||||
|
INNER JOIN defs.technology_dependencies d
|
||||||
|
ON d.technology_name_id = n1.technology_name_id_copyof
|
||||||
|
WHERE n1.technology_name_id = NEW.technology_name_id
|
||||||
|
AND n1.tdcache_reverse
|
||||||
|
AND d.technology_name_id_depends = NEW.technology_name_id_depends;
|
||||||
|
IF FOUND THEN
|
||||||
|
RAISE EXCEPTION '% is a dependency of a technology that depends on %' ,
|
||||||
|
NEW.technology_name_id_depends , NEW.technology_name_id
|
||||||
|
USING ERRCODE = 'check_violation';
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
PERFORM 1
|
||||||
|
FROM defs.technology_dependencies d1
|
||||||
|
INNER JOIN defs.techdep_cache n
|
||||||
|
ON n.technology_name_id = d1.technology_name_id_depends
|
||||||
|
WHERE d1.technology_name_id = NEW.technology_name_id
|
||||||
|
AND n.tdcache_reverse
|
||||||
|
AND n.technology_name_id_copyof = NEW.technology_name_id_depends;
|
||||||
|
IF FOUND THEN
|
||||||
|
RAISE EXCEPTION '% depends on a dependency of %' ,
|
||||||
|
NEW.technology_name_id , NEW.technology_name_id_depends
|
||||||
|
USING ERRCODE = 'check_violation';
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
PERFORM 1 FROM defs.techdep_cache
|
||||||
|
WHERE technology_name_id = NEW.technology_name_id
|
||||||
|
AND technology_name_id_copyof = NEW.technology_name_id_depends
|
||||||
|
AND NOT tdcache_reverse;
|
||||||
|
IF FOUND THEN
|
||||||
|
RAISE EXCEPTION '% is already a dependency of %' ,
|
||||||
|
NEW.technology_name_id_depends , NEW.technology_name_id
|
||||||
|
USING ERRCODE = 'check_violation';
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
RETURN NEW;
|
||||||
|
END;
|
||||||
|
$tgf_techdeps_bi$;
|
||||||
|
|
||||||
|
|
||||||
|
CREATE TRIGGER tg_techdeps_bi
|
||||||
|
BEFORE INSERT ON defs.technology_dependencies
|
||||||
|
FOR EACH ROW EXECUTE PROCEDURE defs.tgf_techdeps_bi( );
|
||||||
|
|
||||||
|
REVOKE EXECUTE
|
||||||
|
ON FUNCTION defs.tgf_techdeps_bi( )
|
||||||
|
FROM PUBLIC;
|
||||||
|
|
||||||
|
|
||||||
|
/*
|
||||||
|
* Trigger function that updates the dependency cache
|
||||||
|
* ---------------------------------------------------
|
||||||
|
*
|
||||||
|
* After a new, valid dependency has been added, trees for both forward and
|
||||||
|
* reverse depdencies must be copied.
|
||||||
|
*/
|
||||||
|
DROP FUNCTION IF EXISTS defs.tgf_techdeps_ai( ) CASCADE;
|
||||||
|
CREATE FUNCTION defs.tgf_techdeps_ai( )
|
||||||
|
RETURNS TRIGGER
|
||||||
|
LANGUAGE PLPGSQL
|
||||||
|
STRICT VOLATILE
|
||||||
|
SECURITY DEFINER
|
||||||
|
AS $tgf_techdeps_ai$
|
||||||
|
BEGIN
|
||||||
|
|
||||||
|
PERFORM defs.tdcache_set_child( FALSE ,
|
||||||
|
NEW.technology_name_id_depends , NEW.technology_name_id ,
|
||||||
|
NEW.techdep_id );
|
||||||
|
|
||||||
|
PERFORM defs.tdcache_set_child( TRUE ,
|
||||||
|
NEW.technology_name_id , NEW.technology_name_id_depends ,
|
||||||
|
NEW.techdep_id );
|
||||||
|
|
||||||
|
RETURN NEW;
|
||||||
|
END;
|
||||||
|
$tgf_techdeps_ai$;
|
||||||
|
|
||||||
|
CREATE TRIGGER tg_techdeps_ai
|
||||||
|
AFTER INSERT ON defs.technology_dependencies
|
||||||
|
FOR EACH ROW EXECUTE PROCEDURE defs.tgf_techdeps_ai( );
|
||||||
|
|
||||||
|
REVOKE EXECUTE
|
||||||
|
ON FUNCTION defs.tgf_techdeps_ai( )
|
||||||
|
FROM PUBLIC;
|
|
@ -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;
|
|
@ -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;
|
|
@ -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;
|
|
@ -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;
|
|
@ -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;
|
|
@ -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;
|
|
@ -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;
|
|
@ -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;
|
|
@ -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;
|
Reference in a new issue