From 74b6f2ab0984fe95fa4b44e14a47f0c84790e6c3 Mon Sep 17 00:00:00 2001
From: =?UTF-8?q?Emmanuel=20Beno=C3=AEt?= <tseeker@legacyworlds.com>
Date: Mon, 16 Jan 2012 12:35:20 +0100
Subject: [PATCH] Mining computation update

* Added various views and helper functions used by the mining
computation but which may be re-used in other parts.

* Added mining computation update type and associated update function

* New constants: game.resources.weightBase (the value used to compute
weights from mining settings) and game.resources.extraction (the
quantity extracted in a day from a full provider at difficulty 0)
---
 .../lw/beans/sys/ConstantsRegistrarBean.java  |   7 +
 .../parts/030-data/000-typedefs.sql           |   5 +-
 .../040-functions/145-resource-providers.sql  |  42 ++-
 .../parts/050-updates/120-planet-mining.sql   | 286 ++++++++++++++++++
 .../030-get-extraction-factor.sql             |  89 ++++++
 .../010-gu-pmc-weights-view.sql               |  44 +++
 .../020-gu-pmc-totals-view.sql                |  35 +++
 .../120-planet-mining/030-gu-pmc-get-data.sql |  89 ++++++
 .../040-gu-pmc-update-resource.sql            |  91 ++++++
 .../050-process-planet-mining-updates.sql     |  58 ++++
 .../dirty/010-mining-update-locks/prepare.sql |   8 +
 .../010-mining-update-locks/run-test.sql      | 104 +++++++
 .../030-get-extraction-factor.sql             |  13 +
 .../010-gu-pmc-weights-view.sql               |  11 +
 .../020-gu-pmc-totals-view.sql                |  11 +
 .../120-planet-mining/030-gu-pmc-get-data.sql |  11 +
 .../040-gu-pmc-update-resource.sql            |  13 +
 .../050-process-planet-mining-updates.sql     |  11 +
 .../setup-gu-pmc-get-data-test.sql            | 170 +++++++++++
 .../db-structure/tests/utils/locks-finder.sql |  43 +++
 20 files changed, 1139 insertions(+), 2 deletions(-)
 create mode 100644 legacyworlds-server-data/db-structure/parts/050-updates/120-planet-mining.sql
 create mode 100644 legacyworlds-server-data/db-structure/tests/admin/040-functions/145-resource-providers/030-get-extraction-factor.sql
 create mode 100644 legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/010-gu-pmc-weights-view.sql
 create mode 100644 legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/020-gu-pmc-totals-view.sql
 create mode 100644 legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/030-gu-pmc-get-data.sql
 create mode 100644 legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/040-gu-pmc-update-resource.sql
 create mode 100644 legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/050-process-planet-mining-updates.sql
 create mode 100644 legacyworlds-server-data/db-structure/tests/dirty/010-mining-update-locks/prepare.sql
 create mode 100644 legacyworlds-server-data/db-structure/tests/dirty/010-mining-update-locks/run-test.sql
 create mode 100644 legacyworlds-server-data/db-structure/tests/user/040-functions/145-resource-providers/030-get-extraction-factor.sql
 create mode 100644 legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/010-gu-pmc-weights-view.sql
 create mode 100644 legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/020-gu-pmc-totals-view.sql
 create mode 100644 legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/030-gu-pmc-get-data.sql
 create mode 100644 legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/040-gu-pmc-update-resource.sql
 create mode 100644 legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/050-process-planet-mining-updates.sql
 create mode 100644 legacyworlds-server-data/db-structure/tests/utils/common-setup/setup-gu-pmc-get-data-test.sql
 create mode 100644 legacyworlds-server-data/db-structure/tests/utils/locks-finder.sql

diff --git a/legacyworlds-server-beans-system/src/main/java/com/deepclone/lw/beans/sys/ConstantsRegistrarBean.java b/legacyworlds-server-beans-system/src/main/java/com/deepclone/lw/beans/sys/ConstantsRegistrarBean.java
index 38960a0..598e896 100644
--- a/legacyworlds-server-beans-system/src/main/java/com/deepclone/lw/beans/sys/ConstantsRegistrarBean.java
+++ b/legacyworlds-server-beans-system/src/main/java/com/deepclone/lw/beans/sys/ConstantsRegistrarBean.java
@@ -61,6 +61,13 @@ public class ConstantsRegistrarBean
 		cDesc = "Resource recovery dampener. Lower means less dampening";
 		defs.add( new ConstantDefinition( "game.resources.recoveryDampening" , "Natural resources" , cDesc , 1.5 , 1.0 ,
 				true ) );
+		cDesc = "Resource weight base value. This value is taken to the Xth power to compute the actual "
+				+ "weight when determining how mining work is distributed amongst a planet's resource providers.";
+		defs.add( new ConstantDefinition( "game.resources.weightBase" , "Natural resources" , cDesc , 10.0 , 1.1 ,
+				100.0 ) );
+		cDesc = "Resources extracted per work unit, per (real) day, from a full provider with minimal difficulty.";
+		defs.add( new ConstantDefinition( "game.resources.extraction" , "Natural resources" , cDesc , 1.0 , 1.0 ,
+				true ) );
 
 		// Happiness
 		String[] hcNames = {
diff --git a/legacyworlds-server-data/db-structure/parts/030-data/000-typedefs.sql b/legacyworlds-server-data/db-structure/parts/030-data/000-typedefs.sql
index ea6934d..ae64132 100644
--- a/legacyworlds-server-data/db-structure/parts/030-data/000-typedefs.sql
+++ b/legacyworlds-server-data/db-structure/parts/030-data/000-typedefs.sql
@@ -83,7 +83,10 @@ CREATE TYPE update_type	AS ENUM (
 	'PLANET_RES_REGEN' ,
 
 	/* Compute income and upkeep of planets */
-	'PLANET_MONEY'
+	'PLANET_MONEY' ,
+	
+	/* Compute mining results for planets owned by empires */
+	'PLANET_MINING'
 );
 
 -- Types of recapitulative e-mail messages
diff --git a/legacyworlds-server-data/db-structure/parts/040-functions/145-resource-providers.sql b/legacyworlds-server-data/db-structure/parts/040-functions/145-resource-providers.sql
index aec2a56..0dfccb2 100644
--- a/legacyworlds-server-data/db-structure/parts/040-functions/145-resource-providers.sql
+++ b/legacyworlds-server-data/db-structure/parts/040-functions/145-resource-providers.sql
@@ -98,4 +98,44 @@ CREATE VIEW emp.mining_settings_view
 
 GRANT SELECT
 	ON emp.mining_settings_view
-	TO :dbuser;
\ No newline at end of file
+	TO :dbuser;
+
+
+
+/*
+ * Compute a resource provider's extraction factor
+ * 
+ * This function computes the extraction factor - a multiplier which makes
+ * mining more costly if the difficulty is high or if a provider is almost
+ * empty - based on a provider's fill ratio and difficulty.
+ * 
+ * The complete formula can be read on the Wiki:
+ *		https://wiki.legacyworlds.com/wiki/Mining#Resource_provider_extraction
+ *
+ * Parameters:
+ * 		_fill_ratio		The ratio between the provider's current and maximal
+ *							quantities
+ *		_difficulty		The provider's extraction difficulty.
+ *
+ * Returns:
+ *		?				The provider's extraction factor
+ */
+DROP FUNCTION IF EXISTS verse.get_extraction_factor( 
+	DOUBLE PRECISION , DOUBLE PRECISION );
+CREATE FUNCTION verse.get_extraction_factor(
+		_fill_ratio DOUBLE PRECISION ,
+		_difficulty	DOUBLE PRECISION )
+	RETURNS DOUBLE PRECISION
+	STRICT IMMUTABLE
+	SECURITY INVOKER
+AS $get_extraction_factor$
+
+	SELECT ( 1 - $2 * 0.5 ) * POW( $1 , 1.5 + 2 * $2 );
+
+$get_extraction_factor$ LANGUAGE SQL;
+
+REVOKE EXECUTE
+	ON FUNCTION verse.get_extraction_factor( 
+		DOUBLE PRECISION , DOUBLE PRECISION )
+	FROM PUBLIC;
+
diff --git a/legacyworlds-server-data/db-structure/parts/050-updates/120-planet-mining.sql b/legacyworlds-server-data/db-structure/parts/050-updates/120-planet-mining.sql
new file mode 100644
index 0000000..dd16737
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/parts/050-updates/120-planet-mining.sql
@@ -0,0 +1,286 @@
+-- LegacyWorlds Beta 6
+-- PostgreSQL database scripts
+--
+-- Game updates - planet mining computations
+--
+-- Copyright(C) 2004-2012, DeepClone Development
+-- --------------------------------------------------------
+
+
+/*
+ * Mining computation weights view
+ * --------------------------------
+ * 
+ * This view computes the actual values used in the mining computations for
+ * each resource provider on all empire-owned planets.
+ * 
+ * Columns:
+ *		planet_id			The planet's identifier
+ *		resource_name_id	The resource type's identifier
+ *		pmc_weight			The computed weight
+ */
+DROP VIEW IF EXISTS sys.gu_pmc_weights_view CASCADE;
+CREATE VIEW sys.gu_pmc_weights_view
+	AS SELECT planet_id , resource_name_id ,
+				POW( sys.get_constant( 'game.resources.weightBase' ) ,
+					mset_weight ) AS pmc_weight
+			FROM emp.mining_settings_view;
+
+
+/*
+ * Mining computation - total weights view
+ * ----------------------------------------
+ *
+ * This view computes per-planet totals for actual mining weights.
+ * 
+ * Columns:
+ *		planet_id			The planet's identifier
+ *		pmc_total			The sum of all mining weights on the planet.
+ */
+DROP VIEW IF EXISTS sys.gu_pmc_totals_view CASCADE;
+CREATE VIEW sys.gu_pmc_totals_view
+	AS SELECT planet_id , SUM( pmc_weight ) AS pmc_total
+			FROM sys.gu_pmc_weights_view
+			GROUP BY planet_id;
+
+
+/*
+ * Planet mining update data
+ * --------------------------
+ * 
+ * This type is used by the records used by planet mining updates to compute a
+ * planet's mining output.
+ */
+DROP TYPE IF EXISTS sys.gu_pmc_data_type CASCADE;
+CREATE TYPE sys.gu_pmc_data_type AS (
+	/* The planet's identifier */
+	planet			INT ,
+
+	/* The resource's identifier */
+	resource		INT ,
+
+	/* The provider's quantity of resources */
+	quantity		DOUBLE PRECISION ,
+
+	/* The provider's maximal quantity of resources */
+	quantity_max	DOUBLE PRECISION ,
+
+	/* The provider's extraction difficulty */
+	difficulty		DOUBLE PRECISION ,
+
+	/* The empire who owns the planet, or NULL if the planet is neutral */
+	empire			INT ,
+
+	/* The planet's happiness, or NULL if the planet is neutral */
+	happiness		REAL ,
+
+	/* The weight computed from the resource's extraction priority as
+	 * set by either the empire in general or the planet-specific settings,
+	 * or NULL if the planet is neutral.
+	 */
+	weight			DOUBLE PRECISION ,
+
+	/* The total weight computed from either the empire-wide or the
+	 * planet-specific mining settings, or NULL if the planet is neutral.
+	 */
+	total_weight	DOUBLE PRECISION
+);
+
+
+
+/*
+ * Lock the rows and access the data used by the mining update
+ * 
+ * This function executes a single query which serves the dual purpose of
+ * locking all rows from various tables used by the planet mining update
+ * and returning the data needed by the computation.
+ *
+ * As far as locking is concerned, the following tables are locked: 
+ *	- Update records are already locked, so we don't care.
+ *	- Planets with resource providers are locked for share.
+ *	- Resource providers and corresponding resource records are locked
+ *		for update
+ *	- Resource definitions are locked for share.
+ *	- Owning empires, as well as their mining settings and any set of
+ *		planet-specific settings for one of the planets we're inspecting,
+ *		are locked for share.
+ *
+ * The data itself is returned as a set of rows using sys.gu_pmc_data_type 
+ * 
+ * Parameters:
+ *		_tick			The identifier of the current game update
+ */ 
+DROP FUNCTION IF EXISTS sys.gu_pmc_get_data( BIGINT );
+CREATE FUNCTION sys.gu_pmc_get_data( _tick BIGINT )
+	RETURNS SETOF sys.gu_pmc_data_type
+	STRICT VOLATILE
+	SECURITY INVOKER
+AS $gu_pmc_get_data$
+	SELECT planet_id AS planet ,
+			resource_name_id AS resource,
+			resprov_quantity AS quantity ,
+			resprov_quantity_max AS quantity_max ,
+			resprov_difficulty AS difficulty ,
+			empire_id AS empire ,
+			happiness ,
+			pmc_weight AS weight ,
+			pmc_total AS total_weight
+
+		FROM sys.updates _upd_sys
+			INNER JOIN verse.updates _upd_verse
+				ON _upd_sys.id = _upd_verse.update_id
+			INNER JOIN verse.planets _planet
+				ON _planet.name_id = _upd_verse.planet_id
+			INNER JOIN verse.resource_providers _resprov
+				USING ( planet_id )
+			INNER JOIN verse.planet_resources _pres
+				USING ( planet_id , resource_name_id )
+			LEFT OUTER JOIN (
+						SELECT _emp_planet.empire_id , _emp_planet.planet_id ,
+								_emset.resource_name_id , pmc_weight ,
+								pmc_total , _happ.current AS happiness
+		
+							FROM sys.updates _upd_sys
+								INNER JOIN verse.updates _upd_verse
+									ON _upd_sys.id = _upd_verse.update_id
+								INNER JOIN emp.planets _emp_planet
+									USING ( planet_id ) 
+								INNER JOIN emp.empires _emp
+									ON _emp_planet.empire_id = _emp.name_id
+								INNER JOIN emp.mining_settings _emset
+									USING ( empire_id )
+								INNER JOIN verse.planet_happiness _happ
+									USING ( planet_id )
+								INNER JOIN sys.gu_pmc_weights_view
+									USING ( planet_id , resource_name_id)
+								INNER JOIN sys.gu_pmc_totals_view
+									USING ( planet_id )
+								LEFT OUTER JOIN (
+											SELECT * FROM emp.planet_mining_settings
+												FOR SHARE
+										) AS _pmset
+									USING ( empire_id , planet_id , resource_name_id )
+	
+							WHERE _upd_sys.last_tick = $1
+								AND _upd_sys.status = 'PROCESSING'
+								AND _upd_sys.gu_type = 'PLANET_MINING'
+
+							FOR SHARE OF _emp_planet , _emp , _emset , _happ 
+					) AS _owner
+				USING ( planet_id , resource_name_id )
+	
+		WHERE _upd_sys.last_tick = $1
+			AND _upd_sys.status = 'PROCESSING'
+			AND _upd_sys.gu_type = 'PLANET_MINING'
+	
+		FOR UPDATE OF _resprov , _pres
+		FOR SHARE OF _planet ;
+$gu_pmc_get_data$ LANGUAGE SQL;
+
+
+REVOKE EXECUTE
+	ON FUNCTION sys.gu_pmc_get_data( BIGINT )
+	FROM PUBLIC;
+
+
+
+/*
+ * Update a planet's resource provider and corresponding resource record
+ *
+ * This function will compute the amount of resources extracted from a
+ * provider, and update both the provider itself and the corresponding
+ * resource record (setting the income to whatever quantity was extracted).
+ * 
+ * Parameters:
+ *		_input		Data about the resource provider to update
+ */
+DROP FUNCTION IF EXISTS sys.gu_pmc_update_resource( sys.gu_pmc_data_type );
+CREATE FUNCTION sys.gu_pmc_update_resource( _input sys.gu_pmc_data_type )
+		RETURNS VOID
+		STRICT VOLATILE
+		SECURITY INVOKER
+	AS $gu_pmc_update_resource$
+
+DECLARE
+	_extraction	DOUBLE PRECISION;
+	_allocation	DOUBLE PRECISION;
+	_production	DOUBLE PRECISION;
+	_quantity	DOUBLE PRECISION;
+
+BEGIN
+
+	_extraction := _input.quantity * verse.get_extraction_factor(
+		_input.quantity / _input.quantity_max ,
+		_input.difficulty );
+	_allocation := _input.weight / _input.total_weight;
+	_production := verse.adjust_production(
+			verse.get_raw_production( _input.planet , 'MINE' ) ,
+			_input.happiness )
+		* sys.get_constant( 'game.resources.extraction' )
+		/ 1440.0; -- FIXME: hardcoded!
+
+	RAISE NOTICE 'Extraction % , allocation % , production %' , _extraction , _allocation , _production;
+	_quantity := _allocation * _production * _extraction;
+	IF _quantity > _input.quantity THEN
+		_quantity := _input.quantity;
+	END IF;
+	
+	UPDATE verse.resource_providers
+		SET resprov_quantity = resprov_quantity - _quantity
+		WHERE planet_id = _input.planet
+			AND resource_name_id = _input.resource;
+	UPDATE verse.planet_resources
+		SET pres_income = _quantity
+		WHERE planet_id = _input.planet
+			AND resource_name_id = _input.resource;
+
+END;
+$gu_pmc_update_resource$ LANGUAGE PLPGSQL;
+
+REVOKE EXECUTE
+	ON FUNCTION sys.gu_pmc_update_resource( sys.gu_pmc_data_type )
+	FROM PUBLIC;
+
+
+
+/*
+ * Planet mining game update
+ * 
+ * Obtains all records to update for the current batch, then either set the
+ * income to 0 without modifying the resource provider if the planet is
+ * neutral, or call gu_pmc_update_resource() if there is an owner.
+ * 
+ * Parameters:
+ *		_tick		The current tick's identifier
+ */
+DROP FUNCTION IF EXISTS sys.process_planet_mining_updates( BIGINT );
+CREATE FUNCTION sys.process_planet_mining_updates( _tick BIGINT )
+		RETURNS VOID
+		STRICT VOLATILE
+		SECURITY INVOKER
+	AS $process_planet_mining_updates$
+
+DECLARE
+	_row		sys.gu_pmc_data_type;
+
+BEGIN
+	FOR _row IN SELECT * FROM sys.gu_pmc_get_data( _tick )
+	LOOP
+		IF _row.empire IS NULL THEN
+			-- Set resource income to 0 on neutrals
+			UPDATE verse.planet_resources
+				SET pres_income = 0
+				WHERE planet_id = _row.planet
+					AND resource_name_id = _row.resource;
+		ELSE
+			PERFORM sys.gu_pmc_update_resource( _row );
+		END IF;
+
+	END LOOP;
+END;
+$process_planet_mining_updates$ LANGUAGE PLPGSQL;
+
+
+REVOKE EXECUTE
+	ON FUNCTION sys.process_planet_mining_updates( BIGINT )
+	FROM PUBLIC;
diff --git a/legacyworlds-server-data/db-structure/tests/admin/040-functions/145-resource-providers/030-get-extraction-factor.sql b/legacyworlds-server-data/db-structure/tests/admin/040-functions/145-resource-providers/030-get-extraction-factor.sql
new file mode 100644
index 0000000..9a9bb34
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/admin/040-functions/145-resource-providers/030-get-extraction-factor.sql
@@ -0,0 +1,89 @@
+/*
+ * Test the verse.get_extraction_factor() function
+ */
+BEGIN;
+	/* Drop foreign keys on resource providers, then fill the table with
+	 * values which can be used to test some fundamental properties of
+	 * the computation, then create a view that returns computation results.
+	 */
+	ALTER TABLE verse.resource_providers
+		DROP CONSTRAINT fk_resprov_planet ,
+		DROP CONSTRAINT fk_resprov_resource;
+
+	CREATE FUNCTION _fill_providers( )
+			RETURNS VOID
+		AS $$
+	DECLARE
+		i	INT;
+		j	INT;
+	BEGIN
+		FOR i IN 0 .. 10
+		LOOP
+			FOR j IN 0 .. 10
+			LOOP
+				INSERT INTO verse.resource_providers(
+						planet_id , resource_name_id ,
+						resprov_quantity_max , resprov_quantity ,
+						resprov_difficulty , resprov_recovery
+					) VALUES (
+						i , j , 100 , j * 10 , i * 0.1 , 0.5
+					);
+			END LOOP;
+		END LOOP;
+	END;
+	$$ LANGUAGE PLPGSQL;
+	SELECT _fill_providers( );
+	DROP FUNCTION _fill_providers( );
+	
+	CREATE VIEW extraction_factor_view
+		AS SELECT planet_id , resource_name_id ,
+				verse.get_extraction_factor(
+					resprov_quantity / resprov_quantity_max ,
+					resprov_difficulty
+				) AS resprov_extraction
+			FROM verse.resource_providers;
+	
+	
+	/***** TESTS BEGIN HERE *****/
+	SELECT plan( 6 );
+
+	SELECT diag_test_name( 'verse.get_extraction_factor() - Range');
+	SELECT is_empty($$
+		SELECT * FROM extraction_factor_view
+			WHERE resprov_extraction NOT BETWEEN 0 AND 1
+	$$);
+
+	SELECT diag_test_name( 'verse.get_extraction_factor() - Full provider with difficulty 0 => extraction is 1');
+	SELECT is( resprov_extraction , 1.0::DOUBLE PRECISION )
+		FROM extraction_factor_view
+		WHERE planet_id = 0 AND resource_name_id = 10;
+	SELECT diag_test_name( 'verse.get_extraction_factor() - Full provider with difficulty 1 => extraction is 0.5');
+	SELECT is( resprov_extraction , 0.5::DOUBLE PRECISION )
+		FROM extraction_factor_view
+		WHERE planet_id = 10 AND resource_name_id = 10;
+	SELECT diag_test_name( 'verse.get_extraction_factor() - Empty provider => extraction is 0');
+	SELECT is_empty($$
+		SELECT * FROM extraction_factor_view
+			WHERE resource_name_id = 0 AND resprov_extraction > 0
+	$$);
+
+	SELECT diag_test_name( 'verse.get_extraction_factor() - At same quantity ratio, higher difficulty => lower extraction');
+	SELECT is_empty($$
+		SELECT * FROM extraction_factor_view v1
+				INNER JOIN extraction_factor_view v2
+					ON v1.resource_name_id = v2.resource_name_id
+			WHERE v1.planet_id > v2.planet_id
+				AND v1.resprov_extraction > v2.resprov_extraction
+	$$);
+
+	SELECT diag_test_name( 'verse.get_extraction_factor() - At same difficulty, higher quantity ratio => higher extraction');
+	SELECT is_empty($$
+		SELECT * FROM extraction_factor_view v1
+				INNER JOIN extraction_factor_view v2
+					ON v1.planet_id = v2.planet_id
+			WHERE v1.resource_name_id > v2.resource_name_id
+				AND v1.resprov_extraction < v2.resprov_extraction
+	$$);
+
+	SELECT * FROM finish( );
+ROLLBACK;
\ No newline at end of file
diff --git a/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/010-gu-pmc-weights-view.sql b/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/010-gu-pmc-weights-view.sql
new file mode 100644
index 0000000..d32e62f
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/010-gu-pmc-weights-view.sql
@@ -0,0 +1,44 @@
+/*
+ * Test sys.gu_pmc_weights_view
+ */
+BEGIN;
+	/* Create a table which will server as an alternate source for
+	 * emp.mining_settings_view ; the table is not temporary (PostgreSQL
+	 * won't allow replacing the view otherwise), but will be dropped
+	 * on rollback anyway. 
+	 */
+	CREATE TABLE fake_mining_settings(
+		planet_id			INT ,
+		resource_name_id	INT ,
+		mset_weight			INT ,
+		mset_specific		BOOLEAN
+	);
+
+	CREATE OR REPLACE VIEW emp.mining_settings_view
+		AS SELECT * FROM fake_mining_settings;
+
+	/* Insert fake records for each possible mining setting */
+	INSERT INTO fake_mining_settings VALUES
+		( 1 , 0 , 0 , FALSE ) ,
+		( 1 , 1 , 1 , FALSE ) ,
+		( 1 , 2 , 2 , FALSE ) ,
+		( 1 , 3 , 3 , FALSE ) ,
+		( 1 , 4 , 4 , FALSE );
+
+	/***** TESTS BEGIN HERE *****/
+	SELECT plan( 2 );
+
+	SELECT diag_test_name( 'sys.gu_pmc_weights_view - Rows present' );
+	SELECT isnt( COUNT(*)::INT , 0 )
+		FROM sys.gu_pmc_weights_view;
+
+	SELECT diag_test_name( 'sys.gu_pmc_weights_view - weight = game.resources.weightBase ^ setting' );
+	SELECT sys.uoc_constant( 'game.resources.weightBase' , '(test)' , 'Resources' , 10.0 );
+	SELECT is_empty( $$
+		SELECT * FROM sys.gu_pmc_weights_view
+			WHERE pmc_weight IS NULL
+				OR pmc_weight <> POW( 10 , resource_name_id )
+	$$ );
+
+	SELECT * FROM finish( );
+ROLLBACK;
\ No newline at end of file
diff --git a/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/020-gu-pmc-totals-view.sql b/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/020-gu-pmc-totals-view.sql
new file mode 100644
index 0000000..e1cfa4c
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/020-gu-pmc-totals-view.sql
@@ -0,0 +1,35 @@
+/*
+ * Test sys.gu_pmc_totals_view
+ */
+BEGIN;
+	/* Create a table which will server as an alternate source for
+	 * sys.gu_pmc_weights_view ; the table is not temporary (PostgreSQL
+	 * won't allow replacing the view otherwise), but will be dropped
+	 * on rollback anyway. 
+	 */
+	CREATE TABLE fake_mining_weights(
+		planet_id			INT ,
+		resource_name_id	INT ,
+		pmc_weight			DOUBLE PRECISION
+	);
+	
+	CREATE OR REPLACE VIEW sys.gu_pmc_weights_view
+		AS SELECT * FROM fake_mining_weights;
+
+	/* Insert fake records for two different planets */
+	INSERT INTO fake_mining_weights VALUES
+		( 1 , 0 , 1 ) ,
+		( 1 , 1 , 2 ) ,
+		( 2 , 0 , 4 ) ,
+		( 2 , 1 , 5 );
+
+	/***** TESTS BEGIN HERE *****/
+	SELECT plan( 1 );
+	
+	SELECT set_eq(
+		$$ SELECT * FROM sys.gu_pmc_totals_view $$ ,
+		$$ VALUES ( 1 , 3.0 ) , ( 2 , 9.0 ) $$
+	);
+
+	SELECT * FROM finish( );
+ROLLBACK;
\ No newline at end of file
diff --git a/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/030-gu-pmc-get-data.sql b/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/030-gu-pmc-get-data.sql
new file mode 100644
index 0000000..7765aa2
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/030-gu-pmc-get-data.sql
@@ -0,0 +1,89 @@
+/*
+ * Test the sys.gu_pmc_get_data() function
+ */
+BEGIN;
+	\i utils/common-setup/setup-gu-pmc-get-data-test.sql
+
+	/* Select results into a temporary table */
+	CREATE TEMPORARY TABLE test_results
+		AS SELECT * FROM sys.gu_pmc_get_data( 0 );
+
+
+
+	/***** TESTS BEGIN HERE *****/
+	SELECT no_plan( );
+	
+	SELECT diag_test_name( 'sys.gu_pmc_get_data() - Neutral planet without resource providers not included' );
+	SELECT is_empty( $$
+		SELECT * FROM test_results
+			WHERE planet = _get_map_name ( 'planet1' );
+	$$ );
+
+	SELECT diag_test_name( 'sys.gu_pmc_get_data() - Neutral planet with resource providers - Rows included' );
+	SELECT is( COUNT(*)::INT , 2)
+		FROM test_results
+		WHERE planet = _get_map_name ( 'planet2' )
+			AND difficulty = 0.2 AND empire IS NULL
+			AND happiness IS NULL AND weight IS NULL
+			AND total_weight IS NULL;
+	SELECT diag_test_name( 'sys.gu_pmc_get_data() - Neutral planet with resource providers - No extra rows' );
+	SELECT is_empty( $$
+		SELECT * FROM test_results
+			WHERE planet = _get_map_name ( 'planet2' )
+				AND NOT ( difficulty = 0.2 AND empire IS NULL
+					AND happiness IS NULL AND weight IS NULL
+					AND total_weight IS NULL );
+	$$ );
+
+	SELECT diag_test_name( 'sys.gu_pmc_get_data() - Planet using empire settings - Rows included' );
+	SELECT is( COUNT(*)::INT , 2)
+		FROM test_results
+		WHERE planet = _get_map_name ( 'planet3' ) AND difficulty = 0.3
+			AND empire = _get_emp_name( 'empire1' )
+			AND happiness IS NOT NULL AND weight = 100
+			AND total_weight = 200;
+	SELECT diag_test_name( 'sys.gu_pmc_get_data() - Planet using empire settings - No extra rows' );
+	SELECT is_empty( $$
+		SELECT * FROM test_results
+			WHERE planet = _get_map_name ( 'planet3' )
+				AND NOT ( difficulty = 0.3
+					AND empire = _get_emp_name( 'empire1' )
+					AND happiness IS NOT NULL
+					AND weight = 100 AND total_weight = 200 );
+	$$ );
+
+	SELECT diag_test_name( 'sys.gu_pmc_get_data() - Planet using specific settings - Rows included' );
+	SELECT is( COUNT(*)::INT , 2)
+		FROM test_results
+		WHERE planet = _get_map_name ( 'planet4' ) AND difficulty = 0.4
+			AND empire = _get_emp_name( 'empire2' )
+			AND happiness IS NOT NULL AND (
+				( resource = _get_string( 'resource1' ) AND weight = 10 )
+				OR ( resource = _get_string( 'resource2' ) AND weight = 1000 ) )
+			AND total_weight = 1010;
+	SELECT diag_test_name( 'sys.gu_pmc_get_data() - Planet using specific settings - No extra rows' );
+	SELECT is_empty( $$
+		SELECT * FROM test_results
+			WHERE planet = _get_map_name ( 'planet4' )
+				AND NOT ( difficulty = 0.4
+					AND empire = _get_emp_name( 'empire2' )
+					AND happiness IS NOT NULL
+					AND total_weight = 1010 AND (
+						( resource = _get_string( 'resource1' ) AND weight = 10 )
+						OR ( resource = _get_string( 'resource2' ) AND weight = 1000 ) ) );
+	$$ );
+	
+	SELECT diag_test_name( 'sys.gu_pmc_get_data() - Owned planet without resource providers not included' );
+	SELECT is_empty( $$
+		SELECT * FROM test_results
+			WHERE planet = _get_map_name ( 'planet5' );
+	$$ );
+	
+	SELECT diag_test_name( 'sys.gu_pmc_get_data() - Planet matching all criterias but marked as processed not included' );
+	SELECT is_empty( $$
+		SELECT * FROM test_results
+			WHERE planet = _get_map_name ( 'planet6' );
+	$$ );
+
+	SELECT * FROM finish( );
+ROLLBACK;
\ No newline at end of file
diff --git a/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/040-gu-pmc-update-resource.sql b/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/040-gu-pmc-update-resource.sql
new file mode 100644
index 0000000..c8181f2
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/040-gu-pmc-update-resource.sql
@@ -0,0 +1,91 @@
+/*
+ * Test the sys.gu_pmc_update_resource() function
+ */
+BEGIN;
+	/*
+	 * We need to create a set of both resource providers and planet resource
+	 * records that will be updated by the function when it is called. We
+	 * disable foreign keys on both tables, as it makes things simpler. We
+	 * also replace verse.get_raw_production(), verse.get_extraction_factor( )
+	 * and verse.adjust_production() so that they return fixed values, and we
+	 * need to set the game.resources.extraction constant.
+	 */
+	ALTER TABLE verse.resource_providers
+		DROP CONSTRAINT fk_resprov_planet ,
+		DROP CONSTRAINT fk_resprov_resource;
+	ALTER TABLE verse.planet_resources
+		DROP CONSTRAINT fk_pres_planet ,
+		DROP CONSTRAINT fk_pres_resource;
+
+	INSERT INTO verse.resource_providers(
+			planet_id , resource_name_id , resprov_quantity_max, resprov_quantity ,
+			resprov_difficulty , resprov_recovery
+		) VALUES (
+			1 , 1 , 1000 , 1000 , 0 , 0.5
+		);
+
+	INSERT INTO verse.planet_resources(
+			planet_id , resource_name_id , pres_income , pres_upkeep
+		) VALUES (
+			1 , 1 , 0 , 0
+		);
+
+	CREATE OR REPLACE FUNCTION verse.get_raw_production( pid INT , pt building_output_type )
+		RETURNS REAL
+	AS $$
+		SELECT 1.0::REAL;
+	$$ LANGUAGE SQL;
+
+	CREATE OR REPLACE FUNCTION verse.adjust_production( prod REAL , happiness REAL )
+		RETURNS REAL
+	AS $$
+		SELECT 1.0::REAL;
+	$$ LANGUAGE SQL;
+
+	CREATE OR REPLACE FUNCTION verse.get_extraction_factor( _fill_ratio DOUBLE PRECISION , _difficulty DOUBLE PRECISION )
+		RETURNS DOUBLE PRECISION
+	AS $$
+		SELECT ( CASE WHEN $1 = 1.0 AND $2 = 0 THEN 0.002 ELSE 0.0 END )::DOUBLE PRECISION;
+	$$ LANGUAGE SQL;
+
+	SELECT sys.uoc_constant( 'game.resources.extraction' , '(test)' , 'Resources' , 1440.0 );
+	ALTER FUNCTION sys.get_constant( TEXT ) VOLATILE;
+
+
+	/***** TESTS BEGIN HERE *****/
+	SELECT plan( 4 );
+
+	SELECT sys.gu_pmc_update_resource( ROW(
+		1 , 1 , 1000.0 , 1000.0 , 0.0 , NULL , 1.0 , 0.5 , 1.0
+	) );
+	
+	SELECT diag_test_name( 'sys.gu_pmc_update_resource( ) - Provider udpated' );
+	SELECT is( resprov_quantity , 999.0::DOUBLE PRECISION )
+		FROM verse.resource_providers
+		WHERE planet_id = 1 AND resource_name_id = 1;
+	
+	SELECT diag_test_name( 'sys.gu_pmc_update_resource( ) - Planet resources income udpated' );
+	SELECT is( pres_income , 1.0::DOUBLE PRECISION )
+		FROM verse.planet_resources
+		WHERE planet_id = 1 AND resource_name_id = 1;
+
+	UPDATE verse.resource_providers SET resprov_quantity = resprov_quantity_max;
+	UPDATE sys.constant_definitions
+		SET c_value = 14400000.0
+		WHERE name = 'game.resources.extraction';
+	SELECT sys.gu_pmc_update_resource( ROW(
+		1 , 1 , 1000.0 , 1000.0 , 0.0 , NULL , 1.0 , 0.5 , 1.0
+	) );
+
+	SELECT diag_test_name( 'sys.gu_pmc_update_resource( ) - Bounded extraction quantity (1/2)' );
+	SELECT is( resprov_quantity , 0.0::DOUBLE PRECISION )
+		FROM verse.resource_providers
+		WHERE planet_id = 1 AND resource_name_id = 1;
+
+	SELECT diag_test_name( 'sys.gu_pmc_update_resource( ) - Bounded extraction quantity (2/2)' );
+	SELECT is( pres_income , 1000.0::DOUBLE PRECISION )
+		FROM verse.planet_resources
+		WHERE planet_id = 1 AND resource_name_id = 1;
+
+	SELECT * FROM finish( );
+ROLLBACK;
\ No newline at end of file
diff --git a/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/050-process-planet-mining-updates.sql b/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/050-process-planet-mining-updates.sql
new file mode 100644
index 0000000..4c449b6
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/admin/050-updates/120-planet-mining/050-process-planet-mining-updates.sql
@@ -0,0 +1,58 @@
+/*
+ * Test the sys.process_planet_mining_updates() function
+ */
+BEGIN;
+	/*
+	 * Create a fake planet resource record which will be updated by the
+	 * function (dropping the foreign key is therefore needed).
+	 */
+	ALTER TABLE verse.planet_resources
+		DROP CONSTRAINT fk_pres_planet ,
+		DROP CONSTRAINT fk_pres_resource;
+
+	INSERT INTO verse.planet_resources(
+			planet_id , resource_name_id , pres_income , pres_upkeep
+		) VALUES (
+			1 , 1 , 42 , 0
+		);
+
+	/*
+	 * Create a table which contains the values which will be returned by
+	 * the fake sys.gu_pmc_get_data( ).
+	 */
+	CREATE TABLE _fake_update_data OF sys.gu_pmc_data_type;
+	INSERT INTO _fake_update_data VALUES (
+		1 , 1 , 1000.0 , 1000.0 , 0.5 , NULL , NULL , NULL , NULL ) ,
+		( 2 , 1 , 1000.0 , 1000.0 , 0.5 , 1 , 0.5 , 1.0 , 1.0 );
+	CREATE OR REPLACE FUNCTION sys.gu_pmc_get_data( _tick BIGINT )
+		RETURNS SETOF sys.gu_pmc_data_type
+	AS $$
+		SELECT * FROM _fake_update_data;
+	$$ LANGUAGE SQL;
+
+	/*
+	 * Replace sys.gu_pmc_update_resource() so it deletes records from the
+	 * table.
+	 */
+	CREATE OR REPLACE FUNCTION sys.gu_pmc_update_resource( _input sys.gu_pmc_data_type )
+		RETURNS VOID
+	AS $$
+		DELETE FROM _fake_update_data WHERE planet = $1.planet AND resource = $1.resource;
+	$$ LANGUAGE SQL;
+	
+
+	/***** TESTS BEGIN HERE *****/
+	SELECT no_plan( );
+	
+	SELECT sys.process_planet_mining_updates( 0 );
+
+	SELECT diag_test_name( 'sys.process_planet_mining_updates() - Neutral planets updated' );
+	SELECT is( pres_income , 0::DOUBLE PRECISION ) FROM verse.planet_resources;
+
+	SELECT diag_test_name( 'sys.process_planet_mining_updates() - Owned planets updated' );
+	SELECT is_empty(
+		$$ SELECT * FROM _fake_update_data WHERE planet = 2 $$
+	);
+
+	SELECT * FROM finish( );
+ROLLBACK;
\ No newline at end of file
diff --git a/legacyworlds-server-data/db-structure/tests/dirty/010-mining-update-locks/prepare.sql b/legacyworlds-server-data/db-structure/tests/dirty/010-mining-update-locks/prepare.sql
new file mode 100644
index 0000000..674e320
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/dirty/010-mining-update-locks/prepare.sql
@@ -0,0 +1,8 @@
+/*
+ * Prepare for the locking tests on sys.gu_pmc_get_data() 
+ */
+BEGIN;
+	CREATE EXTENSION pageinspect;
+	\i utils/common-setup/setup-gu-pmc-get-data-test.sql
+	\i utils/locks-finder.sql
+COMMIT;
\ No newline at end of file
diff --git a/legacyworlds-server-data/db-structure/tests/dirty/010-mining-update-locks/run-test.sql b/legacyworlds-server-data/db-structure/tests/dirty/010-mining-update-locks/run-test.sql
new file mode 100644
index 0000000..1cb5b65
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/dirty/010-mining-update-locks/run-test.sql
@@ -0,0 +1,104 @@
+/*
+ * Test the locks set by sys.gu_pmc_get_data( )
+ */
+BEGIN;
+	SELECT * FROM sys.gu_pmc_get_data( 0 );
+	SELECT plan( 7 );
+
+	SELECT diag_test_name( 'sys.gu_pmc_get_data() - Locks on planets' );
+	SELECT set_eq ( $$
+			SELECT name_id , shared , exclusive
+				FROM verse.planets pl
+					INNER JOIN ( SELECT * FROM _get_locks_on( 'verse.planets' ) ) p
+						ON p.ctid = pl.ctid;
+		$$ , $$
+			VALUES ( _get_map_name( 'planet2' ) , TRUE , FALSE ) ,
+				( _get_map_name( 'planet3' ) , TRUE , FALSE ) ,
+				( _get_map_name( 'planet4' ) , TRUE , FALSE );
+		$$
+	);
+
+	SELECT diag_test_name( 'sys.gu_pmc_get_data() - Locks on resource providers' );
+	SELECT set_eq ( $$
+			SELECT planet_id , resource_name_id , shared , exclusive
+				FROM verse.resource_providers rp
+					INNER JOIN ( SELECT * FROM _get_locks_on( 'verse.resource_providers' ) ) p
+						ON p.ctid = rp.ctid;
+		$$ , $$
+			VALUES ( _get_map_name( 'planet2' ) , _get_string('resource1') , FALSE , TRUE ) ,
+				( _get_map_name( 'planet2' ) , _get_string('resource2') , FALSE , TRUE ) ,
+				( _get_map_name( 'planet3' ) , _get_string('resource1') , FALSE , TRUE ) ,
+				( _get_map_name( 'planet3' ) , _get_string('resource2') , FALSE , TRUE ) ,
+				( _get_map_name( 'planet4' ) , _get_string('resource1') , FALSE , TRUE ) ,
+				( _get_map_name( 'planet4' ) , _get_string('resource2') , FALSE , TRUE );
+		$$
+	);
+
+	SELECT diag_test_name( 'sys.gu_pmc_get_data() - Locks on planet resources' );
+	SELECT set_eq ( $$
+			SELECT planet_id , resource_name_id , shared , exclusive
+				FROM verse.planet_resources pr
+					INNER JOIN ( SELECT * FROM _get_locks_on( 'verse.planet_resources' ) ) p
+						ON p.ctid = pr.ctid;
+		$$ , $$
+			VALUES ( _get_map_name( 'planet2' ) , _get_string('resource1') , FALSE , TRUE ) ,
+				( _get_map_name( 'planet2' ) , _get_string('resource2') , FALSE , TRUE ) ,
+				( _get_map_name( 'planet3' ) , _get_string('resource1') , FALSE , TRUE ) ,
+				( _get_map_name( 'planet3' ) , _get_string('resource2') , FALSE , TRUE ) ,
+				( _get_map_name( 'planet4' ) , _get_string('resource1') , FALSE , TRUE ) ,
+				( _get_map_name( 'planet4' ) , _get_string('resource2') , FALSE , TRUE );
+		$$
+	);
+
+	SELECT diag_test_name( 'sys.gu_pmc_get_data() - Locks on empire planets' );
+	SELECT set_eq ( $$
+			SELECT planet_id , empire_id , shared , exclusive
+				FROM emp.planets ep
+					INNER JOIN ( SELECT * FROM _get_locks_on( 'emp.planets' ) ) p
+						ON p.ctid = ep.ctid;
+		$$ , $$
+			VALUES ( _get_map_name( 'planet3' ) , _get_emp_name('empire1' ) , TRUE , FALSE ) ,
+				( _get_map_name( 'planet4' ) , _get_emp_name('empire2' ) , TRUE , FALSE );
+		$$
+	);
+
+	SELECT diag_test_name( 'sys.gu_pmc_get_data() - Locks on mining settings' );
+	SELECT set_eq ( $$
+			SELECT empire_id , resource_name_id , shared , exclusive
+				FROM emp.mining_settings ms
+					INNER JOIN ( SELECT * FROM _get_locks_on( 'emp.mining_settings' ) ) p
+						ON p.ctid = ms.ctid;
+		$$ , $$
+			VALUES ( _get_emp_name('empire1' ) , _get_string( 'resource1' ) , TRUE , FALSE ) ,
+				( _get_emp_name('empire1' ) , _get_string( 'resource2' ) , TRUE , FALSE ) ,
+				( _get_emp_name('empire2' ) , _get_string( 'resource1' ) , TRUE , FALSE ) ,
+				( _get_emp_name('empire2' ) , _get_string( 'resource2' ) , TRUE , FALSE );
+		$$
+	);
+
+	SELECT diag_test_name( 'sys.gu_pmc_get_data() - Locks on planet mining settings' );
+	SELECT set_eq ( $$
+			SELECT empire_id , planet_id , resource_name_id , shared , exclusive
+				FROM emp.planet_mining_settings ms
+					INNER JOIN ( SELECT * FROM _get_locks_on( 'emp.planet_mining_settings' ) ) p
+						ON p.ctid = ms.ctid;
+		$$ , $$
+			VALUES ( _get_emp_name('empire2' ) , _get_map_name( 'planet4' ) , _get_string( 'resource1' ) , TRUE , FALSE ) ,
+				( _get_emp_name('empire2' ) , _get_map_name( 'planet4' ) , _get_string( 'resource2' ) , TRUE , FALSE );
+		$$
+	);
+
+	SELECT diag_test_name( 'sys.gu_pmc_get_data() - Locks on planet happiness records' );
+	SELECT set_eq ( $$
+			SELECT planet_id , shared , exclusive
+				FROM verse.planet_happiness pl
+					INNER JOIN ( SELECT * FROM _get_locks_on( 'verse.planet_happiness' ) ) p
+						ON p.ctid = pl.ctid;
+		$$ , $$
+			VALUES ( _get_map_name( 'planet3' ) , TRUE , FALSE ) ,
+				( _get_map_name( 'planet4' ) , TRUE , FALSE );
+		$$
+	);
+
+	SELECT * FROM finish( );
+ROLLBACK;
\ No newline at end of file
diff --git a/legacyworlds-server-data/db-structure/tests/user/040-functions/145-resource-providers/030-get-extraction-factor.sql b/legacyworlds-server-data/db-structure/tests/user/040-functions/145-resource-providers/030-get-extraction-factor.sql
new file mode 100644
index 0000000..880a55e
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/user/040-functions/145-resource-providers/030-get-extraction-factor.sql
@@ -0,0 +1,13 @@
+/*
+ * Test privileges on verse.get_extraction_factor()
+ */
+BEGIN;
+	SELECT plan( 1 );
+
+	SELECT diag_test_name( 'verse.get_extraction_factor() - Privileges' );
+	SELECT throws_ok( $$
+		SELECT verse.get_extraction_factor( 0.5 , 0.5 )
+	$$ , 42501 );
+	
+	SELECT * FROM finish( );
+ROLLBACK;
\ No newline at end of file
diff --git a/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/010-gu-pmc-weights-view.sql b/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/010-gu-pmc-weights-view.sql
new file mode 100644
index 0000000..adb0975
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/010-gu-pmc-weights-view.sql
@@ -0,0 +1,11 @@
+/*
+ * Test privileges on sys.gu_pmc_weights_view
+ */
+BEGIN;
+	SELECT plan( 1 );
+
+	SELECT diag_test_name( 'sys.gu_pmc_weights_view - Privileges' );
+	SELECT throws_ok( 'SELECT * FROM sys.gu_pmc_weights_view' , 42501 );
+	
+	SELECT * FROM finish( );
+ROLLBACK;
\ No newline at end of file
diff --git a/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/020-gu-pmc-totals-view.sql b/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/020-gu-pmc-totals-view.sql
new file mode 100644
index 0000000..f4d2b70
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/020-gu-pmc-totals-view.sql
@@ -0,0 +1,11 @@
+/*
+ * Test privileges on sys.gu_pmc_totals_view
+ */
+BEGIN;
+	SELECT plan( 1 );
+
+	SELECT diag_test_name( 'sys.gu_pmc_totals_view - Privileges' );
+	SELECT throws_ok( 'SELECT * FROM sys.gu_pmc_totals_view' , 42501 );
+	
+	SELECT * FROM finish( );
+ROLLBACK;
\ No newline at end of file
diff --git a/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/030-gu-pmc-get-data.sql b/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/030-gu-pmc-get-data.sql
new file mode 100644
index 0000000..9407cfb
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/030-gu-pmc-get-data.sql
@@ -0,0 +1,11 @@
+/*
+ * Test privileges on sys.gu_pmc_get_data( )
+ */
+BEGIN;
+	SELECT plan( 1 );
+
+	SELECT diag_test_name( 'sys.gu_pmc_get_data - Privileges' );
+	SELECT throws_ok( 'SELECT * FROM sys.gu_pmc_get_data( 0 )' , 42501 );
+	
+	SELECT * FROM finish( );
+ROLLBACK;
\ No newline at end of file
diff --git a/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/040-gu-pmc-update-resource.sql b/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/040-gu-pmc-update-resource.sql
new file mode 100644
index 0000000..7de5605
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/040-gu-pmc-update-resource.sql
@@ -0,0 +1,13 @@
+/*
+ * Test privileges on sys.gu_pmc_update_resource( )
+ */
+BEGIN;
+	SELECT plan( 1 );
+
+	SELECT diag_test_name( 'sys.gu_pmc_update_resource - Privileges' );
+	SELECT throws_ok( $$
+		SELECT * FROM sys.gu_pmc_update_resource( ROW( NULL , NULL , NULL , NULL , NULL , NULL , NULL , NULL , NULL ) );
+	$$ , 42501 );
+	
+	SELECT * FROM finish( );
+ROLLBACK;
\ No newline at end of file
diff --git a/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/050-process-planet-mining-updates.sql b/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/050-process-planet-mining-updates.sql
new file mode 100644
index 0000000..03c1616
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/user/050-updates/120-planet-mining/050-process-planet-mining-updates.sql
@@ -0,0 +1,11 @@
+/*
+ * Test privileges on sys.process_planet_mining_updates( )
+ */
+BEGIN;
+	SELECT plan( 1 );
+
+	SELECT diag_test_name( 'sys.process_planet_mining_updates() - Privileges' );
+	SELECT throws_ok( 'SELECT * FROM sys.process_planet_mining_updates( 0 )' , 42501 );
+	
+	SELECT * FROM finish( );
+ROLLBACK;
\ No newline at end of file
diff --git a/legacyworlds-server-data/db-structure/tests/utils/common-setup/setup-gu-pmc-get-data-test.sql b/legacyworlds-server-data/db-structure/tests/utils/common-setup/setup-gu-pmc-get-data-test.sql
new file mode 100644
index 0000000..97df95f
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/utils/common-setup/setup-gu-pmc-get-data-test.sql
@@ -0,0 +1,170 @@
+/*
+ * We need rows in quite a few tables to make sure locking works as
+ * advertised.
+ *
+ * - First we will need a planet with no resource providers. This one
+ *   shouldn't be selected at all.
+ * 
+ * - We need a planet with resource providers, but no owning empire. The
+ *   planet will be selected, but all fields that are obtained from the
+ *   empire's data will be NULL.
+ *
+ * - We need a planet owned by an empire for which empire-wide settings
+ *   will be used.
+ *
+ * - We need a planet owned by an empire but that uses planet-specific
+ *   settings.
+ *
+ * - We need a planet with no resource providers owned by an empire. This
+ *   one shouldn't be selected.
+ *
+ * - Finally, we need a planet that matches the criterias but isn't
+ *   scheduled for an update at the time. 
+ *
+ * FIXME: for now, locking is NOT tested. I simply have no idea how to do
+ *        it, at least not without creating an extra database and that
+ *        kind of stuff.
+ *
+ * FIXME: cannot test where the happiness column comes from until values
+ *		  all use DOUBLE PRECISION.
+ */
+\i utils/strings.sql
+\i utils/resources.sql
+\i utils/accounts.sql
+\i utils/naming.sql
+\i utils/universe.sql
+
+SELECT sys.uoc_constant( 'game.resources.weightBase' , '(test)' , 'Resources' , 10.0 );
+SELECT _create_natural_resources( 2 , 'resource' );
+SELECT _create_raw_planets( 6 , 'planet' );
+SELECT _create_emp_names( 4 , 'empire' );
+INSERT INTO emp.empires ( name_id , cash )
+	SELECT id , 0 FROM naming.empire_names;
+
+/* Planet #1 */
+INSERT INTO sys.updates( id , gu_type , status , last_tick )
+	VALUES ( 1 , 'PLANET_MINING' , 'PROCESSING' , 0 );
+INSERT INTO verse.updates( update_id , planet_id )
+	VALUES ( 1 , _get_map_name( 'planet1' ) );
+
+/* Planet #2 */
+INSERT INTO sys.updates( id , gu_type , status , last_tick )
+	VALUES ( 2 , 'PLANET_MINING' , 'PROCESSING' , 0 );
+INSERT INTO verse.updates( update_id , planet_id )
+	VALUES ( 2 , _get_map_name( 'planet2' ) );
+INSERT INTO verse.resource_providers (
+		planet_id , resource_name_id , resprov_quantity_max ,
+		resprov_quantity , resprov_difficulty , resprov_recovery
+	) VALUES (
+		_get_map_name( 'planet2' ) , _get_string( 'resource1' ) , 100 ,
+		100 , 0.2 , 0.5
+	) , (
+		_get_map_name( 'planet2' ) , _get_string( 'resource2' ) , 100 ,
+		100 , 0.2 , 0.5
+	);
+
+/* Planet #3 */
+INSERT INTO sys.updates( id , gu_type , status , last_tick )
+	VALUES ( 3 , 'PLANET_MINING' , 'PROCESSING' , 0 );
+INSERT INTO verse.updates( update_id , planet_id )
+	VALUES ( 3 , _get_map_name( 'planet3' ) );
+INSERT INTO verse.resource_providers (
+		planet_id , resource_name_id , resprov_quantity_max ,
+		resprov_quantity , resprov_difficulty , resprov_recovery
+	) VALUES (
+		_get_map_name( 'planet3' ) , _get_string( 'resource1' ) , 100 ,
+		100 , 0.3 , 0.5
+	) , (
+		_get_map_name( 'planet3' ) , _get_string( 'resource2' ) , 100 ,
+		100 , 0.3 , 0.5
+	);
+INSERT INTO verse.planet_happiness ( planet_id , current , target )
+	VALUES ( _get_map_name( 'planet3' ) , 0.3 , 0.3 );
+INSERT INTO emp.planets ( empire_id , planet_id )
+	VALUES ( _get_emp_name( 'empire1' ) , _get_map_name( 'planet3' ) );
+INSERT INTO emp.mining_settings( empire_id , resource_name_id , empmset_weight )
+	VALUES (
+		_get_emp_name( 'empire1' ) , _get_string( 'resource1' ) , 2
+	) , (
+		_get_emp_name( 'empire1' ) , _get_string( 'resource2' ) , 2
+	);
+
+/* Planet #4 */
+INSERT INTO sys.updates( id , gu_type , status , last_tick )
+	VALUES ( 4 , 'PLANET_MINING' , 'PROCESSING' , 0 );
+INSERT INTO verse.updates( update_id , planet_id )
+	VALUES ( 4 , _get_map_name( 'planet4' ) );
+INSERT INTO verse.resource_providers (
+		planet_id , resource_name_id , resprov_quantity_max ,
+		resprov_quantity , resprov_difficulty , resprov_recovery
+	) VALUES (
+		_get_map_name( 'planet4' ) , _get_string( 'resource1' ) , 100 ,
+		100 , 0.4 , 0.5
+	) , (
+		_get_map_name( 'planet4' ) , _get_string( 'resource2' ) , 100 ,
+		100 , 0.4 , 0.5
+	);
+INSERT INTO verse.planet_happiness ( planet_id , current , target )
+	VALUES ( _get_map_name( 'planet4' ) , 0.4 , 0.4 );
+INSERT INTO emp.planets ( empire_id , planet_id )
+	VALUES ( _get_emp_name( 'empire2' ) , _get_map_name( 'planet4' ) );
+INSERT INTO emp.mining_settings( empire_id , resource_name_id , empmset_weight )
+	VALUES (
+		_get_emp_name( 'empire2' ) , _get_string( 'resource1' ) , 2
+	) , (
+		_get_emp_name( 'empire2' ) , _get_string( 'resource2' ) , 2
+	);
+INSERT INTO emp.planet_mining_settings(
+		empire_id , planet_id , resource_name_id , emppmset_weight
+	) VALUES (
+			_get_emp_name( 'empire2' ) , _get_map_name( 'planet4' ) , _get_string( 'resource1' ) , 1
+		) , (
+			_get_emp_name( 'empire2' ) , _get_map_name( 'planet4' ) , _get_string( 'resource2' ) , 3
+		);
+
+/* Planet #5 */
+INSERT INTO sys.updates( id , gu_type , status , last_tick )
+	VALUES ( 5 , 'PLANET_MINING' , 'PROCESSING' , 0 );
+INSERT INTO verse.updates( update_id , planet_id )
+	VALUES ( 5 , _get_map_name( 'planet5' ) );
+INSERT INTO verse.planet_happiness ( planet_id , current , target )
+	VALUES ( _get_map_name( 'planet5' ) , 0.5 , 0.5 );
+INSERT INTO emp.planets ( empire_id , planet_id )
+	VALUES ( _get_emp_name( 'empire3' ) , _get_map_name( 'planet5' ) );
+INSERT INTO emp.mining_settings( empire_id , resource_name_id , empmset_weight )
+	VALUES (
+		_get_emp_name( 'empire3' ) , _get_string( 'resource1' ) , 2
+	) , (
+		_get_emp_name( 'empire3' ) , _get_string( 'resource2' ) , 2
+	);
+
+/* Planet #6 */
+INSERT INTO sys.updates( id , gu_type , status , last_tick )
+	VALUES ( 6 , 'PLANET_MINING' , 'PROCESSED' , 0 );
+INSERT INTO verse.updates( update_id , planet_id )
+	VALUES ( 6 , _get_map_name( 'planet6' ) );
+INSERT INTO verse.resource_providers (
+		planet_id , resource_name_id , resprov_quantity_max ,
+		resprov_quantity , resprov_difficulty , resprov_recovery
+	) VALUES (
+		_get_map_name( 'planet6' ) , _get_string( 'resource1' ) , 100 ,
+		100 , 0.6 , 0.5
+	) , (
+		_get_map_name( 'planet6' ) , _get_string( 'resource2' ) , 100 ,
+		100 , 0.6 , 0.5
+	);
+INSERT INTO verse.planet_happiness ( planet_id , current , target )
+	VALUES ( _get_map_name( 'planet6' ) , 0.6 , 0.6 );
+INSERT INTO emp.planets ( empire_id , planet_id )
+	VALUES ( _get_emp_name( 'empire4' ) , _get_map_name( 'planet6' ) );
+INSERT INTO emp.mining_settings( empire_id , resource_name_id , empmset_weight )
+	VALUES (
+		_get_emp_name( 'empire4' ) , _get_string( 'resource1' ) , 2
+	) , (
+		_get_emp_name( 'empire4' ) , _get_string( 'resource2' ) , 2
+	);
+
+/* Insert planet resource records */
+INSERT INTO verse.planet_resources ( planet_id , resource_name_id , pres_income , pres_upkeep )
+	SELECT p.name_id , r.resource_name_id , 42 , 0
+		FROM verse.planets p CROSS JOIN defs.resources r;
diff --git a/legacyworlds-server-data/db-structure/tests/utils/locks-finder.sql b/legacyworlds-server-data/db-structure/tests/utils/locks-finder.sql
new file mode 100644
index 0000000..bcbea18
--- /dev/null
+++ b/legacyworlds-server-data/db-structure/tests/utils/locks-finder.sql
@@ -0,0 +1,43 @@
+/*
+ * Utility functions used by unit tests 
+ *
+ * Row lock checks
+ */
+
+CREATE TYPE _locks_entry AS (
+	ctid		tid ,
+	shared		BOOLEAN ,
+	exclusive	BOOLEAN
+);
+
+CREATE OR REPLACE FUNCTION _get_locks_on(
+			IN _table		TEXT )
+		RETURNS SETOF _locks_entry
+		STRICT VOLATILE
+	AS $$
+
+DECLARE
+	_page		INT;
+	_pages		INT;
+	_record		RECORD;
+	_return		_locks_entry;
+
+BEGIN
+	SELECT INTO _pages pg_relation_size( _table ) / 8192;
+
+	FOR _page IN 0 .. ( _pages - 1 )
+	LOOP
+	
+		FOR _record IN SELECT t_ctid , t_infomask
+				FROM heap_page_items( get_raw_page( _table , _page ) )
+				WHERE t_xmax::text::int > ( txid_current( ) & x'ffffffff'::bigint )
+		LOOP
+			_return := ROW( _record.t_ctid ,
+				_record.t_infomask & x'80'::int <> 0 ,
+				_record.t_infomask & x'40'::int <> 0 );
+			RETURN NEXT _return;
+		END LOOP;
+
+	END LOOP;
+END;
+$$ LANGUAGE PLPGSQL;
\ No newline at end of file