Resource database structures

* Added structures for resource definitions, natural resources
definitions, resource providers, empire resources and empire mining
settings (both empire-wide and planet-specific).

* Added a few common utility functions to the SQL test suite. These
functions allow test initialisation to be a little shorter.

* Added "MINE" production type and an associated building definition.
The production will not be added to the XML dump or to the output of the
planets summary page, as this is extremely temporary.
This commit is contained in:
Emmanuel BENOîT 2011-12-19 11:57:08 +01:00
parent 631f49fb86
commit 4e1bb91780
20 changed files with 2223 additions and 2 deletions

View file

@ -16,6 +16,7 @@
\i parts/data/055-bugs-data.sql
\i parts/data/060-naming-data.sql
\i parts/data/070-constants-data.sql
\i parts/data/075-resources-data.sql
\i parts/data/080-techs-data.sql
\i parts/data/090-buildables-data.sql
\i parts/data/100-universe-data.sql

View file

@ -12,7 +12,7 @@ CREATE TYPE processing_status
-- Building output types
CREATE TYPE building_output_type
AS ENUM ( 'CASH', 'POP', 'DEF', 'WORK' );
AS ENUM ( 'CASH', 'POP', 'DEF', 'WORK' , 'MINE' );
-- Fleet status
CREATE TYPE fleet_status

View file

@ -0,0 +1,121 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Resource definitions
--
-- Copyright(C) 2004-2011, DeepClone Development
-- --------------------------------------------------------
/*
* Common resource definitions
* ----------------------------
*
* The defs.resources table is used to describe the part of a resource's
* definition that's idependant
*/
CREATE TABLE defs.resources(
/* The resource identifier is a reference to an I18N string that
* represents the resource's name. It also serves as the table's
* primary key.
*/
resource_name_id INT NOT NULL PRIMARY KEY ,
/* Identifier of an I18N string which serves as the resource's
* description.
*/
resource_description_id INT NOT NULL ,
/* Identifier of an I18N string that names the resource's category. This
* field may be NULL for resources that do not belong to a category.
*/
resource_category_id INT ,
/* The weight is used when sorting resources. For resources that do not
* have a category, it is used directly. Otherwise, categories themselves
* are sorted by average weight of their contents, and resources in
* categories are sorted by weight.
*/
resource_weight INT NOT NULL
CHECK ( resource_weight > 0 )
);
CREATE UNIQUE INDEX idx_resources_description
ON defs.resources( resource_description_id );
CREATE INDEX idx_resources_category
ON defs.resources( resource_category_id );
CREATE INDEX idx_resources_weight
ON defs.resources( resource_weight );
ALTER TABLE defs.resources
ADD CONSTRAINT fk_resources_name
FOREIGN KEY ( resource_name_id ) REFERENCES defs.strings ,
ADD CONSTRAINT fk_resources_description
FOREIGN KEY ( resource_description_id ) REFERENCES defs.strings ,
ADD CONSTRAINT fk_resources_category
FOREIGN KEY ( resource_category_id ) REFERENCES defs.strings;
/*
* Natural resources
* ------------------
*
* This table contains additional resource information that is used for
* natural resources only. These fields are used by the universe generator
* when it creates resource providers.
*/
CREATE TABLE defs.natural_resources (
/* Identifier of the resource definition for this natural resource, which
* also serves as the primary key for this table.
*/
resource_name_id INT NOT NULL PRIMARY KEY ,
/* Presence probability, used by the universe generator to determine
* whether some type of resource should be added to a planet or not. The
* generator will try to enforce this probability on the universe in
* general (that is, not assigning the resource to a planet will increase
* the probability of it being assigned to another).
*/
natres_p_presence DOUBLE PRECISION NOT NULL
CHECK ( natres_p_presence > 0
AND natres_p_presence < 1 ) ,
/* Average quantity in resource providers. */
natres_quantity_avg DOUBLE PRECISION NOT NULL
CHECK( natres_quantity_avg > 0 ) ,
/* Maximal deviation from the average quantity. */
natres_quantity_dev DOUBLE PRECISION NOT NULL
CHECK( natres_quantity_dev >= 0 ) ,
/* Average extraction difficulty assigned to resource providers */
natres_difficulty_avg DOUBLE PRECISION NOT NULL
CHECK( natres_difficulty_avg BETWEEN 0 AND 1 ) ,
/* Maximal deviation from the average extraction difficulty */
natres_difficulty_dev DOUBLE PRECISION NOT NULL
CHECK( natres_difficulty_dev >= 0 ) ,
/* Average recovery rate for resource providers */
natres_recovery_avg DOUBLE PRECISION NOT NULL
CHECK( natres_recovery_avg > 0
AND natres_recovery_avg <= 1 ) ,
/* Maximal deviation from the average recovery rate */
natres_recovery_dev DOUBLE PRECISION NOT NULL
CHECK( natres_recovery_dev >= 0 ) ,
/*
* For all values which include both an average and a maximal deviation,
* make sure the range defined by the deviation is still within valid
* boundaries for the value in question.
*/
CHECK( natres_quantity_avg - natres_quantity_dev > 0 ) ,
CHECK( natres_difficulty_avg + natres_difficulty_dev <= 1 ) ,
CHECK( natres_difficulty_avg - natres_difficulty_dev >= 0 ) ,
CHECK( natres_recovery_avg + natres_recovery_dev <= 1 ) ,
CHECK( natres_recovery_avg - natres_recovery_dev > 0 )
);
ALTER TABLE defs.natural_resources
ADD CONSTRAINT fk_natres_resource
FOREIGN KEY ( resource_name_id ) REFERENCES defs.resources;

View file

@ -42,6 +42,67 @@ ALTER TABLE verse.planets
FOREIGN KEY (system_id) REFERENCES verse.systems;
/*
* Resource providers
* -------------------
*
* A resource provider allows natural resources to be extracted. Resource
* providers are initialised by the universe generator and updated when
* mining results are computed.
*
* For now, resource providers are bound to planets. Each planet may only
* have one provider for a given type of natural resource.
*/
CREATE TABLE verse.resource_providers(
/* The identifier of the planet the resource provider is bound to. */
planet_id INT NOT NULL ,
/* The identifier of the natural resource that can be mined from this
* resource provider.
*/
resource_name_id INT NOT NULL ,
/* The maximal quantity of resource units in the provider */
resprov_quantity_max DOUBLE PRECISION NOT NULL
CHECK( resprov_quantity_max > 0 ) ,
/* The current quantity of resources */
resprov_quantity DOUBLE PRECISION NOT NULL
CHECK( resprov_quantity >= 0 ) ,
/* The extraction difficulty, which affects the amount of work required to
* extract resources.
*/
resprov_difficulty DOUBLE PRECISION NOT NULL
CHECK( resprov_difficulty BETWEEN 0 AND 1 ) ,
/* The provider's recovery rate, which determines how fast the provider's
* resources are regenerated.
*/
resprov_recovery DOUBLE PRECISION NOT NULL
CHECK( resprov_recovery > 0
AND resprov_recovery <= 1 ) ,
/* Primary key on (planet,type of resource) */
PRIMARY KEY( planet_id , resource_name_id ) ,
/* Make sure the quantity is always equal or smaller than the maximal
* quantity.
*/
CHECK( resprov_quantity <= resprov_quantity_max )
);
CREATE INDEX idx_resprov_resource
ON verse.resource_providers( resource_name_id );
ALTER TABLE verse.resource_providers
ADD CONSTRAINT fk_resprov_planet
FOREIGN KEY ( planet_id ) REFERENCES verse.planets ,
ADD CONSTRAINT fk_resprov_resource
FOREIGN KEY ( resource_name_id ) REFERENCES defs.natural_resources;
--
-- Happiness
--

View file

@ -24,6 +24,49 @@ ALTER TABLE emp.empires
FOREIGN KEY (name_id) REFERENCES naming.empire_names;
/*
* Empire resources
* -----------------
*
* This table contains the list of resources possessed and owed by each
* empire.
*/
CREATE TABLE emp.resources(
/* Identifier of the empire */
empire_id INT NOT NULL ,
/* Identifier of the type of resource */
resource_name_id INT NOT NULL ,
/* Amount of that specific resource possessed by the empire */
empres_possessed DOUBLE PRECISION NOT NULL
DEFAULT 0
CHECK( empres_possessed >= 0 ) ,
/* Amount of that specific resource owed by the empire. This value is
* used to accumulate debts and that, in turn, is used when computing
* debt-related fleet and building destruction.
*/
empres_owed DOUBLE PRECISION NOT NULL
DEFAULT 0
CHECK( empres_owed >= 0 ) ,
/* There is only one entry for each (empire,type of resource) pair */
PRIMARY KEY( empire_id , resource_name_id )
);
CREATE INDEX idx_empres_resource
ON emp.resources ( resource_name_id );
ALTER TABLE emp.resources
ADD CONSTRAINT fk_empres_empire
FOREIGN KEY ( empire_id ) REFERENCES emp.empires
ON DELETE CASCADE ,
ADD CONSTRAINT fk_empres_resource
FOREIGN KEY ( resource_name_id ) REFERENCES defs.resources;
--
-- Empire technologies
--
@ -69,6 +112,91 @@ ALTER TABLE emp.planets
ON DELETE CASCADE;
/*
* Empire mining settings
* -----------------------
*
* This table is used to store general empire mining settings. When the empire
* gains control over a new planet, or if the planet does not have specific
* settings, these settings are used to determine the amount of work units
* that go into extracting each type of resource.
*
* Empire-wide settings are ignored if the planet has specific settings, or if
* none of the resources present on the planet have a positive weight (in
* which case all present resources are extracted as if they had the same
* weight).
*/
CREATE TABLE emp.mining_settings(
/* Identifier of the empire */
empire_id INT NOT NULL ,
/* Identifier of the type of resources */
resource_name_id INT NOT NULL ,
/* Weight to give to this type of resource when there are no planet-
* specific settings.
*/
empmset_weight INT NOT NULL
DEFAULT 1
CHECK( empmset_weight >= 0 ) ,
/* Primary key on (empire,resource type) pairs */
PRIMARY KEY( empire_id , resource_name_id )
);
CREATE INDEX idx_empmset_resource
ON emp.mining_settings ( resource_name_id );
ALTER TABLE emp.mining_settings
ADD CONSTRAINT fk_empmset_empire
FOREIGN KEY ( empire_id ) REFERENCES emp.empires
ON DELETE CASCADE ,
ADD CONSTRAINT fk_empmset_resource
FOREIGN KEY ( resource_name_id ) REFERENCES defs.natural_resources;
/*
* Planet-specific mining settings
* --------------------------------
*
* Empire may set planet-specific mining settings when they own a planet. Even
* once the empire abandons the planet (or when it is taken away), the
* settings are kept in the database and restored if the empire takes control
* over the planet again.
*/
CREATE TABLE emp.planet_mining_settings(
/* Identifier of the empire */
empire_id INT NOT NULL ,
/* The identifier of the planet */
planet_id INT NOT NULL ,
/* Identifier of the type of resources */
resource_name_id INT NOT NULL ,
/* Weight to give to this type of resource */
emppmset_weight INT NOT NULL
DEFAULT 1
CHECK( emppmset_weight >= 0 ) ,
/* Primary key on (empire,resource type) pairs */
PRIMARY KEY( empire_id , planet_id , resource_name_id )
);
CREATE INDEX idx_emppmset_provider
ON emp.planet_mining_settings ( planet_id , resource_name_id );
ALTER TABLE emp.planet_mining_settings
ADD CONSTRAINT fk_emppmset_empire
FOREIGN KEY ( empire_id ) REFERENCES emp.empires
ON DELETE CASCADE ,
ADD CONSTRAINT fk_emppmset_resource
FOREIGN KEY ( planet_id , resource_name_id )
REFERENCES verse.resource_providers;
--
-- Planets being abandonned
--