From 6fa6da6c42443c9fcafadd17d742052fc9bcb5a2 Mon Sep 17 00:00:00 2001
From: Timm Fitschen <t.fitschen@indiscale.com>
Date: Wed, 20 May 2020 16:09:40 +0200
Subject: [PATCH] WIP: versioning phase 7 - preparing partinioning

---
 patches/patch20200426-3.0.0/versioning.sql |  4 +-
 procedures/entityVersioning.sql            | 29 ++++++++----
 procedures/retrieveEntity.sql              |  9 ++--
 tests/test_autotap.sql                     |  2 +-
 tests/test_entity_versioning.sql           | 54 ++++++++++++----------
 5 files changed, 59 insertions(+), 39 deletions(-)

diff --git a/patches/patch20200426-3.0.0/versioning.sql b/patches/patch20200426-3.0.0/versioning.sql
index af42e4d..2ab22ed 100644
--- a/patches/patch20200426-3.0.0/versioning.sql
+++ b/patches/patch20200426-3.0.0/versioning.sql
@@ -35,10 +35,10 @@ CREATE TABLE entity_version (
   _ipparent INT UNSIGNED NULL,
   srid VARBINARY(255) NOT NULL,
   _is_head BOOLEAN DEFAULT FALSE,
-  PRIMARY KEY (`entity_id`, `_iversion`),
+  PRIMARY KEY (`entity_id`, `_iversion`, `_is_head`),
   FOREIGN KEY (`entity_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE,
   FOREIGN KEY (`srid`) REFERENCES `transactions` (`srid`),
-  UNIQUE (`entity_id`, `version`)
+  UNIQUE (`entity_id`, `version`, `_is_head`)
 ) ENGINE=InnoDB;
 
 CREATE TABLE archive_isa (
diff --git a/procedures/entityVersioning.sql b/procedures/entityVersioning.sql
index ff83084..9140f17 100644
--- a/procedures/entityVersioning.sql
+++ b/procedures/entityVersioning.sql
@@ -40,7 +40,8 @@ BEGIN
         SELECT e._iversion INTO newipparent
             FROM entity_version AS e
             WHERE e.entity_id = EntityID
-            AND e.version = Parent;
+            AND e.version = Parent
+            AND e._is_head IS FALSE;
         IF newipparent IS NULL THEN
             -- throw error;
             SELECT concat("This parent does not exists: ", Parent)
@@ -57,19 +58,24 @@ BEGIN
         SET newiversion = 1;
     END IF;
 
-    -- remove old HEAD marker
-    UPDATE entity_version
-        SET _is_head = FALSE
-        WHERE entity_id = EntityID
-        AND _is_head IS TRUE;
-
 
     -- insert new version with HEAD marker
     INSERT INTO entity_version
         (entity_id, hash, version, _iversion, _ipparent, srid, _is_head)
         VALUES
-        (EntityID, Hash, Version, newiversion, newipparent, Transaction, TRUE);
+        (EntityID, Hash, Version, newiversion, newipparent, Transaction, FALSE);
+
+    -- insert head marker
+    INSERT INTO entity_version
+        (entity_id, hash, version, _iversion, _ipparent, srid, _is_head)
+        VALUES
+        (EntityID, Hash, Version, 0, newipparent, Transaction, TRUE)
 
+        ON DUPLICATE KEY UPDATE
+            hash = Hash,
+            version = Version,
+            _ipparent = newipparent,
+            srid = Transaction;
 
 
 END;
@@ -98,6 +104,7 @@ BEGIN
                 AND e.entity_id = p.entity_id)
             WHERE e.entity_id = d
                 AND e.version = v
+                AND e._is_head IS FALSE
             LIMIT 1
         );
 
@@ -119,6 +126,7 @@ BEGIN
             ON ( e.srid = t.srid )
             WHERE e.entity_id = EntityID
             AND e.version = Version
+            AND e._is_head IS FALSE
     );
 END;
 //
@@ -153,6 +161,7 @@ BEGIN
         SELECT e.version
             FROM entity_version AS e
             WHERE e.entity_id = EntityID
+            AND e._is_head IS FALSE
             ORDER BY e._iversion DESC
             LIMIT 1 OFFSET Offset
         );
@@ -172,6 +181,7 @@ BEGIN
         INNER JOIN transactions as t
         ON ( c.srid = t.srid )
         WHERE c.entity_id = EntityID
+        AND c._is_head IS FALSE
         AND c._ipparent is Null
     -- TODO This first SELECT statement is necessary because the second one
     -- does not return the root. However, this should be doable in one go with
@@ -188,7 +198,8 @@ BEGIN
         ON (c._ipparent = p._iversion
             AND c.entity_id = p.entity_id
             AND t.srid = c.srid)
-        WHERE p.entity_id = EntityID;
+        WHERE p.entity_id = EntityID
+        AND c._is_head IS FALSE;
 END;
 //
 
diff --git a/procedures/retrieveEntity.sql b/procedures/retrieveEntity.sql
index 7024451..6c55b66 100644
--- a/procedures/retrieveEntity.sql
+++ b/procedures/retrieveEntity.sql
@@ -56,16 +56,19 @@ retrieveEntityBody: BEGIN
             INNER JOIN transactions AS t
             ON ( e.srid = t.srid )
             WHERE e.entity_id = EntityID
-            AND e.version = Version;
+            AND e.version = Version
+            AND e._is_head IS FALSE;
 
         IF IsHead IS FALSE THEN
             SELECT e._iversion INTO IVersion
                 FROM entity_version as e
                 WHERE e.entity_id = EntityID
-                AND e.version = Version;
+                AND e.version = Version
+                AND e._is_head IS FALSE;
 
             IF IVersion IS NULL THEN
-                -- RETURN EARLY - Version does not exist.
+                -- Version does not exist.
+                -- RETURN EARLY with empty result set.
                 SELECT 0 WHERE 0 = 1;
                 LEAVE retrieveEntityBody;
             END IF;
diff --git a/tests/test_autotap.sql b/tests/test_autotap.sql
index 8493609..ef13840 100644
--- a/tests/test_autotap.sql
+++ b/tests/test_autotap.sql
@@ -2293,7 +2293,7 @@ SELECT tap.constraint_type_is('_caosdb_schema_unit_tests','entity_version','enti
 
 SELECT tap.has_constraint('_caosdb_schema_unit_tests','entity_version','PRIMARY','');
 SELECT tap.constraint_type_is('_caosdb_schema_unit_tests','entity_version','PRIMARY','PRIMARY KEY','');
-SELECT tap.col_is_pk('_caosdb_schema_unit_tests','entity_version','`entity_id`,`_iversion`','');
+SELECT tap.col_is_pk('_caosdb_schema_unit_tests','entity_version','`entity_id`,`_iversion`,`_is_head`','');
 
 -- CONSTRAINT entity_version.entity_version_ibfk_1
 
diff --git a/tests/test_entity_versioning.sql b/tests/test_entity_versioning.sql
index a8084c9..4413893 100644
--- a/tests/test_entity_versioning.sql
+++ b/tests/test_entity_versioning.sql
@@ -30,25 +30,27 @@ SELECT count(*) INTO @x FROM entity_version;
 SELECT tap.eq(@x, 0, "no versions there yet");
 
 CALL insert_single_child_version(@EntityID, "hashbla", "versionbla", NULL, "SRIDbla");
-SELECT _ipparent INTO @x from entity_version WHERE version="versionbla" AND _is_head IS TRUE;
-SELECT tap.eq(@x, NULL, "no parent for the first version");
+SELECT tap.eq(_ipparent, NULL, "no parent for the first version")
+    FROM entity_version WHERE version="versionbla" AND _is_head IS TRUE;
+SELECT tap.eq(_ipparent, NULL, "no parent for the first version")
+    FROM entity_version WHERE version="versionbla" AND _is_head IS FALSE;
 
 -- add a second version
-SELECT count(*) INTO @x FROM entity_version;
-SELECT tap.eq(@x, 1, "one version there yet");
+SELECT tap.eq(count(*), 1, "one version there yet")
+    FROM entity_version WHERE _is_head IS FALSE;
 CALL insert_single_child_version(@EntityID, "hashblub", "versionblub", "versionbla", "SRIDblub");
 
 SELECT _ipparent INTO @x from entity_version WHERE version="versionblub" AND _is_head IS TRUE;
 SELECT tap.eq(@x, 1, "the original entity is the parent");
 
 -- test error: parent does not exist
-SELECT count(*) INTO @x FROM entity_version;
+SELECT count(DISTINCT version) INTO @x FROM entity_version;
 SELECT tap.eq(@x, 2, "two version there yet");
 
 CALL tap._assert_throws(concat("CALL insert_single_child_version(", @EntityID, ', "hashblieb", "versionblieb", "non-existing-parent", "SRIDBlieb")'), "non existing parent throws");
 
-SELECT count(*) INTO @x FROM entity_version;
-SELECT tap.eq(@x, 2, "still two version there");
+SELECT tap.eq(count(DISTINCT version), 2, "still two version there")
+    FROM entity_version;
 
 
 -- TEST get_primary_parent_version
@@ -87,9 +89,10 @@ CALL insertIsa(@EntityID, @ParentID);
 CALL insertEntityProperty(0, @EntityID, 17, "null_data", NULL, NULL,
     "RECOMMENDED", NULL, "DescOverride", NULL, NULL, 0);
 
-SELECT count(*) INTO @x FROM entity_version WHERE entity_id = @EntityID;
-SELECT tap.eq(@x, 1, "after insertEntity, a version is there.");
-SELECT _iversion INTO @x FROM entity_version WHERE entity_id = @EntityID and _ipparent is NULL AND _is_head IS TRUE;
+SELECT tap.eq(count(DISTINCT version), 1,
+    "after insertEntity, a version is there.")
+    FROM entity_version WHERE entity_id = @EntityID;
+SELECT _iversion INTO @x FROM entity_version WHERE entity_id = @EntityID and _ipparent is NULL AND _is_head IS FALSE;
 SELECT tap.eq(@x, 1, "after insertEntity, the _iversion number is 1.");
 
 SELECT _ipparent INTO @x from entity_version WHERE entity_id = @EntityID AND _is_head IS TRUE;
@@ -102,13 +105,16 @@ SELECT tap.eq(count(*), 0, "no entity in archive_entities before first update")
 SET @SRID = "SRIDblub";
 CALL deleteEntityProperties(@EntityID);
 CALL updateEntity(@EntityID, "NewEntityName", "NewEntityDesc", "RECORD", NULL, NULL, "{acl1}");
-SELECT count(*) INTO @x FROM entity_version WHERE entity_id = @EntityID;
-SELECT tap.eq(@x, 2, "after updateEntity, a second version is there.");
+SELECT tap.eq(count(DISTINCT version), 2,
+    "after updateEntity, a second version is there.")
+    FROM entity_version WHERE entity_id = @EntityID;
 
-SELECT _iversion INTO @x FROM entity_version WHERE entity_id = @EntityID and _ipparent = 1 AND _is_head IS TRUE;
-SELECT tap.eq(@x, 2, "after updateEntity, the _iversion number incremented.");
-SELECT _ipparent INTO @x FROM entity_version WHERE entity_id = @EntityID and _ipparent = 1 AND _is_head IS TRUE;
-SELECT tap.eq(@x, 1, "after updateEntity, the _pparent points to the first version");
+SELECT tap.eq(_iversion, 2,
+        "after updateEntity, the _iversion number incremented."),
+    tap.eq(_ipparent, 1,
+        "after updateEntity, the _ipparent points to the first version")
+    FROM entity_version WHERE entity_id = @EntityID and _ipparent = 1 
+        AND _is_head IS FALSE;
 
 SELECT tap.eq(count(*), 1, "after updateEntity, one entity in archive_entities")
     FROM archive_entities;
@@ -119,9 +125,10 @@ SELECT tap.eq(count(*), 1, "after updateEntity, one entity in archive_entities")
 SELECT version INTO @x FROM entity_version
     WHERE entity_id = @EntityID
     AND _iversion = 2;
+SELECT get_head_version(@EntityID) AS "HERE";
+CALL retrieveEntity(@EntityID, get_head_version(@EntityID));
 CALL retrieveEntity(@EntityID, NULL);
 CALL retrieveEntity(@EntityID, "non-existing-version");
-CALL retrieveEntity(@EntityID, get_head_version(@EntityID));
 CALL retrieveEntity(@EntityID, @x);
 
 -- TEST retrieveEntityParents
@@ -149,20 +156,19 @@ CALL retrieveOverrides(0, @EntityID, @x);
 -- and 2nd updateEntity
 SET @SRID = "SRIDblieb";
 CALL updateEntity(@EntityID, "EntityName", "EntityDesc", "RECORDTYPE", NULL, NULL, "{acl1}");
-SELECT count(*) INTO @x FROM entity_version WHERE entity_id = @EntityID;
-SELECT tap.eq(@x, 3, "after 2nd updateEntity, a 3rd version is there.");
+
+SELECT tap.eq(count(DISTINCT version), 3,
+    "after 2nd updateEntity, a 3rd version is there.")
+    FROM entity_version WHERE entity_id = @EntityID;
 
 SELECT tap.eq(count(*), 1, "after 2nd updateEntity, a single HEAD version is there.")
     FROM entity_version WHERE entity_id = @EntityID AND _is_head IS TRUE;
 
-SELECT tap.eq(count(*), 2, "after 2nd updateEntity, two non-HEAD versions are there.")
-    FROM entity_version WHERE entity_id = @EntityID AND _is_head IS FALSE;
-
-SELECT _iversion INTO @x FROM entity_version WHERE entity_id = @EntityID and _ipparent = 2;
+SELECT _iversion INTO @x FROM entity_version WHERE entity_id = @EntityID and _ipparent = 2 AND _is_head IS FALSE;
 SELECT tap.eq(@x, 3, "after 2nd updateEntity, the _iversion number incremented again.");
 SELECT _ipparent INTO @x FROM entity_version WHERE entity_id = @EntityID and _iversion = 3;
 SELECT tap.eq(@x, 2, "after 2nd updateEntity, the _pparent points to the 2nd version");
-SELECT tap.eq("SRIDblieb", srid, "correct transaction was stored") FROM entity_version WHERE entity_id = @EntityID AND _ipparent = 2;
+SELECT tap.eq("SRIDblieb", srid, "correct transaction was stored") FROM entity_version WHERE entity_id = @EntityID AND _ipparent = 2 AND _is_head IS FALSE;
 
 
 -- TEST deleteEntity - should remove all versions
-- 
GitLab