-- LegacyWorlds Beta 6 -- PostgreSQL database scripts -- -- Technology definitions -- -- Copyright(C) 2004-2012, DeepClone Development -- -------------------------------------------------------- /* * Technology definitions * ----------------------- * * This table contains all defined technologies. It includes references to * the various I18N strings used to describe the technology, as well as its * cost in research points. * * FIXME: for now it also includes the monetary cost, but that will go away * when the full resource system is completed. */ CREATE TABLE defs.technologies( /* Name of the technology (I18N string) */ technology_name_id INT NOT NULL PRIMARY KEY , /* Category of the technology (I18N string) */ technology_category_id INT NOT NULL , /* Text to display when the technology is discovered (I18N string) */ technology_discovery_id INT NOT NULL , /* A more "factual" description of the technology (I18N string) */ technology_description_id INT NOT NULL , /* Monetary price of the technology - FIXME: will be removed later */ technology_price BIGINT NOT NULL CHECK( technology_price > 0 ) , /* Cost of the technology in terms of research points */ technology_points BIGINT NOT NULL CHECK( technology_points > 0 ) ); CREATE INDEX idx_techs_category ON defs.technologies( technology_category_id ); CREATE UNIQUE INDEX idx_techs_discovery ON defs.technologies( technology_discovery_id ); CREATE UNIQUE INDEX idx_techs_description ON defs.technologies( technology_description_id ); ALTER TABLE defs.technologies ADD CONSTRAINT fk_techs_name FOREIGN KEY ( technology_name_id ) REFERENCES defs.strings , ADD CONSTRAINT fk_techs_category FOREIGN KEY ( technology_category_id ) REFERENCES defs.strings , ADD CONSTRAINT fk_techs_discovery FOREIGN KEY ( technology_discovery_id ) REFERENCES defs.strings , ADD CONSTRAINT fk_techs_description FOREIGN KEY ( technology_description_id ) REFERENCES defs.strings; /* * Technology dependencies * ------------------------ * * This table list dependencies between technologies. It stores pairs of * dependent / dependency references. */ CREATE TABLE defs.technology_dependencies( /* Identifier of the dependency itself. Makes integrity checks easier */ techdep_id SERIAL NOT NULL PRIMARY KEY , /* Identifier of the dependent technology */ technology_name_id INT NOT NULL , /* Identifier of the technology being depended on */ technology_name_id_depends INT NOT NULL ); CREATE UNIQUE INDEX idx_techdeps_techs ON defs.technology_dependencies( technology_name_id , technology_name_id_depends ); CREATE INDEX idx_techdeps_dependency ON defs.technology_dependencies( technology_name_id_depends ); ALTER TABLE defs.technology_dependencies ADD CONSTRAINT fk_techdeps_dependent FOREIGN KEY ( technology_name_id ) REFERENCES defs.technologies , ADD CONSTRAINT fk_techdeps_dependency 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;