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

View file

@ -89,6 +89,79 @@ ALTER TABLE defs.technology_dependencies
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.