From 4a2d395920070bb27f94da73fcf7dcff1dde8fc6 Mon Sep 17 00:00:00 2001
From: Timm Fitschen <t.fitschen@indiscale.com>
Date: Tue, 19 May 2020 03:41:59 +0200
Subject: [PATCH] WIP: versioning phase 6

---
 .../patch20200426-3.0.0/feature_config.sql    | 19 ++++++
 patches/patch20200426-3.0.0/patch.sh          |  3 +-
 patches/patch20200426-3.0.0/versioning.sql    | 21 +------
 procedures/deleteIsaCache.sql                 |  3 +-
 procedures/entityVersioning.sql               | 63 +++++++++++++++++--
 procedures/insertEntity.sql                   |  5 +-
 procedures/registerSubdomain.sql              | 16 ++---
 procedures/retrieveEntity.sql                 |  6 +-
 procedures/updateEntity.sql                   |  5 +-
 9 files changed, 99 insertions(+), 42 deletions(-)
 create mode 100644 patches/patch20200426-3.0.0/feature_config.sql

diff --git a/patches/patch20200426-3.0.0/feature_config.sql b/patches/patch20200426-3.0.0/feature_config.sql
new file mode 100644
index 0000000..f50c51e
--- /dev/null
+++ b/patches/patch20200426-3.0.0/feature_config.sql
@@ -0,0 +1,19 @@
+DROP TABLE IF EXISTS feature_config;
+CREATE TABLE feature_config (
+    _key VARCHAR(255) PRIMARY KEY,
+    _value VARCHAR(255)
+) ENGINE=InnoDB;
+
+delimiter //
+
+DROP FUNCTION IF EXISTS is_feature_config //
+CREATE FUNCTION is_feature_config(
+    _Key VARCHAR(255),
+    Expected VARCHAR(255))
+RETURNS BOOLEAN
+READS SQL DATA
+BEGIN
+    RETURN (
+        SELECT f._value = Expected FROM feature_config as f WHERE f._key = _Key
+    );
+END //
diff --git a/patches/patch20200426-3.0.0/patch.sh b/patches/patch20200426-3.0.0/patch.sh
index 3d28b4e..df53677 100755
--- a/patches/patch20200426-3.0.0/patch.sh
+++ b/patches/patch20200426-3.0.0/patch.sh
@@ -24,7 +24,7 @@
 # new entity_version table
 # Update mysql schema to version v3.0.0
 NEW_VERSION="v3.0.0"
-OLD_VERSION="v2.1.1"
+OLD_VERSION="v2.1.2"
 
 if [ -z "$UTILSPATH" ]; then
  UTILSPATH="../utils"
@@ -36,6 +36,7 @@ fi
 check_version $OLD_VERSION
 
 
+mysql_execute_file $PATCH_DIR/feature_config.sql
 mysql_execute_file $PATCH_DIR/versioning.sql
 
 
diff --git a/patches/patch20200426-3.0.0/versioning.sql b/patches/patch20200426-3.0.0/versioning.sql
index d1e9450..17e359f 100644
--- a/patches/patch20200426-3.0.0/versioning.sql
+++ b/patches/patch20200426-3.0.0/versioning.sql
@@ -1,4 +1,3 @@
-
 DROP TABLE IF EXISTS archive_reference_data;
 DROP TABLE IF EXISTS archive_null_data;
 DROP TABLE IF EXISTS archive_text_data;
@@ -30,7 +29,7 @@ CREATE TABLE transactions (
 -- TODO remove ON DELETE CASCADE when feature is stable.
 CREATE TABLE entity_version (
   entity_id INT UNSIGNED NOT NULL,
-  hash VARBINARY(255) NOT NULL,
+  hash VARBINARY(255) DEFAULT NULL,
   version VARBINARY(255) NOT NULL,
   _iversion INT UNSIGNED NOT NULL,
   _ipparent INT UNSIGNED NULL,
@@ -289,26 +288,8 @@ CREATE TABLE archive_entities (
 ) ENGINE=InnoDB;
 
 
-DROP TABLE IF EXISTS feature_config;
-CREATE TABLE feature_config (
-    _key VARCHAR(255) PRIMARY KEY,
-    _value VARCHAR(255)
-) ENGINE=InnoDB;
-
 delimiter //
 
-DROP FUNCTION IF EXISTS is_feature_config //
-CREATE FUNCTION is_feature_config(
-    _Key VARCHAR(255),
-    Expected VARCHAR(255))
-RETURNS BOOLEAN
-READS SQL DATA
-BEGIN
-    RETURN (
-        SELECT f._value = Expected FROM feature_config as f WHERE f._key = _Key
-    );
-END //
-
 DROP PROCEDURE IF EXISTS set_transaction //
 CREATE PROCEDURE set_transaction(
     srid VARBINARY(255),
diff --git a/procedures/deleteIsaCache.sql b/procedures/deleteIsaCache.sql
index 09a963c..1c0ab90 100644
--- a/procedures/deleteIsaCache.sql
+++ b/procedures/deleteIsaCache.sql
@@ -44,10 +44,11 @@ BEGIN
     DECLARE IVersion INT UNSIGNED DEFAULT NULL;
 
     IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN
-        -- move to archive_isa
         SELECT max(_iversion) INTO IVersion
             FROM entity_version
             WHERE entity_id = EntityID;
+
+        -- move to archive_isa before deleting
         INSERT INTO archive_isa (child, child_iversion, parent)
             SELECT e.child, IVersion AS child_iversion, e.parent
             FROM isa_cache AS e
diff --git a/procedures/entityVersioning.sql b/procedures/entityVersioning.sql
index ff5bd9e..f6d4665 100644
--- a/procedures/entityVersioning.sql
+++ b/procedures/entityVersioning.sql
@@ -37,21 +37,30 @@ BEGIN
 
     -- find _ipparent
     IF Parent IS NOT NULL THEN
-        SELECT e._iversion INTO newipparent FROM entity_version as e WHERE e.entity_id = EntityID AND e.version = Parent;
+        SELECT e._iversion INTO newipparent
+            FROM entity_version AS e
+            WHERE e.entity_id = EntityID
+            AND e.version = Parent;
         IF newipparent IS NULL THEN
             -- throw error;
-            SELECT concat("This parent does not exists: ", Parent) from nonexisting;
+            SELECT concat("This parent does not exists: ", Parent)
+            FROM nonexisting;
         END IF;
     END IF;
 
 
     -- generate _iversion
-    SELECT max(e._iversion)+1 INTO newiversion FROM entity_version as e WHERE e.entity_id=EntityID;
+    SELECT max(e._iversion)+1 INTO newiversion
+        FROM entity_version AS e
+        WHERE e.entity_id=EntityID;
     IF newiversion IS NULL THEN
-        SET newiversion = 0;
+        SET newiversion = 1;
     END IF;
 
-    INSERT INTO entity_version (entity_id, hash, version, _iversion, _ipparent, srid) VALUES (EntityID, Hash, Version, newiversion, newipparent, Transaction);
+    INSERT INTO entity_version
+        (entity_id, hash, version, _iversion, _ipparent, srid)
+        VALUES
+        (EntityID, Hash, Version, newiversion, newipparent, Transaction);
 
 
 
@@ -111,15 +120,57 @@ CREATE FUNCTION db_2_0.get_head_version(
     EntityID INT UNSIGNED)
 RETURNS VARBINARY(255)
 READS SQL DATA
+BEGIN
+    RETURN get_head_relative(EntityID, 0);
+END;
+//
+
+DROP FUNCTION IF EXISTS db_2_0.get_head_relative //
+CREATE FUNCTION db_2_0.get_head_relative(
+    EntityID INT UNSIGNED,
+    Offset INT UNSIGNED)
+RETURNS VARBINARY(255)
+READS SQL DATA
 BEGIN
     RETURN (
         SELECT e.version
             FROM entity_version AS e
             WHERE e.entity_id = EntityID
             ORDER BY e._iversion DESC
-            LIMIT 1
+            LIMIT 1 OFFSET Offset
         );
 END;
 //
 
+DROP PROCEDURE IF EXISTS db_2_0.get_version_history //
+CREATE PROCEDURE db_2_0.get_version_history(
+    in EntityID INT UNSIGNED)
+BEGIN
+    -- retrieve root(s)
+    SELECT c.version AS child,
+            NULL as parent,
+            t.seconds AS child_seconds,
+            t.nanos AS child_nanos
+        FROM entity_version AS c
+        INNER JOIN transactions as t
+        ON ( c.srid = t.srid )
+        WHERE c.entity_id = EntityID
+        AND c._ipparent is Null
+
+    -- retrieve branches
+    UNION SELECT c.version AS child,
+            p.version AS parent,
+            t.seconds AS child_seconds,
+            t.nanos AS child_nanos
+        FROM entity_version AS p
+        INNER JOIN entity_version as c
+        INNER JOIN transactions AS t
+        ON (c._ipparent = p._iversion
+            AND c.entity_id = p.entity_id
+            AND t.srid = c.srid)
+        WHERE p.entity_id = EntityID;
+END;
+//
+
+
 delimiter ;
diff --git a/procedures/insertEntity.sql b/procedures/insertEntity.sql
index 72072aa..b3b271e 100644
--- a/procedures/insertEntity.sql
+++ b/procedures/insertEntity.sql
@@ -44,8 +44,8 @@ CREATE PROCEDURE db_2_0.insertEntity(in EntityName VARCHAR(255), in EntityDesc T
 BEGIN
     DECLARE NewEntityID INT UNSIGNED DEFAULT NULL;
     DECLARE NewACLID INT UNSIGNED DEFAULT NULL;
-    DECLARE Hash VARBINARY(255) DEFAULT SHA1(UUID());
-    DECLARE Version VARBINARY(255) DEFAULT NULL;
+    DECLARE Hash VARBINARY(255) DEFAULT NULL;
+    DECLARE Version VARBINARY(255) DEFAULT SHA1(UUID());
     DECLARE Transaction VARBINARY(255) DEFAULT NULL;
 
     call entityACL(NewACLID, ACL);
@@ -55,7 +55,6 @@ BEGIN
 
     IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN
         SET Transaction = @SRID;
-        SET Version = Hash;
         CALL insert_single_child_version(NewEntityID, Hash, Version, Null, Transaction);
     END IF;
 
diff --git a/procedures/registerSubdomain.sql b/procedures/registerSubdomain.sql
index ac7eebb..86a13b0 100644
--- a/procedures/registerSubdomain.sql
+++ b/procedures/registerSubdomain.sql
@@ -31,17 +31,19 @@
 DROP PROCEDURE IF EXISTS db_2_0.registerSubdomain;
 delimiter //
 
-CREATE PROCEDURE db_2_0.registerSubdomain(in Count INT UNSIGNED)
+CREATE PROCEDURE db_2_0.registerSubdomain(in amount INT UNSIGNED)
 BEGIN
     DECLARE ED INTEGER DEFAULT NULL;
 
-Select COUNT(id) INTO ED FROM entities WHERE Role='DOMAIN' AND id!=0;
-WHILE ED < Count DO
-		INSERT INTO entities (name, description, role, acl) VALUES (NULL, "Multipurpose subdomain", 'DOMAIN', 0);
-		SET ED = ED + 1;
-END WHILE;
+    SELECT COUNT(id) INTO ED FROM entities WHERE Role='DOMAIN' AND id!=0;
 
-SELECT id as DomainID FROM entities WHERE Role='DOMAIN' and id!=0;
+    WHILE ED < amount DO
+        INSERT INTO entities (name, description, role, acl) VALUES
+            (NULL, "Multipurpose subdomain", 'DOMAIN', 0);
+        SET ED = ED + 1;
+    END WHILE;
+
+    SELECT id as DomainID FROM entities WHERE Role='DOMAIN' and id!=0;
 
 END;
 //
diff --git a/procedures/retrieveEntity.sql b/procedures/retrieveEntity.sql
index 08cba84..7024451 100644
--- a/procedures/retrieveEntity.sql
+++ b/procedures/retrieveEntity.sql
@@ -41,8 +41,11 @@ retrieveEntityBody: BEGIN
 
 
     IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN
-        IF Version IS NULL THEN
+        IF Version IS NULL OR UPPER(Version) = "HEAD" THEN
             SET Version = get_head_version(EntityID);
+        ELSEIF UPPER(LEFT(Version, 5)) = "HEAD~" THEN
+            SET IsHead = FALSE;
+            SET Version = get_head_relative(EntityID, SUBSTR(Version, 6));
         ELSE
             SELECT get_head_version(EntityID) = Version INTO IsHead;
         END IF;
@@ -63,6 +66,7 @@ retrieveEntityBody: BEGIN
 
             IF IVersion IS NULL THEN
                 -- RETURN EARLY - Version does not exist.
+                SELECT 0 WHERE 0 = 1;
                 LEAVE retrieveEntityBody;
             END IF;
 
diff --git a/procedures/updateEntity.sql b/procedures/updateEntity.sql
index d14425a..e3c21af 100644
--- a/procedures/updateEntity.sql
+++ b/procedures/updateEntity.sql
@@ -41,8 +41,8 @@ CREATE PROCEDURE db_2_0.updateEntity(
     in ACL VARBINARY(65525))
 BEGIN
     DECLARE ACLID INT UNSIGNED DEFAULT NULL;
-    DECLARE Hash VARBINARY(255) DEFAULT SHA1(UUID());
-    DECLARE Version VARBINARY(255) DEFAULT NULL;
+    DECLARE Hash VARBINARY(255) DEFAULT NULL;
+    DECLARE Version VARBINARY(255) DEFAULT SHA1(UUID());
     DECLARE ParentVersion VARBINARY(255) DEFAULT NULL;
     DECLARE Transaction VARBINARY(255) DEFAULT NULL;
     DECLARE OldIVersion INT UNSIGNED DEFAULT NULL;
@@ -88,7 +88,6 @@ BEGIN
             FROM entity_version as e
             WHERE e.entity_id = EntityID
             AND e._iversion = OldIVersion;
-        SET Version = SHA1(concat(ParentVersion, Hash));
         CALL insert_single_child_version(
             EntityID, Hash, Version,
             ParentVersion, Transaction);
-- 
GitLab