diff --git a/legacyworlds-server-data/db-structure/parts/010-data.sql b/legacyworlds-server-data/db-structure/parts/010-data.sql
index add939b..f5e52b7 100644
--- a/legacyworlds-server-data/db-structure/parts/010-data.sql
+++ b/legacyworlds-server-data/db-structure/parts/010-data.sql
@@ -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
diff --git a/legacyworlds-server-data/db-structure/parts/data/000-typedefs.sql b/legacyworlds-server-data/db-structure/parts/data/000-typedefs.sql
index 4ba3baa..f9fe790 100644
--- a/legacyworlds-server-data/db-structure/parts/data/000-typedefs.sql
+++ b/legacyworlds-server-data/db-structure/parts/data/000-typedefs.sql
@@ -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
diff --git a/legacyworlds-server-data/db-structure/parts/data/075-resources-data.sql b/legacyworlds-server-data/db-structure/parts/data/075-resources-data.sql
new file mode 100644
index 0000000..70f1347
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/parts/data/075-resources-data.sql
@@ -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;
diff --git a/legacyworlds-server-data/db-structure/parts/data/100-universe-data.sql b/legacyworlds-server-data/db-structure/parts/data/100-universe-data.sql
index fb8f379..58ddf52 100644
--- a/legacyworlds-server-data/db-structure/parts/data/100-universe-data.sql
+++ b/legacyworlds-server-data/db-structure/parts/data/100-universe-data.sql
@@ -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
--
diff --git a/legacyworlds-server-data/db-structure/parts/data/110-empires-data.sql b/legacyworlds-server-data/db-structure/parts/data/110-empires-data.sql
index 5a3d00a..a92e197 100644
--- a/legacyworlds-server-data/db-structure/parts/data/110-empires-data.sql
+++ b/legacyworlds-server-data/db-structure/parts/data/110-empires-data.sql
@@ -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
--
diff --git a/legacyworlds-server-data/db-structure/tests/admin/constraints/defs/07500-resources.sql b/legacyworlds-server-data/db-structure/tests/admin/constraints/defs/07500-resources.sql
new file mode 100644
index 0000000..216b857
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/admin/constraints/defs/07500-resources.sql
@@ -0,0 +1,225 @@
+/*
+ * Test constraints and foreign keys on defs.resources
+ */
+BEGIN;
+
+ /* We need a few strings to be used when creating resource definitions. */
+ \i utils/strings.sql
+ SELECT _create_test_strings( 6 );
+
+ /****** TESTS BEGIN HERE ******/
+ SELECT plan( 17 );
+
+
+ /* Valid resource definition, no category */
+ SELECT diag_test_name( 'Valid resource definition without category' );
+ PREPARE _test_this AS
+ INSERT INTO defs.resources (
+ resource_name_id , resource_description_id , resource_weight
+ ) VALUES (
+ _get_string( 'test1' ) , _get_string( 'test2' ) , 1
+ );
+ SELECT lives_ok( '_test_this' );
+ DEALLOCATE ALL;
+ DELETE FROM defs.resources;
+
+ /* Resource with valid fields, including a category */
+ SELECT diag_test_name( 'Valid resource definition with category' );
+ PREPARE _test_this AS
+ INSERT INTO defs.resources (
+ resource_name_id , resource_description_id ,
+ resource_category_id , resource_weight
+ ) VALUES (
+ _get_string( 'test1' ) , _get_string( 'test2' ) ,
+ _get_string( 'test3' ) , 1
+ );
+ SELECT lives_ok( '_test_this' );
+ DEALLOCATE ALL;
+ DELETE FROM defs.resources;
+
+
+ /* Resource definition with an invalid name */
+ SELECT diag_test_name( 'Resource definition with an invalid name' );
+ PREPARE _test_this AS
+ INSERT INTO defs.resources (
+ resource_name_id , resource_description_id , resource_weight
+ ) VALUES (
+ _get_bad_string( ) , _get_string( 'test2' ) , 1
+ );
+ SELECT throws_ok( '_test_this' , 23503 );
+ DEALLOCATE ALL;
+
+ /* Resource definition with a NULL name */
+ SELECT diag_test_name( 'Resource definition with a NULL name' );
+ PREPARE _test_this AS
+ INSERT INTO defs.resources (
+ resource_name_id , resource_description_id , resource_weight
+ ) VALUES (
+ NULL , _get_string( 'test2' ) , 1
+ );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+
+ /* Resource definition with an invalid description */
+ SELECT diag_test_name( 'Resource definition with an invalid description' );
+ PREPARE _test_this AS
+ INSERT INTO defs.resources (
+ resource_name_id , resource_description_id , resource_weight
+ ) VALUES (
+ _get_string( 'test1' ) , _get_bad_string( ) , 1
+ );
+ SELECT throws_ok( '_test_this' , 23503 );
+ DEALLOCATE ALL;
+
+ /* Resource definition with a NULL description */
+ SELECT diag_test_name( 'Resource definition with a NULL description' );
+ PREPARE _test_this AS
+ INSERT INTO defs.resources (
+ resource_name_id , resource_description_id , resource_weight
+ ) VALUES (
+ _get_string( 'test1' ) , NULL , 1
+ );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+
+ /* Resource definition with an invalid category */
+ SELECT diag_test_name( 'Resource definition with an invalid category' );
+ PREPARE _test_this AS
+ INSERT INTO defs.resources (
+ resource_name_id , resource_description_id ,
+ resource_category_id , resource_weight
+ ) VALUES (
+ _get_string( 'test1' ) , _get_string( 'test2' ) ,
+ _get_bad_string( ) , 1
+ );
+ SELECT throws_ok( '_test_this' , 23503 );
+ DEALLOCATE ALL;
+
+
+ /* Resource definition with an invalid weight */
+ SELECT diag_test_name( 'Resource definition with an invalid weight' );
+ PREPARE _test_this AS
+ INSERT INTO defs.resources (
+ resource_name_id , resource_description_id , resource_weight
+ ) VALUES (
+ _get_string( 'test1' ) , _get_string( 'test2' ) , 0
+ );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+ /* Resource definition with a NULL weight */
+ SELECT diag_test_name( 'Resource definition with a NULL weight' );
+ PREPARE _test_this AS
+ INSERT INTO defs.resources (
+ resource_name_id , resource_description_id , resource_weight
+ ) VALUES (
+ _get_string( 'test1' ) , _get_string( 'test2' ) , NULL
+ );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+
+ /* Resource definitions using the same name */
+ INSERT INTO defs.resources (
+ resource_name_id , resource_description_id , resource_weight
+ ) VALUES (
+ _get_string( 'test1' ) , _get_string( 'test2' ) , 1
+ );
+ SELECT diag_test_name( 'Resource definitions using the same name' );
+ PREPARE _test_this AS
+ INSERT INTO defs.resources (
+ resource_name_id , resource_description_id , resource_weight
+ ) VALUES (
+ _get_string( 'test1' ) , _get_string( 'test3' ) , 1
+ );
+ SELECT throws_ok( '_test_this' , 23505 );
+ DEALLOCATE ALL;
+
+ /* Resource definitions using the same description */
+ SELECT diag_test_name( 'Resource definitions using the same description' );
+ PREPARE _test_this AS
+ INSERT INTO defs.resources (
+ resource_name_id , resource_description_id , resource_weight
+ ) VALUES (
+ _get_string( 'test3' ) , _get_string( 'test2' ) , 1
+ );
+ SELECT throws_ok( '_test_this' , 23505 );
+ DEALLOCATE ALL;
+
+ /* Resources with distinct names and descriptions */
+ SELECT diag_test_name( 'Resources with distinct names and descriptions' );
+ PREPARE _test_this AS
+ INSERT INTO defs.resources (
+ resource_name_id , resource_description_id , resource_weight
+ ) VALUES (
+ _get_string( 'test3' ) , _get_string( 'test4' ) , 1
+ );
+ SELECT lives_ok( '_test_this' );
+ DEALLOCATE ALL;
+ DELETE FROM defs.resources;
+
+
+ /* Resources with distinct categories */
+ INSERT INTO defs.resources (
+ resource_name_id , resource_description_id ,
+ resource_category_id , resource_weight
+ ) VALUES (
+ _get_string( 'test1' ) , _get_string( 'test2' ) ,
+ _get_string( 'test3' ) , 1
+ );
+ SELECT diag_test_name( 'Resources with distinct categories' );
+ PREPARE _test_this AS
+ INSERT INTO defs.resources (
+ resource_name_id , resource_description_id ,
+ resource_category_id , resource_weight
+ ) VALUES (
+ _get_string( 'test4' ) , _get_string( 'test5' ) ,
+ _get_string( 'test6' ) , 1
+ );
+ SELECT lives_ok( '_test_this' );
+ DEALLOCATE ALL;
+ DELETE FROM defs.resources WHERE resource_name_id = _get_string( 'test4' );
+
+ /* Resources in the same category */
+ SELECT diag_test_name( 'Resources in the same category' );
+ PREPARE _test_this AS
+ INSERT INTO defs.resources (
+ resource_name_id , resource_description_id ,
+ resource_category_id , resource_weight
+ ) VALUES (
+ _get_string( 'test4' ) , _get_string( 'test5' ) ,
+ _get_string( 'test3' ) , 1
+ );
+ SELECT lives_ok( '_test_this' );
+ DEALLOCATE ALL;
+
+
+ /* Resource definition name deletion impossible */
+ SELECT diag_test_name( 'Resource definition name deletion impossible' );
+ PREPARE _test_this AS
+ DELETE FROM defs.strings WHERE id = _get_string( 'test1' );
+ SELECT throws_ok( '_test_this' , 23503 );
+ DEALLOCATE ALL;
+
+ /* Resource definition description deletion impossible */
+ SELECT diag_test_name( 'Resource definition description deletion impossible' );
+ PREPARE _test_this AS
+ DELETE FROM defs.strings WHERE id = _get_string( 'test2' );
+ SELECT throws_ok( '_test_this' , 23503 );
+ DEALLOCATE ALL;
+
+ /*
+ * 17/ Make sure it is impossible to delete a string definition used as
+ * a resource category
+ */
+ SELECT diag_test_name( 'Resource definition description deletion impossible' );
+ PREPARE _test_this AS
+ DELETE FROM defs.strings WHERE id = _get_string( 'test3' );
+ SELECT throws_ok( '_test_this' , 23503 );
+ DEALLOCATE ALL;
+
+
+ SELECT * FROM finish( );
+ROLLBACK;
\ No newline at end of file
diff --git a/legacyworlds-server-data/db-structure/tests/admin/constraints/defs/07501-natural-resources.sql b/legacyworlds-server-data/db-structure/tests/admin/constraints/defs/07501-natural-resources.sql
new file mode 100644
index 0000000..b38b69c
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/admin/constraints/defs/07501-natural-resources.sql
@@ -0,0 +1,474 @@
+/*
+ * Test constraints and foreign keys on defs.natural_resources
+ */
+BEGIN;
+
+ /* We need a few strings to be used when creating resource definitions. */
+ \i utils/strings.sql
+ SELECT _create_test_strings( 4 );
+
+ /*
+ * We need a a pair of resource definitions to be used when creating
+ * natural resources.
+ */
+ INSERT INTO defs.resources (
+ resource_name_id , resource_description_id , resource_weight
+ ) VALUES ( _get_string( 'test1' ) , _get_string( 'test2' ) , 1 );
+ INSERT INTO defs.resources (
+ resource_name_id , resource_description_id , resource_weight
+ ) VALUES ( _get_string( 'test3' ) , _get_string( 'test4' ) , 2 );
+
+
+ /****** TESTS BEGIN HERE ******/
+ SELECT plan( 33 );
+
+
+ SELECT diag_test_name( 'Valid natural resource definition' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources (
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0.5 , 100 , 1 , 0.5 , 0.05 , 0.5 , 0.05
+ );
+ SELECT lives_ok( '_test_this' );
+
+ SELECT diag_test_name( 'Duplicate natural resource definition' );
+ SELECT throws_ok( '_test_this' , 23505 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Distinct natural resource definitions' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources (
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test3' ) , 0.5 , 100 , 1 , 0.5 , 0.05 , 0.5 , 0.05
+ );
+ SELECT lives_ok( '_test_this' );
+ DEALLOCATE ALL;
+ DELETE FROM defs.natural_resources;
+
+
+ SELECT diag_test_name( 'Natural resource definition with missing resource definition' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test2' ) , 0.5 , 100 , 1 , 0.5 , 0.05 , 0.5 , 0.05
+ );
+ SELECT throws_ok( '_test_this' , 23503 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Natural resource definition with NULL resource definition' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ NULL , 0.5 , 100 , 1 , 0.5 , 0.05 , 0.5 , 0.05
+ );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+
+ SELECT diag_test_name( 'Natural resource definition with presence probability <= 0' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0 , 100 , 1 , 0.5 , 0.05 , 0.5 , 0.05
+ );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Natural resource definition with presence probability >= 1' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 1 , 100 , 1 , 0.5 , 0.05 , 0.5 , 0.05
+ );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Natural resource definition with NULL presence probability' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , NULL , 100 , 1 , 0.5 , 0.05 , 0.5 , 0.05
+ );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+
+ SELECT diag_test_name( 'Natural resource definition with avg. quantity <= 0' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0.5 , 0 , 1 , 0.5 , 0.05 , 0.5 , 0.05
+ );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Natural resource definition with NULL avg. quantity' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0.5 , NULL , 1 , 0.5 , 0.05 , 0.5 , 0.05
+ );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+
+
+ SELECT diag_test_name( 'Natural resource definition with quantity dev. < 0' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0.5 , 100 , -1 , 0.5 , 0.05 , 0.5 , 0.05
+ );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Natural resource definition with NULL quantity dev.' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0.5 , 100 , NULL , 0.5 , 0.05 , 0.5 , 0.05
+ );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Natural resource definition with quantity dev. = avg. quantity' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0.5 , 100 , 100 , 0.5 , 0.05 , 0.5 , 0.05
+ );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Natural resource definition with quantity dev. = 0' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0.5 , 100 , 0 , 0.5 , 0.05 , 0.5 , 0.05
+ );
+ SELECT lives_ok( '_test_this' );
+ DEALLOCATE ALL;
+ DELETE FROM defs.natural_resources;
+
+
+
+ SELECT diag_test_name( 'Natural resource definition with avg. difficulty = 1' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0.5 , 100 , 1 , 1 , 0 , 0.5 , 0.05
+ );
+ SELECT lives_ok( '_test_this' );
+ DEALLOCATE ALL;
+ DELETE FROM defs.natural_resources;
+
+ SELECT diag_test_name( 'Natural resource definition with avg. difficulty = 0' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0.5 , 100 , 1 , 0 , 0 , 0.5 , 0.05
+ );
+ SELECT lives_ok( '_test_this' );
+ DEALLOCATE ALL;
+ DELETE FROM defs.natural_resources;
+
+ SELECT diag_test_name( 'Natural resource definition with avg. difficulty > 1' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0.5 , 100 , 1 , 1.0001 , 0 , 0.5 , 0.05
+ );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+
+ SELECT diag_test_name( 'Natural resource definition with avg. difficulty < 0' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0.5 , 100 , 1 , -0.0001 , 0 , 0.5 , 0.05
+ );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Natural resource definition with NULL avg. difficulty' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0.5 , 100 , 1 , NULL , 0.05 , 0.5 , 0.05
+ );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+
+
+ SELECT diag_test_name( 'Natural resource definition with difficulty dev. < 0' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0.5 , 100 , 1 , 0.5 , -1 , 0.5 , 0.05
+ );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Natural resource definition with avg. difficulty - difficulty dev. < 0' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0.5 , 100 , 1 , 0.25 , 0.5 , 0.5 , 0.05
+ );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Natural resource definition with difficulty dev. + avg. difficulty > 1' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0.5 , 100 , 1 , 0.75 , 0.5 , 0.5 , 0.05
+ );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Natural resource definition with NULL difficulty dev.' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0.5 , 100 , 1 , 0.5 , NULL , 0.5 , 0.05
+ );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+
+ SELECT diag_test_name( 'Natural resource definition with avg. recovery = 1' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0.5 , 100 , 1 , 0.5 , 0.05 ,
+ 1 , 0
+ );
+ SELECT lives_ok( '_test_this' );
+ DEALLOCATE ALL;
+ DELETE FROM defs.natural_resources;
+
+ SELECT diag_test_name( 'Natural resource definition with avg. recovery = 0+' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0.5 , 100 , 1 , 0.5 , 0.05 ,
+ 0.0001 , 0
+ );
+ SELECT lives_ok( '_test_this' );
+ DEALLOCATE ALL;
+ DELETE FROM defs.natural_resources;
+
+ SELECT diag_test_name( 'Natural resource definition with avg. recovery > 1' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0.5 , 100 , 1 , 0.5 , 0.05 ,
+ 1.1 , 0
+ );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Natural resource definition with avg. recovery <= 0' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0.5 , 100 , 1 , 0.5 , 0.05 ,
+ 0 , 0
+ );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Natural resource definition with NULL avg. recovery' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0.5 , 100 , 1 , 0.5 , 0.05 ,
+ NULL , 0.05
+ );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+
+ SELECT diag_test_name( 'Natural resource definition with recovery dev. < 0' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0.5 , 100 , 1 , 0.5 , 0.05 ,
+ 0.5 , -1
+ );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Natural resource definition with avg.recovery - recovery dev. <= 0' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0.5 , 100 , 1 , 0.5 , 0.05 ,
+ 0.5 , 0.5
+ );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Natural resource definition with avg.recovery - recovery dev. > 1' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0.5 , 100 , 1 , 0.5 , 0.05 ,
+ 0.75 , 0.5
+ );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Natural resource definition with NULL recovery dev.' );
+ PREPARE _test_this AS
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0.5 , 100 , 1 , 0.5 , 0.05 ,
+ 0.5 , NULL
+ );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+
+ SELECT diag_test_name( 'Deletion of the base definition for a natural resource' );
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( 'test1' ) , 0.5 , 100 , 1 , 0.5 , 0.05 , 0.5 , 0.05
+ );
+ PREPARE _test_this AS
+ DELETE FROM defs.resources WHERE resource_name_id = _get_string( 'test1' );
+ SELECT throws_ok( '_test_this' , 23503 );
+
+ SELECT * FROM finish( );
+ROLLBACK;
\ No newline at end of file
diff --git a/legacyworlds-server-data/db-structure/tests/admin/constraints/defs/10003-resource-providers.sql b/legacyworlds-server-data/db-structure/tests/admin/constraints/defs/10003-resource-providers.sql
new file mode 100644
index 0000000..9e31d1d
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/admin/constraints/defs/10003-resource-providers.sql
@@ -0,0 +1,331 @@
+/*
+ * Test constraints and foreign keys on verse.resource_providers
+ */
+BEGIN;
+
+ /* We need a pair of resource definitions and a pair of planets. */
+ \i utils/strings.sql
+ \i utils/resources.sql
+ \i utils/accounts.sql
+ \i utils/naming.sql
+ \i utils/universe.sql
+ SELECT _create_natural_resources( 2 , 'testResource' );
+ SELECT _create_raw_planets( 2 , 'testPlanet' );
+
+
+ /****** TESTS BEGIN HERE ******/
+ SELECT plan( 22 );
+
+
+ SELECT diag_test_name( 'Valid resource provider' );
+ PREPARE _test_this AS
+ INSERT INTO verse.resource_providers(
+ planet_id , resource_name_id ,
+ resprov_quantity_max , resprov_quantity ,
+ resprov_difficulty , resprov_recovery
+ ) VALUES (
+ _get_map_name( 'testPlanet1' ) , _get_string( 'testResource1' ) ,
+ 100 , 50 ,
+ 0.5 , 0.5
+ );
+ SELECT lives_ok( '_test_this' );
+
+ SELECT diag_test_name( 'Duplicate resource provider' );
+ SELECT throws_ok( '_test_this' , 23505 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Resource provider with same planet but different type' );
+ PREPARE _test_this AS
+ INSERT INTO verse.resource_providers(
+ planet_id , resource_name_id ,
+ resprov_quantity_max , resprov_quantity ,
+ resprov_difficulty , resprov_recovery
+ ) VALUES (
+ _get_map_name( 'testPlanet1' ) , _get_string( 'testResource2' ) ,
+ 100 , 50 ,
+ 0.5 , 0.5
+ );
+ SELECT lives_ok( '_test_this' );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Resource provider with same type but different planet' );
+ PREPARE _test_this AS
+ INSERT INTO verse.resource_providers(
+ planet_id , resource_name_id ,
+ resprov_quantity_max , resprov_quantity ,
+ resprov_difficulty , resprov_recovery
+ ) VALUES (
+ _get_map_name( 'testPlanet2' ) , _get_string( 'testResource1' ) ,
+ 100 , 50 ,
+ 0.5 , 0.5
+ );
+ SELECT lives_ok( '_test_this' );
+ DEALLOCATE ALL;
+ DELETE FROM verse.resource_providers;
+
+
+ SELECT diag_test_name( 'Resource provider with NULL planet identifier' );
+ PREPARE _test_this AS
+ INSERT INTO verse.resource_providers(
+ planet_id , resource_name_id ,
+ resprov_quantity_max , resprov_quantity ,
+ resprov_difficulty , resprov_recovery
+ ) VALUES (
+ NULL , _get_string( 'testResource1' ) ,
+ 100 , 50 ,
+ 0.5 , 0.5
+ );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Resource provider with invalid planet identifier' );
+ PREPARE _test_this AS
+ INSERT INTO verse.resource_providers(
+ planet_id , resource_name_id ,
+ resprov_quantity_max , resprov_quantity ,
+ resprov_difficulty , resprov_recovery
+ ) VALUES (
+ _get_bad_map_name( ) , _get_string( 'testResource1' ) ,
+ 100 , 50 ,
+ 0.5 , 0.5
+ );
+ SELECT throws_ok( '_test_this' , 23503 );
+ DEALLOCATE ALL;
+
+
+ SELECT diag_test_name( 'Resource provider with NULL resource identifier' );
+ PREPARE _test_this AS
+ INSERT INTO verse.resource_providers(
+ planet_id , resource_name_id ,
+ resprov_quantity_max , resprov_quantity ,
+ resprov_difficulty , resprov_recovery
+
+ ) VALUES (
+ _get_map_name( 'testPlanet1' ) , NULL ,
+ 100 , 50 ,
+ 0.5 , 0.5
+ );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Resource provider with invalid resource identifier' );
+ PREPARE _test_this AS
+ INSERT INTO verse.resource_providers(
+ planet_id , resource_name_id ,
+ resprov_quantity_max , resprov_quantity ,
+ resprov_difficulty , resprov_recovery
+ ) VALUES (
+ _get_map_name( 'testPlanet1' ) , _get_bad_string( ) ,
+ 100 , 50 ,
+ 0.5 , 0.5
+ );
+ SELECT throws_ok( '_test_this' , 23503 );
+ DEALLOCATE ALL;
+
+
+ SELECT diag_test_name( 'Resource provider with NULL maximal quantity' );
+ PREPARE _test_this AS
+ INSERT INTO verse.resource_providers(
+ planet_id , resource_name_id ,
+ resprov_quantity_max , resprov_quantity ,
+ resprov_difficulty , resprov_recovery
+
+ ) VALUES (
+ _get_map_name( 'testPlanet1' ) , _get_string( 'testResource1' ) ,
+ NULL , 50 ,
+ 0.5 , 0.5
+ );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Resource provider with maximal quantity <= 0' );
+ PREPARE _test_this AS
+ INSERT INTO verse.resource_providers(
+ planet_id , resource_name_id ,
+ resprov_quantity_max , resprov_quantity ,
+ resprov_difficulty , resprov_recovery
+ ) VALUES (
+ _get_map_name( 'testPlanet1' ) , _get_string( 'testResource1' ) ,
+ 0 , 0 ,
+ 0.5 , 0.5
+ );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+
+ SELECT diag_test_name( 'Resource provider with NULL quantity' );
+ PREPARE _test_this AS
+ INSERT INTO verse.resource_providers(
+ planet_id , resource_name_id ,
+ resprov_quantity_max , resprov_quantity ,
+ resprov_difficulty , resprov_recovery
+ ) VALUES (
+ _get_map_name( 'testPlanet1' ) , _get_string( 'testResource1' ) ,
+ 100 , NULL ,
+ 0.5 , 0.5
+ );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Resource provider with quantity < 0' );
+ PREPARE _test_this AS
+ INSERT INTO verse.resource_providers(
+ planet_id , resource_name_id ,
+ resprov_quantity_max , resprov_quantity ,
+ resprov_difficulty , resprov_recovery
+ ) VALUES (
+ _get_map_name( 'testPlanet1' ) , _get_string( 'testResource1' ) ,
+ 100 , -1 ,
+ 0.5 , 0.5
+ );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Resource provider with quantity > max. quantity' );
+ PREPARE _test_this AS
+ INSERT INTO verse.resource_providers(
+ planet_id , resource_name_id ,
+ resprov_quantity_max , resprov_quantity ,
+ resprov_difficulty , resprov_recovery
+ ) VALUES (
+ _get_map_name( 'testPlanet1' ) , _get_string( 'testResource1' ) ,
+ 100 , 101 ,
+ 0.5 , 0.5
+ );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+
+ SELECT diag_test_name( 'Resource provider with NULL difficulty' );
+ PREPARE _test_this AS
+ INSERT INTO verse.resource_providers(
+ planet_id , resource_name_id ,
+ resprov_quantity_max , resprov_quantity ,
+ resprov_difficulty , resprov_recovery
+ ) VALUES (
+ _get_map_name( 'testPlanet1' ) , _get_string( 'testResource1' ) ,
+ 100 , 50 ,
+ NULL , 0.5
+ );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Resource provider with difficulty < 0' );
+ PREPARE _test_this AS
+ INSERT INTO verse.resource_providers(
+ planet_id , resource_name_id ,
+ resprov_quantity_max , resprov_quantity ,
+ resprov_difficulty , resprov_recovery
+ ) VALUES (
+ _get_map_name( 'testPlanet1' ) , _get_string( 'testResource1' ) ,
+ 100 , 50 ,
+ -0.5 , 0.5
+ );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Resource provider with difficulty > 1' );
+ PREPARE _test_this AS
+ INSERT INTO verse.resource_providers(
+ planet_id , resource_name_id ,
+ resprov_quantity_max , resprov_quantity ,
+ resprov_difficulty , resprov_recovery
+ ) VALUES (
+ _get_map_name( 'testPlanet1' ) , _get_string( 'testResource1' ) ,
+ 100 , 50 ,
+ 1.5 , 0.5
+ );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Resource provider with difficulty = 0' );
+ PREPARE _test_this AS
+ INSERT INTO verse.resource_providers(
+ planet_id , resource_name_id ,
+ resprov_quantity_max , resprov_quantity ,
+ resprov_difficulty , resprov_recovery
+ ) VALUES (
+ _get_map_name( 'testPlanet1' ) , _get_string( 'testResource1' ) ,
+ 100 , 50 ,
+ 0 , 0.5
+ );
+ SELECT lives_ok( '_test_this' );
+ DEALLOCATE ALL;
+ DELETE FROM verse.resource_providers;
+
+ SELECT diag_test_name( 'Resource provider with difficulty = 1' );
+ PREPARE _test_this AS
+ INSERT INTO verse.resource_providers(
+ planet_id , resource_name_id ,
+ resprov_quantity_max , resprov_quantity ,
+ resprov_difficulty , resprov_recovery
+ ) VALUES (
+ _get_map_name( 'testPlanet1' ) , _get_string( 'testResource1' ) ,
+ 100 , 50 ,
+ 1 , 0.5
+ );
+ SELECT lives_ok( '_test_this' );
+ DEALLOCATE ALL;
+ DELETE FROM verse.resource_providers;
+
+
+ SELECT diag_test_name( 'Resource provider with NULL recovery' );
+ PREPARE _test_this AS
+ INSERT INTO verse.resource_providers(
+ planet_id , resource_name_id ,
+ resprov_quantity_max , resprov_quantity ,
+ resprov_difficulty , resprov_recovery
+ ) VALUES (
+ _get_map_name( 'testPlanet1' ) , _get_string( 'testResource1' ) ,
+ 100 , 50 ,
+ 0.5 , NULL
+ );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Resource provider with recovery = 0' );
+ PREPARE _test_this AS
+ INSERT INTO verse.resource_providers(
+ planet_id , resource_name_id ,
+ resprov_quantity_max , resprov_quantity ,
+ resprov_difficulty , resprov_recovery
+ ) VALUES (
+ _get_map_name( 'testPlanet1' ) , _get_string( 'testResource1' ) ,
+ 100 , 50 ,
+ 0.5 , 0
+ );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Resource provider with recovery > 1' );
+ PREPARE _test_this AS
+ INSERT INTO verse.resource_providers(
+ planet_id , resource_name_id ,
+ resprov_quantity_max , resprov_quantity ,
+ resprov_difficulty , resprov_recovery
+ ) VALUES (
+ _get_map_name( 'testPlanet1' ) , _get_string( 'testResource1' ) ,
+ 100 , 50 ,
+ 0.5 , 1.5
+ );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Resource provider with recovery = 1' );
+ PREPARE _test_this AS
+ INSERT INTO verse.resource_providers(
+ planet_id , resource_name_id ,
+ resprov_quantity_max , resprov_quantity ,
+ resprov_difficulty , resprov_recovery
+ ) VALUES (
+ _get_map_name( 'testPlanet1' ) , _get_string( 'testResource1' ) ,
+ 100 , 50 ,
+ 0.5 , 1
+ );
+ SELECT lives_ok( '_test_this' );
+ DEALLOCATE ALL;
+ DELETE FROM verse.resource_providers;
+
+
+ SELECT * FROM finish( );
+ROLLBACK;
\ No newline at end of file
diff --git a/legacyworlds-server-data/db-structure/tests/admin/constraints/defs/11001-empire-resources.sql b/legacyworlds-server-data/db-structure/tests/admin/constraints/defs/11001-empire-resources.sql
new file mode 100644
index 0000000..06ace16
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/admin/constraints/defs/11001-empire-resources.sql
@@ -0,0 +1,191 @@
+/*
+ * Test constraints and foreign keys on emp.resources
+ */
+BEGIN;
+
+ /* We need to create a pair of resources and a pair of empires */
+ \i utils/strings.sql
+ \i utils/resources.sql
+ \i utils/accounts.sql
+ \i utils/naming.sql
+ SELECT _create_natural_resources( 2 , 'testResource' );
+ SELECT _create_emp_names( 2 , 'testUser' );
+ INSERT INTO emp.empires ( name_id , cash )
+ SELECT id , 0 FROM naming.empire_names;
+
+
+
+ /****** TESTS BEGIN HERE ******/
+ SELECT plan( 16 );
+
+
+ SELECT diag_test_name( 'Valid empire resources record' );
+ PREPARE _test_this AS
+ INSERT INTO emp.resources (
+ empire_id , resource_name_id , empres_possessed , empres_owed
+ ) VALUES (
+ _get_emp_name( 'testUser1' ) , _get_string( 'testResource1' ) ,
+ 1 , 1
+ );
+ SELECT lives_ok( '_test_this' );
+ DELETE FROM emp.resources;
+ DEALLOCATE ALL;
+
+ INSERT INTO emp.resources (
+ empire_id , resource_name_id
+ ) VALUES (
+ _get_emp_name( 'testUser1' ) , _get_string( 'testResource1' )
+ );
+ SELECT diag_test_name( 'Default possessed value in empire resources record' );
+ SELECT results_eq(
+ $$ SELECT empres_possessed FROM emp.resources $$ ,
+ $$ VALUES ( 0::DOUBLE PRECISION ) $$
+ );
+ SELECT diag_test_name( 'Default owed value in empire resources record' );
+ SELECT results_eq(
+ $$ SELECT empres_owed FROM emp.resources $$ ,
+ $$ VALUES ( 0::DOUBLE PRECISION ) $$
+ );
+ DELETE FROM emp.resources;
+
+
+ SELECT diag_test_name( 'NULL empire identifier in empire resources record' );
+ PREPARE _test_this AS
+ INSERT INTO emp.resources (
+ empire_id , resource_name_id , empres_possessed , empres_owed
+ ) VALUES (
+ NULL , _get_string( 'testResource1' ) ,
+ 1 , 1
+ );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Invalid empire identifier in empire resources record' );
+ PREPARE _test_this AS
+ INSERT INTO emp.resources (
+ empire_id , resource_name_id , empres_possessed , empres_owed
+ ) VALUES (
+ _get_bad_emp_name( ) , _get_string( 'testResource1' ) ,
+ 1 , 1
+ );
+ SELECT throws_ok( '_test_this' , 23503 );
+ DEALLOCATE ALL;
+
+
+ SELECT diag_test_name( 'NULL resource identifier in empire resources record' );
+ PREPARE _test_this AS
+ INSERT INTO emp.resources (
+ empire_id , resource_name_id , empres_possessed , empres_owed
+ ) VALUES (
+ _get_emp_name( 'testUser1' ) , NULL ,
+ 1 , 1
+ );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Invalid resource identifier in empire resources record' );
+ PREPARE _test_this AS
+ INSERT INTO emp.resources (
+ empire_id , resource_name_id , empres_possessed , empres_owed
+ ) VALUES (
+ _get_emp_name( 'testUser1' ) , _get_bad_string( ) ,
+ 1 , 1
+ );
+ SELECT throws_ok( '_test_this' , 23503 );
+ DEALLOCATE ALL;
+
+
+ SELECT diag_test_name( 'Duplicate empire resources record' );
+ PREPARE _test_this AS
+ INSERT INTO emp.resources (
+ empire_id , resource_name_id , empres_possessed , empres_owed
+ ) VALUES (
+ _get_emp_name( 'testUser1' ) , _get_string( 'testResource1' ) ,
+ 1 , 1
+ );
+ EXECUTE _test_this;
+ SELECT throws_ok( '_test_this' , 23505 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Empire resources record with same empire but different types of resources' );
+ PREPARE _test_this AS
+ INSERT INTO emp.resources (
+ empire_id , resource_name_id , empres_possessed , empres_owed
+ ) VALUES (
+ _get_emp_name( 'testUser1' ) , _get_string( 'testResource2' ) ,
+ 1 , 1
+ );
+ SELECT lives_ok( '_test_this' );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Empire resources record with different empires but same type of resources' );
+ PREPARE _test_this AS
+ INSERT INTO emp.resources (
+ empire_id , resource_name_id , empres_possessed , empres_owed
+ ) VALUES (
+ _get_emp_name( 'testUser2' ) , _get_string( 'testResource1' ) ,
+ 1 , 1
+ );
+ SELECT lives_ok( '_test_this' );
+ DEALLOCATE ALL;
+ DELETE FROM emp.resources;
+
+
+ INSERT INTO emp.resources (
+ empire_id , resource_name_id
+ ) VALUES (
+ _get_emp_name( 'testUser2' ) , _get_string( 'testResource1' )
+ );
+ SELECT diag_test_name( 'Empire deletion succeeds when empire resources records are present' );
+ PREPARE _test_this AS
+ DELETE FROM emp.empires WHERE name_id = _get_emp_name( 'testUser2' );
+ SELECT lives_ok( '_test_this' );
+ SELECT diag_test_name( 'Empire deletion causes empire resources record deletion' );
+ SELECT is_empty( 'SELECT * FROM emp.resources' );
+ DEALLOCATE ALL;
+
+
+ PREPARE _test_this AS
+ INSERT INTO emp.resources (
+ empire_id , resource_name_id , empres_possessed
+ ) VALUES (
+ _get_emp_name( 'testUser1' ) , _get_string( 'testResource1' ) , NULL
+ );
+ SELECT diag_test_name( 'NULL possessed value in empire resources record' );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+ PREPARE _test_this AS
+ INSERT INTO emp.resources (
+ empire_id , resource_name_id , empres_possessed
+ ) VALUES (
+ _get_emp_name( 'testUser1' ) , _get_string( 'testResource1' ) , -1
+ );
+ SELECT diag_test_name( 'Negative possessed value in empire resources record' );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+
+ PREPARE _test_this AS
+ INSERT INTO emp.resources (
+ empire_id , resource_name_id , empres_owed
+ ) VALUES (
+ _get_emp_name( 'testUser1' ) , _get_string( 'testResource1' ) , NULL
+ );
+ SELECT diag_test_name( 'NULL owed value in empire resources record' );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+ PREPARE _test_this AS
+ INSERT INTO emp.resources (
+ empire_id , resource_name_id , empres_owed
+ ) VALUES (
+ _get_emp_name( 'testUser1' ) , _get_string( 'testResource1' ) , -1
+ );
+ SELECT diag_test_name( 'Negative owed value in empire resources record' );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+
+ SELECT * FROM finish( );
+ROLLBACK;
\ No newline at end of file
diff --git a/legacyworlds-server-data/db-structure/tests/admin/constraints/defs/11002-empire-mining-settings.sql b/legacyworlds-server-data/db-structure/tests/admin/constraints/defs/11002-empire-mining-settings.sql
new file mode 100644
index 0000000..8fb1158
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/admin/constraints/defs/11002-empire-mining-settings.sql
@@ -0,0 +1,119 @@
+/*
+ * Test constraints and foreign keys on emp.mining_settings
+ */
+BEGIN;
+
+ /* We need to create a pair of resources and a pair of empires */
+ \i utils/strings.sql
+ \i utils/resources.sql
+ \i utils/accounts.sql
+ \i utils/naming.sql
+ SELECT _create_natural_resources( 2 , 'testResource' );
+ SELECT _create_emp_names( 2 , 'testUser' );
+ INSERT INTO emp.empires ( name_id , cash )
+ SELECT id , 0 FROM naming.empire_names;
+
+ /****** TESTS BEGIN HERE ******/
+ SELECT plan( 10 );
+
+
+ SELECT diag_test_name( 'Valid empire mining settings record' );
+ PREPARE _test_this AS
+ INSERT INTO emp.mining_settings(
+ empire_id , resource_name_id , empmset_weight
+ ) VALUES (
+ _get_emp_name( 'testUser1' ) , _get_string( 'testResource1' ) , 0
+ );
+ SELECT lives_ok( '_test_this' );
+
+ SELECT diag_test_name( 'Duplicate empire mining settings record' );
+ SELECT throws_ok( '_test_this' , 23505 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Empire mining settings records with same empire but different types' );
+ PREPARE _test_this AS
+ INSERT INTO emp.mining_settings(
+ empire_id , resource_name_id , empmset_weight
+ ) VALUES (
+ _get_emp_name( 'testUser1' ) , _get_string( 'testResource2' ) , 0
+ );
+ SELECT lives_ok( '_test_this' );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Empire mining settings records with same type but different empires' );
+ PREPARE _test_this AS
+ INSERT INTO emp.mining_settings(
+ empire_id , resource_name_id , empmset_weight
+ ) VALUES (
+ _get_emp_name( 'testUser2' ) , _get_string( 'testResource1' ) , 0
+ );
+ SELECT lives_ok( '_test_this' );
+ DEALLOCATE ALL;
+ DELETE FROM emp.mining_settings;
+
+
+ SELECT diag_test_name( 'Empire mining settings record with NULL empire identifier' );
+ PREPARE _test_this AS
+ INSERT INTO emp.mining_settings(
+ empire_id , resource_name_id , empmset_weight
+ ) VALUES (
+ NULL , _get_string( 'testResource1' ) , 0
+ );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Empire mining settings record with invalid empire identifier' );
+ PREPARE _test_this AS
+ INSERT INTO emp.mining_settings(
+ empire_id , resource_name_id , empmset_weight
+ ) VALUES (
+ _get_bad_emp_name( ) , _get_string( 'testResource1' ) , 0
+ );
+ SELECT throws_ok( '_test_this' , 23503 );
+ DEALLOCATE ALL;
+
+
+ SELECT diag_test_name( 'Empire mining settings record with NULL resource identifier' );
+ PREPARE _test_this AS
+ INSERT INTO emp.mining_settings(
+ empire_id , resource_name_id , empmset_weight
+ ) VALUES (
+ _get_emp_name( 'testUser1' ) , NULL , 0
+ );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Empire mining settings record with invalid resource identifier' );
+ PREPARE _test_this AS
+ INSERT INTO emp.mining_settings(
+ empire_id , resource_name_id , empmset_weight
+ ) VALUES (
+ _get_emp_name( 'testUser1' ) , _get_bad_string( ) , 0
+ );
+ SELECT throws_ok( '_test_this' , 23503 );
+ DEALLOCATE ALL;
+
+
+ SELECT diag_test_name( 'Empire mining settings record with NULL weight' );
+ PREPARE _test_this AS
+ INSERT INTO emp.mining_settings(
+ empire_id , resource_name_id , empmset_weight
+ ) VALUES (
+ _get_emp_name( 'testUser1' ) , _get_string( 'testResource1' ) , NULL
+ );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Empire mining settings record with weight < 0' );
+ PREPARE _test_this AS
+ INSERT INTO emp.mining_settings(
+ empire_id , resource_name_id , empmset_weight
+ ) VALUES (
+ _get_emp_name( 'testUser1' ) , _get_string( 'testResource1' ) , -1
+ );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+
+ SELECT * FROM finish( );
+ROLLBACK;
\ No newline at end of file
diff --git a/legacyworlds-server-data/db-structure/tests/admin/constraints/defs/11003-empire-planet-mining-settings.sql b/legacyworlds-server-data/db-structure/tests/admin/constraints/defs/11003-empire-planet-mining-settings.sql
new file mode 100644
index 0000000..ea1e154
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/admin/constraints/defs/11003-empire-planet-mining-settings.sql
@@ -0,0 +1,193 @@
+/*
+ * Test constraints and foreign keys on emp.mining_settings
+ */
+BEGIN;
+
+ /* We need to create a pair of resources, a pair of empires, a pair of planets, and resource providers */
+ \i utils/strings.sql
+ \i utils/resources.sql
+ \i utils/accounts.sql
+ \i utils/naming.sql
+ \i utils/universe.sql
+ SELECT _create_natural_resources( 2 , 'testResource' );
+ SELECT _create_emp_names( 2 , 'testUser' );
+ INSERT INTO emp.empires ( name_id , cash )
+ SELECT id , 0 FROM naming.empire_names;
+ SELECT _create_raw_planets( 2 , 'testPlanet' );
+ SELECT _create_resource_provider( 'testPlanet1' , 'testResource1' );
+ SELECT _create_resource_provider( 'testPlanet1' , 'testResource2' );
+ SELECT _create_resource_provider( 'testPlanet2' , 'testResource1' );
+ -- No provider for testResource2 on testPlanet2
+
+ /****** TESTS BEGIN HERE ******/
+ SELECT plan( 14 );
+
+
+ SELECT diag_test_name( 'Valid empire planet mining settings record' );
+ PREPARE _test_this AS
+ INSERT INTO emp.planet_mining_settings(
+ empire_id , planet_id ,
+ resource_name_id , emppmset_weight
+ ) VALUES (
+ _get_emp_name( 'testUser1' ) , _get_map_name( 'testPlanet1' ) ,
+ _get_string( 'testResource1' ) , 0
+ );
+ SELECT lives_ok( '_test_this' );
+
+ SELECT diag_test_name( 'Duplicate empire planet mining settings record' );
+ SELECT throws_ok( '_test_this' , 23505 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Empire planet mining settings records with different types' );
+ PREPARE _test_this AS
+ INSERT INTO emp.planet_mining_settings(
+ empire_id , planet_id ,
+ resource_name_id , emppmset_weight
+ ) VALUES (
+ _get_emp_name( 'testUser1' ) , _get_map_name( 'testPlanet1' ) ,
+ _get_string( 'testResource2' ) , 0
+ );
+ SELECT lives_ok( '_test_this' );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Empire planet mining settings records with different empires' );
+ PREPARE _test_this AS
+ INSERT INTO emp.planet_mining_settings(
+ empire_id , planet_id ,
+ resource_name_id , emppmset_weight
+ ) VALUES (
+ _get_emp_name( 'testUser2' ) , _get_map_name( 'testPlanet1' ) ,
+ _get_string( 'testResource1' ) , 0
+ );
+ SELECT lives_ok( '_test_this' );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Empire planet mining settings records with different planets' );
+ PREPARE _test_this AS
+ INSERT INTO emp.planet_mining_settings(
+ empire_id , planet_id ,
+ resource_name_id , emppmset_weight
+ ) VALUES (
+ _get_emp_name( 'testUser1' ) , _get_map_name( 'testPlanet2' ) ,
+ _get_string( 'testResource1' ) , 0
+ );
+ SELECT lives_ok( '_test_this' );
+ DEALLOCATE ALL;
+ DELETE FROM emp.mining_settings;
+
+
+ SELECT diag_test_name( 'Empire planet mining setting record with NULL empire identifier' );
+ PREPARE _test_this AS
+ INSERT INTO emp.planet_mining_settings(
+ empire_id , planet_id ,
+ resource_name_id , emppmset_weight
+ ) VALUES (
+ NULL , _get_map_name( 'testPlanet2' ) ,
+ _get_string( 'testResource1' ) , 0
+ );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Empire planet mining setting record with invalid empire identifier' );
+ PREPARE _test_this AS
+ INSERT INTO emp.planet_mining_settings(
+ empire_id , planet_id ,
+ resource_name_id , emppmset_weight
+ ) VALUES (
+ _get_bad_emp_name( ) , _get_map_name( 'testPlanet2' ) ,
+ _get_string( 'testResource1' ) , 0
+ );
+ SELECT throws_ok( '_test_this' , 23503 );
+ DEALLOCATE ALL;
+
+
+ SELECT diag_test_name( 'Empire planet mining setting record with NULL planet identifier' );
+ PREPARE _test_this AS
+ INSERT INTO emp.planet_mining_settings(
+ empire_id , planet_id ,
+ resource_name_id , emppmset_weight
+ ) VALUES (
+ _get_emp_name( 'testUser1' ) , NULL ,
+ _get_string( 'testResource1' ) , 0
+ );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Empire planet mining setting record with invalid planet identifier' );
+ PREPARE _test_this AS
+ INSERT INTO emp.planet_mining_settings(
+ empire_id , planet_id ,
+ resource_name_id , emppmset_weight
+ ) VALUES (
+ _get_emp_name( 'testUser1' ) , _get_bad_map_name( ) ,
+ _get_string( 'testResource1' ) , 0
+ );
+ SELECT throws_ok( '_test_this' , 23503 );
+ DEALLOCATE ALL;
+
+
+ SELECT diag_test_name( 'Empire planet mining setting record with NULL resource identifier' );
+ PREPARE _test_this AS
+ INSERT INTO emp.planet_mining_settings(
+ empire_id , planet_id ,
+ resource_name_id , emppmset_weight
+ ) VALUES (
+ _get_emp_name( 'testUser1' ) , _get_map_name( 'testPlanet2' ) ,
+ NULL , 0
+ );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Empire planet mining setting record with invalid resource identifier' );
+ PREPARE _test_this AS
+ INSERT INTO emp.planet_mining_settings(
+ empire_id , planet_id ,
+ resource_name_id , emppmset_weight
+ ) VALUES (
+ _get_emp_name( 'testUser1' ) , _get_map_name( 'testPlanet2' ) ,
+ _get_bad_string( ) , 0
+ );
+ SELECT throws_ok( '_test_this' , 23503 );
+ DEALLOCATE ALL;
+
+
+ SELECT diag_test_name( 'Empire planet mining setting record with invalid resource provider identifier' );
+ PREPARE _test_this AS
+ INSERT INTO emp.planet_mining_settings(
+ empire_id , planet_id ,
+ resource_name_id , emppmset_weight
+ ) VALUES (
+ _get_emp_name( 'testUser1' ) , _get_map_name( 'testPlanet2' ) ,
+ _get_string( 'testResource2' ) , 0
+ );
+ SELECT throws_ok( '_test_this' , 23503 );
+ DEALLOCATE ALL;
+
+
+ SELECT diag_test_name( 'Empire planet mining setting record with NULL weight' );
+ PREPARE _test_this AS
+ INSERT INTO emp.planet_mining_settings(
+ empire_id , planet_id ,
+ resource_name_id , emppmset_weight
+ ) VALUES (
+ _get_emp_name( 'testUser1' ) , _get_map_name( 'testPlanet1' ) ,
+ _get_string( 'testResource1' ) , NULL
+ );
+ SELECT throws_ok( '_test_this' , 23502 );
+ DEALLOCATE ALL;
+
+ SELECT diag_test_name( 'Empire planet mining setting record with weight < 0' );
+ PREPARE _test_this AS
+ INSERT INTO emp.planet_mining_settings(
+ empire_id , planet_id ,
+ resource_name_id , emppmset_weight
+ ) VALUES (
+ _get_emp_name( 'testUser1' ) , _get_map_name( 'testPlanet1' ) ,
+ _get_string( 'testResource1' ) , -1
+ );
+ SELECT throws_ok( '_test_this' , 23514 );
+ DEALLOCATE ALL;
+
+
+ SELECT * FROM finish( );
+ROLLBACK;
\ No newline at end of file
diff --git a/legacyworlds-server-data/db-structure/tests/utils/accounts.sql b/legacyworlds-server-data/db-structure/tests/utils/accounts.sql
new file mode 100644
index 0000000..b93c82a
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/utils/accounts.sql
@@ -0,0 +1,68 @@
+/*
+ * Utility functions used by unit tests
+ *
+ * User accounts
+ */
+
+
+/*
+ * Find a test address
+ */
+CREATE FUNCTION _find_address( TEXT ) RETURNS INT AS $$
+ SELECT id FROM users.addresses WHERE address = $1 || '@example.org';
+$$ LANGUAGE SQL;
+
+
+/*
+ * Create a set of user addresses using some prefix
+ */
+CREATE FUNCTION _create_addresses( _quantity INT , _prefix TEXT )
+ RETURNS VOID
+ AS $$
+DECLARE
+ i INT;
+BEGIN
+ i := 0;
+ WHILE i < _quantity
+ LOOP
+ i := i + 1;
+ BEGIN
+ INSERT INTO users.addresses ( address )
+ VALUES ( _prefix || i::TEXT || '@example.org' );
+ EXCEPTION
+ WHEN unique_violation THEN
+ -- Address already exists, that's nice
+ END;
+ END LOOP;
+END;
+$$ LANGUAGE plpgsql;
+
+
+/*
+ * Create a set of user accounts
+ */
+CREATE FUNCTION _create_accounts( _quantity INT , _prefix TEXT )
+ RETURNS VOID
+ AS $$
+DECLARE
+ i INT;
+BEGIN
+ PERFORM _create_test_strings( 0 );
+ PERFORM _create_addresses( _quantity , _prefix );
+ i := 0;
+ WHILE i < _quantity
+ LOOP
+ i := i + 1;
+ BEGIN
+ INSERT INTO users.credentials (
+ address_id , pass_md5 , pass_sha1 , language_id , credits
+ ) VALUES (
+ _find_address( _prefix || i::TEXT ) , '' , '' , _get_language( 't' ) , 0
+ );
+ EXCEPTION
+ WHEN unique_violation THEN
+ -- Account already exists
+ END;
+ END LOOP;
+END;
+$$ LANGUAGE plpgsql;
\ No newline at end of file
diff --git a/legacyworlds-server-data/db-structure/tests/utils/naming.sql b/legacyworlds-server-data/db-structure/tests/utils/naming.sql
new file mode 100644
index 0000000..56efb0a
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/utils/naming.sql
@@ -0,0 +1,93 @@
+/*
+ * Utility functions used by unit tests
+ *
+ * Naming system
+ */
+
+
+/*
+ * Obtain a map name identifier
+ */
+CREATE FUNCTION _get_map_name( TEXT ) RETURNS INT AS $$
+ SELECT id FROM naming.map_names WHERE name = $1;
+$$ LANGUAGE SQL;
+
+
+/*
+ * Obtain a map name identifier that does not exist
+ */
+CREATE FUNCTION _get_bad_map_name( ) RETURNS INT AS $$
+ SELECT MAX( id ) + 1 FROM naming.map_names;
+$$ LANGUAGE SQL;
+
+
+/*
+ * Create a few map names using a prefix
+ */
+CREATE FUNCTION _create_map_names( _quantity INT , _prefix TEXT )
+ RETURNS VOID
+ AS $$
+DECLARE
+ i INT;
+BEGIN
+ i := 0;
+ WHILE i < _quantity
+ LOOP
+ i := i + 1;
+ BEGIN
+ INSERT INTO naming.map_names (name) VALUES ( _prefix || i::TEXT );
+ EXCEPTION
+ WHEN unique_violation THEN
+ -- Ignore the error
+ END;
+ END LOOP;
+END;
+$$ LANGUAGE PLPGSQL;
+
+
+/*
+ * Get the empire that belongs to some user, based on that user's email
+ */
+CREATE FUNCTION _get_emp_name( TEXT ) RETURNS INT AS $$
+ SELECT id FROM naming.empire_names WHERE owner_id = _find_address( $1 );
+$$ LANGUAGE SQL;
+
+
+/*
+ * Obtain a map name identifier that does not exist
+ */
+CREATE FUNCTION _get_bad_emp_name( ) RETURNS INT AS $$
+ SELECT MAX( id ) + 1 FROM naming.empire_names;
+$$ LANGUAGE SQL;
+
+
+/*
+ * Create a few empire names using a prefix for user accounts.
+ * Empires are named "testX" independently of the user accounts.
+ */
+CREATE FUNCTION _create_emp_names( _quantity INT , _prefix TEXT )
+ RETURNS VOID
+ AS $$
+DECLARE
+ i INT;
+ j INT;
+BEGIN
+ PERFORM _create_accounts( _quantity , _prefix );
+ i := 0;
+ WHILE i < _quantity
+ LOOP
+ i := i + 1;
+ j := 0;
+ LOOP
+ BEGIN
+ INSERT INTO naming.empire_names ( owner_id , name )
+ VALUES ( _find_address( _prefix || i::TEXT ) , 'test' || j::TEXT );
+ EXIT;
+ EXCEPTION
+ WHEN unique_violation THEN
+ j := j + 1;
+ END;
+ END LOOP;
+ END LOOP;
+END;
+$$ LANGUAGE PLPGSQL;
\ No newline at end of file
diff --git a/legacyworlds-server-data/db-structure/tests/utils/resources.sql b/legacyworlds-server-data/db-structure/tests/utils/resources.sql
new file mode 100644
index 0000000..8cc3415
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/utils/resources.sql
@@ -0,0 +1,63 @@
+/*
+ * Utility functions used by unit tests
+ *
+ * Resources and natural resources
+ */
+
+
+/*
+ * Function that creates some quantity of resources
+ * All resources are created using the specified prefix for the strings
+ */
+CREATE FUNCTION _create_resources( _quantity INT , _prefix TEXT )
+ RETURNS VOID
+ AS $$
+DECLARE
+ i INT;
+BEGIN
+ PERFORM _create_test_strings( _quantity , _prefix );
+ PERFORM _create_test_strings( _quantity , _prefix || 'Description' );
+
+ i := 0;
+ WHILE i < _quantity
+ LOOP
+ i := i + 1;
+ INSERT INTO defs.resources (
+ resource_name_id , resource_description_id , resource_weight
+ ) VALUES (
+ _get_string( _prefix || i::TEXT ) ,
+ _get_string( _prefix || 'Description' || i::TEXT ) ,
+ i
+ );
+ END LOOP;
+END;
+$$ LANGUAGE PLPGSQL;
+
+
+/*
+ * Function that creates some quantity of /natural/ resources
+ * All resources are created using the specified prefix for the strings
+ */
+CREATE FUNCTION _create_natural_resources( _quantity INT , _prefix TEXT )
+ RETURNS VOID
+ AS $$
+DECLARE
+ i INT;
+BEGIN
+ PERFORM _create_resources( _quantity , _prefix );
+
+ i := 0;
+ WHILE i < _quantity
+ LOOP
+ i := i + 1;
+ INSERT INTO defs.natural_resources(
+ resource_name_id , natres_p_presence , natres_quantity_avg ,
+ natres_quantity_dev , natres_difficulty_avg ,
+ natres_difficulty_dev , natres_recovery_avg ,
+ natres_recovery_dev
+ ) VALUES (
+ _get_string( _prefix || i::TEXT ) , 0.5 , 100 , 1 , 0.5 , 0.05 , 0.5 , 0.05
+ );
+ END LOOP;
+END;
+$$ LANGUAGE PLPGSQL;
\ No newline at end of file
diff --git a/legacyworlds-server-data/db-structure/tests/utils/strings.sql b/legacyworlds-server-data/db-structure/tests/utils/strings.sql
new file mode 100644
index 0000000..33ead96
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/utils/strings.sql
@@ -0,0 +1,65 @@
+/*
+ * Utility functions used by unit tests
+ *
+ * I18N string creation and access
+ */
+
+
+/*
+ * Function that returns an invalid string identifier.
+ */
+CREATE FUNCTION _get_bad_string( ) RETURNS INT AS $$
+ SELECT MAX( id ) + 1 FROM defs.strings;
+$$ LANGUAGE SQL;
+
+
+/*
+ * Function that returns a language's identifier
+ */
+CREATE FUNCTION _get_language( TEXT ) RETURNS INT AS $$
+ SELECT id FROM defs.languages WHERE language = $1;
+$$ LANGUAGE SQL;
+
+
+/*
+ * Function that returns a string's identifier
+ */
+CREATE FUNCTION _get_string( TEXT ) RETURNS INT AS $$
+ SELECT id FROM defs.strings WHERE name = $1;
+$$ LANGUAGE SQL;
+
+
+/*
+ * Function that creates some quantity of test strings
+ */
+CREATE FUNCTION _create_test_strings( _quantity INT )
+ RETURNS VOID
+ AS $$
+DECLARE
+ i INT;
+BEGIN
+ PERFORM _create_test_strings( _quantity , 'test' );
+END;
+$$ LANGUAGE PLPGSQL;
+
+
+/*
+ * Function that creates some quantity of test strings using a specific prefix
+ */
+CREATE FUNCTION _create_test_strings( _quantity INT , _prefix TEXT )
+ RETURNS VOID
+ AS $$
+DECLARE
+ i INT;
+BEGIN
+ PERFORM defs.uoc_language( 't' , 'Test' );
+
+ i := 0;
+ WHILE i < _quantity
+ LOOP
+ i := i + 1;
+ PERFORM defs.uoc_translation( 't' , _prefix || i::TEXT ,
+ 'Test string #' || i::TEXT );
+ END LOOP;
+END;
+$$ LANGUAGE PLPGSQL;
diff --git a/legacyworlds-server-data/db-structure/tests/utils/universe.sql b/legacyworlds-server-data/db-structure/tests/utils/universe.sql
new file mode 100644
index 0000000..8a2a4bc
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/utils/universe.sql
@@ -0,0 +1,71 @@
+/*
+ * Utility functions used by unit tests
+ *
+ * Universe
+ */
+
+/*
+ * Create a new system at some coordinates and return its identifier
+ */
+CREATE FUNCTION _create_system( INT , INT ) RETURNS INT AS $$
+ INSERT INTO verse.systems ( x , y )
+ VALUES ( $1 , $2 )
+ RETURNING id;
+$$ LANGUAGE SQL;
+
+
+/*
+ * Create "raw" planets
+ */
+CREATE FUNCTION _create_raw_planets( _quantity INT , _prefix TEXT )
+ RETURNS VOID
+ AS $$
+DECLARE
+ _system INT;
+ _orbit INT;
+ i INT;
+BEGIN
+ PERFORM _create_map_names( _quantity , _prefix );
+
+ i := 0;
+ WHILE i < _quantity
+ LOOP
+ i := i + 1;
+
+ IF _system IS NULL
+ THEN
+ _system := _create_system( i , i );
+ _orbit := 1;
+ END IF;
+
+ INSERT INTO verse.planets(
+ name_id , system_id , orbit , picture , population
+ ) VALUES (
+ _get_map_name( _prefix || i::TEXT ) , _system , _orbit , 1 , 1
+ );
+
+ IF _orbit = 5
+ THEN
+ _system := NULL;
+ ELSE
+ _orbit := _orbit + 1;
+ END IF;
+ END LOOP;
+END;
+$$ LANGUAGE PLPGSQL;
+
+
+/*
+ * Create a resource provider
+ */
+CREATE FUNCTION _create_resource_provider( TEXT , TEXT ) RETURNS VOID AS $$
+ INSERT INTO verse.resource_providers(
+ planet_id , resource_name_id ,
+ resprov_quantity_max , resprov_quantity ,
+ resprov_difficulty , resprov_recovery
+ ) VALUES (
+ _get_map_name( $1 ) , _get_string( $2 ) ,
+ 100 , 50 ,
+ 0.5 , 0.5
+ );
+$$ LANGUAGE SQL;
\ No newline at end of file
diff --git a/legacyworlds-server-data/src/main/java/com/deepclone/lw/sqld/game/BuildingOutputType.java b/legacyworlds-server-data/src/main/java/com/deepclone/lw/sqld/game/BuildingOutputType.java
index 1301ef0..22b5bda 100644
--- a/legacyworlds-server-data/src/main/java/com/deepclone/lw/sqld/game/BuildingOutputType.java
+++ b/legacyworlds-server-data/src/main/java/com/deepclone/lw/sqld/game/BuildingOutputType.java
@@ -6,6 +6,7 @@ public enum BuildingOutputType {
WORK ,
CASH ,
DEF ,
- POP
+ POP ,
+ MINE
}
diff --git a/legacyworlds-server-main/data/buildables.xml b/legacyworlds-server-main/data/buildables.xml
index 5ba9554..5f9ed15 100644
--- a/legacyworlds-server-main/data/buildables.xml
+++ b/legacyworlds-server-main/data/buildables.xml
@@ -5,6 +5,9 @@
+
+
+
diff --git a/legacyworlds-server-main/data/buildables.xsd b/legacyworlds-server-main/data/buildables.xsd
index a3e80ab..0447edf 100644
--- a/legacyworlds-server-main/data/buildables.xsd
+++ b/legacyworlds-server-main/data/buildables.xsd
@@ -19,6 +19,7 @@
+
diff --git a/legacyworlds-server-main/data/i18n-text.xml b/legacyworlds-server-main/data/i18n-text.xml
index b148a45..aaf18ca 100644
--- a/legacyworlds-server-main/data/i18n-text.xml
+++ b/legacyworlds-server-main/data/i18n-text.xml
@@ -99,6 +99,12 @@ ${text}
Technology has advanced. The ultimate weapon is now available. Claim the awesome power of the Dreadnought and crush your enemies. Ever wanted a tank in space? Well, now you have it. All their base are belong to you.
+
+ Mine
+
+
+ Exactly what it says on the cover. Not the exploding kind, though. Even if that happens from time to time, anyway.
+
Ship parts factory
@@ -613,6 +619,12 @@ ${text}
La technologie a évolué. L'arme ultime est maintenant disponible. Revendiquez la puissance écrasante du cuirassé et pulvérisez vos opposants. Déjà rêvé d'un tank de l'espace ? Eh bien, maintenant, vous l'avez. All their base are belong to you.
+
+ Mine
+
+
+ Exactement ce qu'il y a marqué sur l'emballage. Enfin, ce n'est pas la variété qui explose. Même si parfois ça se produit quand même.
+
Fabrique de pièces de vaisseaux