diff --git a/legacyworlds-server-data/db-structure/parts/030-data/110-empires.sql b/legacyworlds-server-data/db-structure/parts/030-data/110-empires.sql
index f6015dc..4480ff9 100644
--- a/legacyworlds-server-data/db-structure/parts/030-data/110-empires.sql
+++ b/legacyworlds-server-data/db-structure/parts/030-data/110-empires.sql
@@ -67,6 +67,86 @@ ALTER TABLE emp.resources
 		FOREIGN KEY ( resource_name_id ) REFERENCES defs.resources;
 
 
+
+/*
+ * States for empire technologies
+ * -------------------------------
+ *
+ * This enumerated type represents the 3 possible state for an empire
+ * technology: being researched, pending implementation, or implemented.
+ */
+
+DROP TYPE IF EXISTS emp.technology_state CASCADE;
+CREATE TYPE emp.technology_state
+	AS ENUM(
+		/* Research in progress */
+		'RESEARCH' ,
+		/* Implementation pending */
+		'PENDING' ,
+		/* Implemented technology */
+		'KNOWN'
+	);
+
+
+/*
+ * Empire technologies
+ * --------------------
+ * 
+ * This table stores technologies that are being researched, need to be or
+ * have been implemented by an empire. Technologies that are being researched
+ * include additional information that represent the research progress and
+ * priority.
+ * 
+ * FIXME: this table must be renamed to emp.technologies after the old
+ * research system has been removed 
+ */
+
+CREATE TABLE emp.technologies_v2(
+	/* Identifier of the empire */
+	empire_id				INT NOT NULL ,
+	
+	/* Identifier of the technology */
+	technology_name_id		INT NOT NULL ,
+	
+	/* Current state of the technology */
+	emptech_state			emp.technology_state NOT NULL
+								DEFAULT 'RESEARCH' ,
+
+	/* Accumulated research points, or NULL if research is over */
+	emptech_points			DOUBLE PRECISION
+								DEFAULT 0.0 ,
+
+	/* Research priority, or NULL if research is over */
+	emptech_priority		INT DEFAULT 2
+								CHECK( emptech_priority BETWEEN 0 AND 4 ) ,
+
+	/* Primary key is the empire / technology pair */
+	PRIMARY KEY( empire_id , technology_name_id ) ,
+	
+	/* Make sure there are both research points and a priority during research
+	 * and neither when the technology is pending implementation or
+	 * implemented.
+	 */
+	CHECK( CASE emptech_state
+		WHEN 'RESEARCH' THEN
+			( emptech_points IS NOT NULL AND emptech_priority IS NOT NULL )
+		ELSE
+			( emptech_points IS NULL AND emptech_priority IS NULL )
+	END )
+);
+
+CREATE INDEX idx_emptech_technology
+	ON emp.technologies_v2 ( technology_name_id );
+
+ALTER TABLE emp.technologies_v2
+	ADD CONSTRAINT fk_emptech_empire
+		FOREIGN KEY ( empire_id ) REFERENCES emp.empires ( name_id )
+			ON DELETE CASCADE ,
+	ADD CONSTRAINT fk_emptech_technology
+		FOREIGN KEY ( technology_name_id ) REFERENCES defs.technologies;
+
+
+
 --
 -- Empire technologies
 --