From 174bf84652df21c6421a2b6e0c749c0d38322341 Mon Sep 17 00:00:00 2001
From: Timm Fitschen <t.fitschen@indiscale.com>
Date: Thu, 4 Jun 2020 00:55:24 +0200
Subject: [PATCH] WIP: phase 8

---
 patches/patch20200426-3.0.0/versioning.sql |   8 ++
 procedures/deleteEntityProperties.sql      |   6 +-
 procedures/entityVersioning.sql            |  39 ++++++-
 procedures/insertEntityProperty.sql        |  24 +++-
 procedures/retrieveEntity.sql              |   5 +-
 procedures/retrieveEntityProperties.sql    |   8 +-
 tests/test_autotap.sql                     |  11 +-
 tests/test_reference_values.sql            | 124 +++++++++++++++++++++
 utils/make_db                              |  17 +--
 9 files changed, 220 insertions(+), 22 deletions(-)
 create mode 100644 tests/test_reference_values.sql

diff --git a/patches/patch20200426-3.0.0/versioning.sql b/patches/patch20200426-3.0.0/versioning.sql
index 17e359f..3bfcc13 100644
--- a/patches/patch20200426-3.0.0/versioning.sql
+++ b/patches/patch20200426-3.0.0/versioning.sql
@@ -40,6 +40,13 @@ CREATE TABLE entity_version (
   UNIQUE (`entity_id`, `version`)
 ) ENGINE=InnoDB;
 
+ALTER TABLE reference_data
+    ADD COLUMN `value_iversion` INT UNSIGNED DEFAULT NULL;
+-- TODO
+--    ADD FOREIGN KEY (`value`, `value_iversion) REFERENCES
+--        entity_version (`entity_id`, `_iversion`);
+
+
 CREATE TABLE archive_isa (
   child INT UNSIGNED NOT NULL,
   child_iversion INT UNSIGNED NOT NULL,
@@ -53,6 +60,7 @@ CREATE TABLE archive_reference_data (
     entity_id INT UNSIGNED NOT NULL,
     property_id INT UNSIGNED NOT NULL,
     value INT UNSIGNED NOT NULL,
+    value_iversion INT UNSIGNED DEFAULT NULL,
     status ENUM('OBLIGATORY','RECOMMENDED','SUGGESTED','FIX','REPLACEMENT')
         NOT NULL,
     pidx INT(10) UNSIGNED NOT NULL,
diff --git a/procedures/deleteEntityProperties.sql b/procedures/deleteEntityProperties.sql
index 34d429d..1da3fef 100644
--- a/procedures/deleteEntityProperties.sql
+++ b/procedures/deleteEntityProperties.sql
@@ -36,9 +36,9 @@ BEGIN
             WHERE e.entity_id = EntityID;
 
         INSERT INTO archive_reference_data (domain_id, entity_id,
-                property_id, value, status, pidx, _iversion)
-            SELECT domain_id, entity_id, property_id, value, status,
-                pidx, IVersion AS _iversion
+                property_id, value, value_iversion, status, pidx, _iversion)
+            SELECT domain_id, entity_id, property_id, value, value_iversion,
+                status, pidx, IVersion AS _iversion
             FROM reference_data
             WHERE (domain_id = 0 AND entity_id = EntityID)
             OR domain_id = EntityID;
diff --git a/procedures/entityVersioning.sql b/procedures/entityVersioning.sql
index 298fefa..5583d86 100644
--- a/procedures/entityVersioning.sql
+++ b/procedures/entityVersioning.sql
@@ -21,6 +21,7 @@
  * ** end header
  */
 
+
 DROP PROCEDURE IF EXISTS db_2_0.insert_single_child_version;
 delimiter //
 
@@ -77,8 +78,27 @@ BEGIN
 END;
 //
 
+DROP FUNCTION IF EXISTS db_2_0.get_iversion //
+CREATE FUNCTION db_2_0.get_iversion(
+    EntityID INT UNSIGNED,
+    Version VARBINARY(255))
+RETURNS INT UNSIGNED
+READS SQL DATA
+BEGIN
+    RETURN (
+        SELECT e._iversion
+            FROM entity_version AS e
+            WHERE e.entity_id = EntityID
+                AND e.version = Version
+        );
+END;
+//
+
+
 DROP FUNCTION IF EXISTS db_2_0.get_primary_parent_version //
-CREATE FUNCTION db_2_0.get_primary_parent_version(d INT UNSIGNED, v VARBINARY(255))
+CREATE FUNCTION db_2_0.get_primary_parent_version(
+    d INT UNSIGNED,
+    v VARBINARY(255))
 RETURNS VARBINARY(255)
 READS SQL DATA
 BEGIN
@@ -90,9 +110,7 @@ BEGIN
                 AND e.entity_id = p.entity_id)
             WHERE e.entity_id = d
                 AND e.version = v
-            LIMIT 1
         );
-
 END;
 //
 
@@ -147,6 +165,21 @@ BEGIN
 END;
 //
 
+DROP FUNCTION IF EXISTS db_2_0._get_version //
+CREATE FUNCTION db_2_0._get_version(
+    EntityID INT UNSIGNED,
+    IVersion INT UNSIGNED)
+RETURNS VARBINARY(255)
+READS SQL DATA
+BEGIN
+    RETURN (
+        SELECT version FROM entity_version
+            WHERE entity_id = EntityID
+            AND _iversion = IVersion
+        );
+END;
+//
+
 DROP PROCEDURE IF EXISTS db_2_0.get_version_history //
 CREATE PROCEDURE db_2_0.get_version_history(
     in EntityID INT UNSIGNED)
diff --git a/procedures/insertEntityProperty.sql b/procedures/insertEntityProperty.sql
index 8ed9579..8d7ab63 100644
--- a/procedures/insertEntityProperty.sql
+++ b/procedures/insertEntityProperty.sql
@@ -37,6 +37,9 @@ CREATE PROCEDURE db_2_0.insertEntityProperty(
     in Collection VARCHAR(255),
     in PropertyIndex INT UNSIGNED)
 BEGIN
+    DECLARE ReferenceValueIVersion INT UNSIGNED DEFAULT NULL;
+    DECLARE ReferenceValue INT UNSIGNED DEFAULT NULL;
+    DECLARE AT_PRESENT INTEGER DEFAULT NULL;
 
     CASE Datatable
     WHEN 'double_data' THEN
@@ -55,10 +58,27 @@ BEGIN
         VALUES
         (DomainID, EntityID, PropertyID, SUBSTRING_INDEX(PropertyValue, 'UTC', 1), IF(SUBSTRING_INDEX(PropertyValue, 'UTC', -1)='',NULL,SUBSTRING_INDEX(PropertyValue, 'UTC', -1)), PropertyStatus, PropertyIndex);
     WHEN 'reference_data' THEN
+
+        SET AT_PRESENT=LOCATE("@", PropertyValue);
+        IF is_feature_config("ENTITY_VERSIONING", "ENABLED") AND AT_PRESENT > 0 THEN
+            SET ReferenceValue = SUBSTRING_INDEX(PropertyValue, '@', 1);
+            SET ReferenceValueIVersion = get_iversion(ReferenceValue,
+                SUBSTRING_INDEX(PropertyValue, '@', -1));
+            -- TODO raise error when @ present but iversion is null
+            IF ReferenceValueIVersion IS NULL THEN
+                SELECT 0 from `ReferenceValueIVersion_WAS_NULL`;
+            END IF;
+
+        ELSE
+            SET ReferenceValue = PropertyValue;
+        END IF;
+
         INSERT INTO reference_data
-        (domain_id, entity_id, property_id, value, status, pidx)
+            (domain_id, entity_id, property_id, value, value_iversion, status,
+                pidx)
         VALUES
-        (DomainID, EntityID, PropertyID, PropertyValue, PropertyStatus, PropertyIndex);
+            (DomainID, EntityID, PropertyID, ReferenceValue,
+                ReferenceValueIVersion, PropertyStatus, PropertyIndex);
     WHEN 'enum_data' THEN
         INSERT INTO enum_data
         (domain_id, entity_id, property_id, value, status, pidx)
diff --git a/procedures/retrieveEntity.sql b/procedures/retrieveEntity.sql
index 7024451..12eb507 100644
--- a/procedures/retrieveEntity.sql
+++ b/procedures/retrieveEntity.sql
@@ -59,10 +59,7 @@ retrieveEntityBody: BEGIN
             AND e.version = Version;
 
         IF IsHead IS FALSE THEN
-            SELECT e._iversion INTO IVersion
-                FROM entity_version as e
-                WHERE e.entity_id = EntityID
-                AND e.version = Version;
+            SET IVersion=get_iversion(EntityID, Version);
 
             IF IVersion IS NULL THEN
                 -- RETURN EARLY - Version does not exist.
diff --git a/procedures/retrieveEntityProperties.sql b/procedures/retrieveEntityProperties.sql
index 01bb6a4..2872813 100644
--- a/procedures/retrieveEntityProperties.sql
+++ b/procedures/retrieveEntityProperties.sql
@@ -139,7 +139,9 @@ retrieveEntityPropertiesBody: BEGIN
             #-- reference properties
             SELECT
                 property_id AS PropertyID,
-                value AS PropertyValue,
+                IF(value_iversion IS NULL, value,
+                    CONCAT(value, "@", _get_version(value, value_iversion)))
+                    AS PropertyValue,
                 status AS PropertyStatus,
                 pidx AS PropertyIndex
             FROM archive_reference_data
@@ -253,7 +255,9 @@ retrieveEntityPropertiesBody: BEGIN
     #-- reference properties
     SELECT
         property_id AS PropertyID,
-        value AS PropertyValue,
+        IF(value_iversion IS NULL, value,
+            CONCAT(value, "@", _get_version(value, value_iversion)))
+            AS PropertyValue,
         status AS PropertyStatus,
         pidx AS PropertyIndex
     FROM reference_data
diff --git a/tests/test_autotap.sql b/tests/test_autotap.sql
index 2be5ec6..0c9a263 100644
--- a/tests/test_autotap.sql
+++ b/tests/test_autotap.sql
@@ -1581,7 +1581,7 @@ SELECT tap.table_collation_is('_caosdb_schema_unit_tests','reference_data','utf8
 SELECT tap.table_engine_is('_caosdb_schema_unit_tests','reference_data','InnoDB','');
 
 -- COLUMNS
-SELECT tap.columns_are('_caosdb_schema_unit_tests','reference_data','`domain_id`,`entity_id`,`property_id`,`value`,`status`,`pidx`','');
+SELECT tap.columns_are('_caosdb_schema_unit_tests','reference_data','`domain_id`,`entity_id`,`property_id`,`value`,`status`,`pidx`,`value_iversion`','');
 
 -- COLUMN reference_data.domain_id
 
@@ -1637,6 +1637,15 @@ SELECT tap.col_default_is('_caosdb_schema_unit_tests','reference_data','pidx',0,
 SELECT tap.col_charset_is('_caosdb_schema_unit_tests','reference_data','pidx',NULL,'');
 SELECT tap.col_collation_is('_caosdb_schema_unit_tests','reference_data','pidx',NULL,'');
 
+-- COLUMN reference_data.value_iversion
+
+SELECT tap.has_column('_caosdb_schema_unit_tests','reference_data','value_iversion','');
+SELECT tap.col_column_type_is('_caosdb_schema_unit_tests','reference_data','value_iversion','int(10) unsigned','');
+SELECT tap.col_extra_is('_caosdb_schema_unit_tests','reference_data','value_iversion','','');
+SELECT tap.col_default_is('_caosdb_schema_unit_tests','reference_data','value_iversion','NULL','');
+SELECT tap.col_charset_is('_caosdb_schema_unit_tests','reference_data','value_iversion',NULL,'');
+SELECT tap.col_collation_is('_caosdb_schema_unit_tests','reference_data','value_iversion',NULL,'');
+
 -- INDEXES
 SELECT tap.indexes_are('_caosdb_schema_unit_tests','reference_data','`entity_id`','');
 
diff --git a/tests/test_reference_values.sql b/tests/test_reference_values.sql
new file mode 100644
index 0000000..210cbba
--- /dev/null
+++ b/tests/test_reference_values.sql
@@ -0,0 +1,124 @@
+USE _caosdb_schema_unit_tests;
+
+BEGIN;
+CALL tap.no_plan();
+
+-- #####################################################################
+-- TEST insertEntityProperty without Versioning
+-- #####################################################################
+
+-- SETUP
+
+INSERT INTO transactions (srid,seconds,nanos,username,realm) VALUES 
+("SRIDbla", 1234, 2345, "me", "home"),
+("SRIDblub", 2345, 3465, "me", "home"),
+("SRIDblieb", 3456, 4576, "you", "home");
+SET @EntityID=99;
+SET @PropertyID=11;
+SET @Value=50;
+
+-- switch off versioning
+DELETE FROM feature_config WHERE _key = "ENTITY_VERSIONING";
+
+
+-- TEST insertEntityProperty without Versioning
+CALL insertEntityProperty(0, @EntityID, @PropertyID, "reference_data", @Value,
+    NULL, "FIX", NULL, NULL, NULL, NULL, 0);
+
+-- TODO switch expected/actual
+SELECT tap.eq(0, domain_id, "domain ok") FROM reference_data;
+SELECT tap.eq(99, entity_id, "entity ok") FROM reference_data;
+SELECT tap.eq(11, property_id, "property ok") FROM reference_data;
+SELECT tap.eq(50, value, "value ok") FROM reference_data;
+SELECT tap.eq("FIX", status, "status ok") FROM reference_data;
+SELECT tap.eq("0", pidx, "pidx ok") FROM reference_data;
+SELECT tap.eq(NULL, value_iversion, "value_iversion ok") FROM reference_data;
+
+
+-- clean up
+DELETE FROM reference_data WHERE domain_id=0 AND entity_id=99;
+
+-- #####################################################################
+-- TODO TEST insertEntityProperty with Versioning
+-- #####################################################################
+
+
+-- switch on versioning
+INSERT INTO feature_config (_key, _value) VALUES ("ENTITY_VERSIONING", "ENABLED");
+
+
+-- TEST insertEntityProperty with Versioning - REFERENCE HEAD
+-- TODO assert throws
+SET @VALUE="50@";
+CALL insertEntityProperty(0, @EntityID, @PropertyID, "reference_data", @Value,
+    NULL, "FIX", NULL, NULL, NULL, NULL, 0);
+
+-- TODO switch expected/actual
+SELECT tap.eq(0, domain_id, "domain ok") FROM reference_data;
+SELECT tap.eq(99, entity_id, "entity ok") FROM reference_data;
+SELECT tap.eq(11, property_id, "property ok") FROM reference_data;
+SELECT tap.eq(50, value, "value ok") FROM reference_data;
+SELECT tap.eq("FIX", status, "status ok") FROM reference_data;
+SELECT tap.eq("0", pidx, "pidx ok") FROM reference_data;
+SELECT tap.eq(value_iversion, NULL, "value_iversion ok") FROM reference_data;
+
+DELETE FROM reference_data WHERE domain_id=0 AND entity_id=99;
+
+
+SET @VALUE="50";
+CALL insertEntityProperty(0, @EntityID, @PropertyID, "reference_data", @Value,
+    NULL, "FIX", NULL, NULL, NULL, NULL, 0);
+
+-- TODO switch expected/actual
+SELECT tap.eq(0, domain_id, "domain ok") FROM reference_data;
+SELECT tap.eq(99, entity_id, "entity ok") FROM reference_data;
+SELECT tap.eq(11, property_id, "property ok") FROM reference_data;
+SELECT tap.eq(50, value, "value ok") FROM reference_data;
+SELECT tap.eq("FIX", status, "status ok") FROM reference_data;
+SELECT tap.eq("0", pidx, "pidx ok") FROM reference_data;
+SELECT tap.eq(value_iversion, NULL, "value_iversion ok") FROM reference_data;
+
+DELETE FROM reference_data WHERE domain_id=0 AND entity_id=99;
+
+
+-- TEST insertEntityProperty with Versioning - Reference version
+CALL insert_single_child_version(@EntityID, "hashbla", "versionbla", NULL, "SRIDbla");
+CALL insert_single_child_version(@EntityID, "hashblub", "versionblub", "versionbla", "SRIDblub");
+
+SET @VALUE="50@versionbla";
+CALL insertEntityProperty(0, @EntityID, @PropertyID, "reference_data", @Value,
+    NULL, "FIX", NULL, NULL, NULL, NULL, 0);
+
+SELECT tap.eq(0, domain_id, "domain ok") FROM reference_data;
+SELECT tap.eq(99, entity_id, "entity ok") FROM reference_data;
+SELECT tap.eq(11, property_id, "property ok") FROM reference_data;
+SELECT tap.eq(50, value, "value ok") FROM reference_data;
+SELECT tap.eq("FIX", status, "status ok") FROM reference_data;
+SELECT tap.eq("0", pidx, "pidx ok") FROM reference_data;
+SELECT tap.eq(value_iversion, "1", "value_iversion ok") FROM reference_data;
+
+DELETE FROM reference_data WHERE domain_id=0 AND entity_id=99;
+
+SET @VALUE="50@versionblub";
+CALL insertEntityProperty(0, @EntityID, @PropertyID, "reference_data", @Value,
+    NULL, "FIX", NULL, NULL, NULL, NULL, 0);
+
+SELECT tap.eq(0, domain_id, "domain ok") FROM reference_data;
+SELECT tap.eq(99, entity_id, "entity ok") FROM reference_data;
+SELECT tap.eq(11, property_id, "property ok") FROM reference_data;
+SELECT tap.eq(50, value, "value ok") FROM reference_data;
+SELECT tap.eq("FIX", status, "status ok") FROM reference_data;
+SELECT tap.eq("0", pidx, "pidx ok") FROM reference_data;
+SELECT tap.eq(value_iversion, "2", "value_iversion ok") FROM reference_data;
+
+-- TODO switch expected/actual
+
+
+-- #####################################################################
+-- TEST retrieveEntityProperty without Versioning
+-- #####################################################################
+
+
+
+CALL tap.finish();
+ROLLBACK;
diff --git a/utils/make_db b/utils/make_db
index 6144563..214de9d 100755
--- a/utils/make_db
+++ b/utils/make_db
@@ -70,18 +70,21 @@ function _execute_tests () {
 # optional parameter: [--fresh] for installing a fresh data base. Otherwise an existing one would be reused.
 function _install_unit_test_database () {
     DATABASE_NAME=$UNITTEST_DATABASE
-    if _db_exists "$DATABASE_NAME"; then
-        if [[ "$1" == "--fresh" ]] ; then
+    if [[ "$1" == "--fresh" ]] ; then
+        if _db_exists "$DATABASE_NAME"; then
             drop "$DATABASE_NAME" ;
-        else
-            return 0;
         fi
     fi
 
-    sed "s/db_2_0/$DATABASE_NAME/g" "$INSTALL_SQL_FILE" | $MYSQL_CMD $(get_mysql_args_nodb)
+    if _db_exists "$DATABASE_NAME"; then
+        echo "using $DATABASE_NAME"
+    else
+        sed "s/db_2_0/$DATABASE_NAME/g" "$INSTALL_SQL_FILE" | $MYSQL_CMD $(get_mysql_args_nodb)
+
+        # create test user
+        grant
+    fi
 
-    # create test user
-    grant
 
     echo "DATABASE_NAME=\"$UNITTEST_DATABASE\"" >> .test_config
     pushd patches > /dev/null
-- 
GitLab