From 7c496e093f43027810a9bdf1d2a38e0a60201e58 Mon Sep 17 00:00:00 2001
From: Daniel <daniel@harvey>
Date: Wed, 12 Aug 2020 16:29:26 +0200
Subject: [PATCH] DOC, STY: Added documentation, also some formatting.

---
 doc/table_structure.md                        | 64 +++++++++++++++++
 .../fix_unversioned.sql                       |  8 ++-
 .../patch20200710-3.0.0-rc2/versioning.sql    |  9 +--
 procedures/deleteEntityProperties.sql         |  5 +-
 procedures/deleteIsaCache.sql                 |  3 +-
 procedures/entityVersioning.sql               | 69 ++++++++++---------
 procedures/insertEntity.sql                   |  6 ++
 procedures/insertEntityProperty.sql           |  3 +
 procedures/retrieveEntity.sql                 | 33 +++++++--
 procedures/retrieveEntityOverrides.sql        |  7 +-
 procedures/retrieveEntityParents.sql          | 14 ++--
 procedures/retrieveEntityProperties.sql       |  3 +
 procedures/updateEntity.sql                   | 23 +++----
 tests/test_0_setup.sql                        | 22 ++++++
 tests/test_entity_versioning.sql              | 59 ++++++++++++----
 tests/test_insert_update_delete.sql           |  5 --
 tests/test_reference_values.sql               | 33 ++++++---
 17 files changed, 269 insertions(+), 97 deletions(-)

diff --git a/doc/table_structure.md b/doc/table_structure.md
index 3ec27dc..59958f5 100644
--- a/doc/table_structure.md
+++ b/doc/table_structure.md
@@ -56,6 +56,20 @@ These tables share (generally) the same set of columns:
 - `pidx` :: The property index, becomes nonzero when a property occurs more than
   once in an entity.
 
+### `name_data` ###
+
+This table is used to name RecordTypoes, Records, Properties etc.  The column `property_id` has the
+value 20, because that is the entity ID for names:
+
+```sql
+> SELECT * FROM entities WHERE id=20;
++----+-------------------+----------+------+
+| id | description       | role     | acl  |
++----+-------------------+----------+------+
+| 20 | Name of an entity | PROPERTY |    0 |
++----+-------------------+----------+------+
+```
+
 ## data_type ##
 The type of properties is stored here.  The columns are:
 - `domain_id` :: Property identitification, same as for plain data?
@@ -71,6 +85,56 @@ The type of properties is stored here.  The columns are:
 - `hash` :: Hash of the file contents, as binary. **TODO** Which algorithm?
 - `checked_timestamp` :: Timestamp when last checked? 
 
+## `feature_config` ##
++-------------------+---------+
+| _key              | _value  |
++-------------------+---------+
+| ENTITY_VERSIONING | ENABLED |
++-------------------+---------+
+
+A key-value store for features.  Use the `is_feature_config` procedure to check for the status of
+specific features.
+
+## Versioning tables ##
+
+There are a few extra tables for implementing versioning.  Also there is a special column
+`value_iversion` in the `reference_data` table which stores the version of the referenced entity at
+the time of the version.  If `value_iversion` is NULL, no specific version is stored.
+
+### transactions ###
+
+Replacement for `transaction_log`, holds ID, user and time of transaction:
+
+- `srid` :: Server request ID, used to identify transactions
+- `username` :: User name
+- `realm` :: Realm for which the user name is valid
+- `seconds` :: Time of transaction: seconds
+- `nanos` :: Time of transaction: sub-second time resolution
+
+### `entity_version` ###
+
+Versioning info for entities:
+
+- `entity_id` :: persistent ID of the entity
+- `hash` :: Hash, for future use.
+- `version` :: External version string, may be globally unique.  Should be used by API calls.
+- `_iversion` :: Version ID for this entity for internal use, typically an incremental counter,
+  starting with 1
+- `_ipparent` :: Primary parent ID (internal) for this version, i.e. predecessor
+- `srid` :: Server request / transaction ID which created this version
+
+### `archive_foo_data` ###
+
+Older (i.e. not current) data value, from previous versions of an entity.
+- `domain_id` :: Same as in `foo_data`.
+- `entity_id` :: Same as in `foo_data`.
+- `property_id` :: Same as in `foo_data`.
+- `value` :: The value at the given version.
+- `status` :: The value at the given version.
+- `pidx` :: Same as in `foo_data`.
+- `_iversion` :: Version index of this version.
+- ... :: Data type specific columns may also be there.
+
 ## TODO ##
 
 - entity_acl
diff --git a/patches/patch20200710-3.0.0-rc2/fix_unversioned.sql b/patches/patch20200710-3.0.0-rc2/fix_unversioned.sql
index 329706a..b3017b6 100644
--- a/patches/patch20200710-3.0.0-rc2/fix_unversioned.sql
+++ b/patches/patch20200710-3.0.0-rc2/fix_unversioned.sql
@@ -49,6 +49,8 @@ BEGIN
         INSERT IGNORE INTO transactions (srid, username, realm, seconds, nanos)
             SELECT tmp.srid, tmp.username, tmp.realm, tmp.seconds, tmp.nanos FROM (
                 SELECT
+                    -- SRID needs to be invented in this case, because original server request ID is
+                    -- not known (any more).
                     SHA2(CONCAT(username, realm, seconds, nanos), 512) AS srid,
                     username AS username,
                     realm AS realm,
@@ -57,15 +59,15 @@ BEGIN
                 FROM transaction_log
                 WHERE entity_id = unversioned_id
                 UNION SELECT
-                    -- this is for the standard entities (id<100)
+                    -- this is the fallback for the standard entities (id<100)
                     SHA2("", 512) AS srid,
                     "administration" As username,
                     "CaosDB" AS realm,
                     0 as seconds,
                     0 as nanos
-            ) AS tmp ORDER BY tmp.seconds DESC, tmp.nanos DESC LIMIT 1;
+            ) AS tmp ORDER BY tmp.seconds DESC, tmp.nanos DESC LIMIT 1; -- only latest transaction
 
-        -- insert single version into entity_version
+        -- insert single (latest) version into entity_version
         INSERT INTO entity_version (entity_id, hash, version, _iversion,
             _ipparent, srid)
             SELECT tmp.entity_id, tmp.hash, tmp.version, tmp._iversion,
diff --git a/patches/patch20200710-3.0.0-rc2/versioning.sql b/patches/patch20200710-3.0.0-rc2/versioning.sql
index 2be9925..9f29897 100644
--- a/patches/patch20200710-3.0.0-rc2/versioning.sql
+++ b/patches/patch20200710-3.0.0-rc2/versioning.sql
@@ -51,9 +51,9 @@ CREATE TABLE transactions (
 CREATE TABLE entity_version (
   entity_id INT UNSIGNED NOT NULL,
   hash VARBINARY(255) DEFAULT NULL,
-  version VARBINARY(255) NOT NULL,
-  _iversion INT UNSIGNED NOT NULL,
-  _ipparent INT UNSIGNED NULL,
+  version VARBINARY(255) NOT NULL, -- external version identifier, may be globally unique
+  _iversion INT UNSIGNED NOT NULL, -- internal version ID, typically an incremental counter
+  _ipparent INT UNSIGNED NULL,  -- (internal) ID of the primary parent, i.e. of the predecessor
   srid VARBINARY(255) NOT NULL,
   PRIMARY KEY (`entity_id`, `_iversion`),
   FOREIGN KEY (`entity_id`) REFERENCES `entities` (`id`) ON DELETE CASCADE,
@@ -72,7 +72,8 @@ CREATE TABLE archive_isa (
   child_iversion INT UNSIGNED NOT NULL,
   parent INT UNSIGNED NOT NULL,
   FOREIGN KEY (`parent`) REFERENCES `entities` (`id`) ON DELETE CASCADE,
-  FOREIGN KEY (`child`, `child_iversion`) REFERENCES `entity_version` (`entity_id`, `_iversion`) ON DELETE CASCADE
+  FOREIGN KEY (`child`, `child_iversion`) REFERENCES `entity_version`
+      (`entity_id`, `_iversion`) ON DELETE CASCADE
 ) ENGINE=InnoDB;
 
 CREATE TABLE archive_reference_data (
diff --git a/procedures/deleteEntityProperties.sql b/procedures/deleteEntityProperties.sql
index 1da3fef..2075696 100644
--- a/procedures/deleteEntityProperties.sql
+++ b/procedures/deleteEntityProperties.sql
@@ -4,6 +4,8 @@
  *
  * Copyright (C) 2018 Research Group Biomedical Physics,
  * Max-Planck-Institute for Dynamics and Self-Organization Göttingen
+ * Copyright (C) 2020 IndiScale GmbH <info@indiscale.com>
+ * Copyright (C) 2020 Timm Fitschen <t.fitschen@indiscale.com>
  *
  * This program is free software: you can redistribute it and/or modify
  * it under the terms of the GNU Affero General Public License as
@@ -31,10 +33,11 @@ BEGIN
     CALL deleteIsa(EntityID);
 
     IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN
-        SELECT max(e._iversion) INTO IVersion
+        SELECT max(e._iversion) INTO IVersion -- What's the latest version?
             FROM entity_version AS e
             WHERE e.entity_id = EntityID;
 
+        -- Copy the rows from *_data to archive_*_data ---------------------
         INSERT INTO archive_reference_data (domain_id, entity_id,
                 property_id, value, value_iversion, status, pidx, _iversion)
             SELECT domain_id, entity_id, property_id, value, value_iversion,
diff --git a/procedures/deleteIsaCache.sql b/procedures/deleteIsaCache.sql
index 1c0ab90..f37c3fc 100644
--- a/procedures/deleteIsaCache.sql
+++ b/procedures/deleteIsaCache.sql
@@ -5,6 +5,7 @@
  * Copyright (C) 2018 Research Group Biomedical Physics,
  * Max-Planck-Institute for Dynamics and Self-Organization Göttingen
  * Copyright (C) 2020 IndiScale GmbH <info@indiscale.com>
+ * Copyright (C) 2020 Timm Fitschen <t.fitschen@indiscale.com>
  *
  * This program is free software: you can redistribute it and/or modify
  * it under the terms of the GNU Affero General Public License as
@@ -48,7 +49,7 @@ BEGIN
             FROM entity_version
             WHERE entity_id = EntityID;
 
-        -- move to archive_isa before deleting
+        -- move to archive_isa before deleting (only direct child-parent relations)
         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 da0decb..b009d3f 100644
--- a/procedures/entityVersioning.sql
+++ b/procedures/entityVersioning.sql
@@ -18,26 +18,28 @@
  * along with this program. If not, see <https://www.gnu.org/licenses/>.
  */
 
-
-DROP PROCEDURE IF EXISTS db_2_0.insert_single_child_version;
 delimiter //
 
+DROP PROCEDURE IF EXISTS db_2_0.insert_single_child_version //
+
 /**
  * Creates a new version record in the `entity_version` table.
  *
  * Parameters
  * ----------
  * EntityID
- *   The id of the versioned entity.
+ *   The ID of the versioned entity.
  * Hash
  *   A hash of the entity. This is currently not implemented properly and only
  *   there for future use.
  * Version
- *   The id of the entity version.
+ *   The new version ID of the entity, must be produced by the caller.  Must be unique for each
+ *   EntityID.
  * Parent
- *   The primary parent version's id.
+ *   The version ID of the primary parent (i.e. predecessor).  May be NULL; but if given, it must
+ *   exist.
  * Transaction
- *   The id of the transaction which created this entity version (by inserting
+ *   The transaction ID which created this entity version (by inserting
  *   or updating an entity).
  */
 CREATE PROCEDURE db_2_0.insert_single_child_version(
@@ -137,7 +139,7 @@ END;
 DROP FUNCTION IF EXISTS db_2_0.get_primary_parent_version //
 
 /**
- * Get the version id of the primary parent of a version.
+ * Get the version ID of the primary parent (i.e. predecessor) of a version.
  *
  * Parameters
  * ----------
@@ -158,10 +160,9 @@ READS SQL DATA
 BEGIN
     RETURN (
         SELECT p.version
-            FROM entity_version AS e
-            INNER JOIN entity_version as p
-            ON (e._ipparent = p._iversion
-                AND e.entity_id = p.entity_id)
+            FROM entity_version AS e INNER JOIN entity_version AS p
+                ON (e._ipparent = p._iversion
+                    AND e.entity_id = p.entity_id)
             WHERE e.entity_id = EntityID
                 AND e.version = Version
         );
@@ -184,6 +185,7 @@ DROP FUNCTION IF EXISTS db_2_0.get_version_timestamp //
  * Returns
  * -------
  * The versions' timestamp in <seconds-since-epoch>.<nanoseconds> format.
+ * Note that the dot `.` here is not necessarily a decimal separator.
  */
 CREATE FUNCTION db_2_0.get_version_timestamp(
     EntityID INT UNSIGNED,
@@ -193,9 +195,8 @@ READS SQL DATA
 BEGIN
     RETURN (
         SELECT concat(t.seconds, '.', t.nanos)
-            FROM entity_version AS e
-            INNER JOIN transactions AS t
-            ON ( e.srid = t.srid )
+            FROM entity_version AS e INNER JOIN transactions AS t
+                ON ( e.srid = t.srid )
             WHERE e.entity_id = EntityID
             AND e.version = Version
     );
@@ -252,9 +253,9 @@ RETURNS VARBINARY(255)
 READS SQL DATA
 BEGIN
     -- This implementation assumes that the distance from the head equals the
-    -- difference between the _iversion numbers. This will not be correct anymore,
-    -- as soon as branches may split and merge. Then, an tree-walk will be
-    -- necessary, traversing the primary parents (_pparent), will be necessary.
+    -- difference between the _iversion numbers. This will not be correct anymore
+    -- as soon as branches may split and merge. Then, a walk over the primary
+    -- parents (_ipparent) will be necessary.
     RETURN (
         SELECT e.version
             FROM entity_version AS e
@@ -297,7 +298,7 @@ END;
 DROP PROCEDURE IF EXISTS db_2_0.get_version_history //
 
 /**
- * Select all version information of an entity.
+ * Select version timestamps of an entity.
  *
  * Parameters
  * ----------
@@ -306,18 +307,18 @@ DROP PROCEDURE IF EXISTS db_2_0.get_version_history //
  *
  * Selects
  * -------
- * Tuples (child, parent, child_seconds, child_nanos). child and parent are version ids.
+ * Tuples (child, parent, child_seconds, child_nanos). `child` and `parent` are
+ * version IDs.
  */
 CREATE PROCEDURE db_2_0.get_version_history(
     in EntityID INT UNSIGNED)
 BEGIN
-    -- retrieve root(s)
+    -- retrieve root(s) (initial versions)
     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
+        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
@@ -326,17 +327,17 @@ BEGIN
     -- does not return the root. However, this should be doable in one go with
     -- a left join instead of an inner join(?).
 
-    -- retrieve branches
+    -- retrieve branches (later versions)
     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)
+            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;
 //
@@ -368,7 +369,7 @@ CREATE PROCEDURE set_transaction(
     nanos INT(10) UNSIGNED)
 BEGIN
 
-    SET @SRID = srid;
+    SET @SRID = srid;  -- Make the transaction / server request ID globally available.
     INSERT INTO transactions (srid, username, realm, seconds, nanos)
         VALUES (srid, username, realm, seconds, nanos);
 END //
@@ -387,7 +388,8 @@ DROP PROCEDURE IF EXISTS setFileProperties //
  * EntityID
  *   The file's id.
  * FilePath
- *   Path of the file in the internal file system.
+ *   Path of the file in the internal file system.  If NULL, an existing file
+ *   entity is simply deleted.
  * FileSize
  *   Size of the file in bytes.
  * FileHash
@@ -426,10 +428,7 @@ END //
 DROP PROCEDURE IF EXISTS retrieveQueryTemplateDef //
 
 /**
- * Insert/Update file properties.
- *
- * If ENTITY_VERSIONING is enabled the old file properties are moved to
- * `archive_files`.
+ * Select a query string from the templates tables.
  *
  * Parameters
  * ----------
@@ -452,11 +451,13 @@ retrieveQueryTemplateDefBody: BEGIN
     DECLARE IsHead BOOLEAN DEFAULT TRUE;
 
     IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN
+        -- Are we at the head?
         IF Version IS NOT NULL THEN
             SELECT get_head_version(EntityID) = Version INTO IsHead;
         END IF;
 
         IF IsHead IS FALSE THEN
+            -- TODO Use get_iversion(EntityID, Version) instead?  Or will that be much slower?
             SELECT e._iversion INTO IVersion
                 FROM entity_version as e
                 WHERE e.entity_id = EntityID
diff --git a/procedures/insertEntity.sql b/procedures/insertEntity.sql
index 4816edd..50a3997 100644
--- a/procedures/insertEntity.sql
+++ b/procedures/insertEntity.sql
@@ -5,6 +5,7 @@
  * Copyright (C) 2018 Research Group Biomedical Physics,
  * Max-Planck-Institute for Dynamics and Self-Organization Göttingen
  * Copyright (C) 2020 IndiScale GmbH <info@indiscale.com>
+ * Copyright (C) 2020 Timm Fitschen <t.fitschen@indiscale
  *
  * This program is free software: you can redistribute it and/or modify
  * it under the terms of the GNU Affero General Public License as
@@ -39,6 +40,11 @@ Currently one of 'RECORDTYPE', 'RECORD', 'FILE', 'DOMAIN', 'PROPERTY',
 'DATATYPE', 'ROLE', 'QUERYTEMPLATE'
 
 ACL : VARBINARY(65525)
+
+Select
+======
+
+A tuple (EntityID, Version)
 */
 CREATE PROCEDURE db_2_0.insertEntity(in EntityName VARCHAR(255), in EntityDesc TEXT, in EntityRole VARCHAR(255), in ACL VARBINARY(65525))
 BEGIN
diff --git a/procedures/insertEntityProperty.sql b/procedures/insertEntityProperty.sql
index 8d7ab63..d208dbc 100644
--- a/procedures/insertEntityProperty.sql
+++ b/procedures/insertEntityProperty.sql
@@ -4,6 +4,8 @@
  *
  * Copyright (C) 2018 Research Group Biomedical Physics,
  * Max-Planck-Institute for Dynamics and Self-Organization Göttingen
+ * Copyright (C) 2020 IndiScale GmbH <info@indiscale.com>
+ * Copyright (C) 2020 Timm Fitschen <t.fitschen@indiscale
  *
  * This program is free software: you can redistribute it and/or modify
  * it under the terms of the GNU Affero General Public License as
@@ -59,6 +61,7 @@ BEGIN
         (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
 
+        -- special handling if versioning enabled and specific version of referenced entity is given.
         SET AT_PRESENT=LOCATE("@", PropertyValue);
         IF is_feature_config("ENTITY_VERSIONING", "ENABLED") AND AT_PRESENT > 0 THEN
             SET ReferenceValue = SUBSTRING_INDEX(PropertyValue, '@', 1);
diff --git a/procedures/retrieveEntity.sql b/procedures/retrieveEntity.sql
index 9451955..e06e6fb 100644
--- a/procedures/retrieveEntity.sql
+++ b/procedures/retrieveEntity.sql
@@ -4,6 +4,8 @@
  *
  * Copyright (C) 2018 Research Group Biomedical Physics,
  * Max-Planck-Institute for Dynamics and Self-Organization Göttingen
+ * Copyright (C) 2020 IndiScale GmbH <info@indiscale.com>
+ * Copyright (C) 2020 Timm Fitschen <t.fitschen@indiscale
  *
  * This program is free software: you can redistribute it and/or modify
  * it under the terms of the GNU Affero General Public License as
@@ -27,7 +29,24 @@ delimiter //
 
 drop procedure if exists db_2_0.retrieveEntity //
 
-create procedure db_2_0.retrieveEntity(in EntityID INT UNSIGNED, in Version VARBINARY(255))
+/**
+ * Select the content of an entity.
+ *
+ * By default the head is selected, but a specific version may be given.
+ *
+ * Parameters
+ * ----------
+ * EntityID
+ *   The entity's id.
+ * Version
+ *   The version id.  In this procedure only, the version may also be given as
+ *   `HEAD` for the latest version or as `HEAD~n`, which retrieves the n-th
+ *   ancestor of `HEAD`.
+ *
+ */
+create procedure db_2_0.retrieveEntity(
+    in EntityID INT UNSIGNED,
+    in Version VARBINARY(255))
 retrieveEntityBody: BEGIN
     DECLARE FilePath VARCHAR(255) DEFAULT NULL;
     DECLARE FileSize VARCHAR(255) DEFAULT NULL;
@@ -41,6 +60,7 @@ retrieveEntityBody: BEGIN
 
 
     IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN
+        -- Find out head-ness and version
         IF Version IS NULL OR UPPER(Version) = "HEAD" THEN
             SET Version = get_head_version(EntityID);
         ELSEIF UPPER(LEFT(Version, 5)) = "HEAD~" THEN
@@ -92,7 +112,8 @@ retrieveEntityBody: BEGIN
                 AND _iversion = IVersion
                 LIMIT 1;
 
-            Select
+            -- Final select before returning
+            SELECT
                 ( SELECT value FROM
                     ( SELECT value FROM name_data
                         WHERE domain_id = 0
@@ -110,7 +131,7 @@ retrieveEntityBody: BEGIN
                 e.role AS EntityRole,
                 FileSize AS FileSize,
                 FilePath AS FilePath,
-                FileHASh AS FileHASh,
+                FileHash AS FileHash,
                 (SELECT acl FROM entity_acl AS a WHERE a.id = e.acl) AS ACL,
                 Version AS Version,
                 VersionSeconds AS VersionSeconds,
@@ -126,13 +147,13 @@ retrieveEntityBody: BEGIN
         END IF;
     END IF;
 
-    Select path, size, hex(hash)
+    SELECT path, size, hex(hash)
         INTO FilePath, FileSize, FileHash
         FROM files
         WHERE file_id = EntityID
         LIMIT 1;
 
-    Select datatype INTO DatatypeID
+    SELECT datatype INTO DatatypeID
         FROM data_type
         WHERE domain_id=0
         AND entity_id=0
@@ -146,7 +167,7 @@ retrieveEntityBody: BEGIN
         AND property_id=EntityID
         LIMIT 1;
 
-    Select
+    SELECT
         ( SELECT value FROM name_data
             WHERE domain_id = 0
             AND entity_ID = DatatypeID
diff --git a/procedures/retrieveEntityOverrides.sql b/procedures/retrieveEntityOverrides.sql
index 7a929bb..fa43d6b 100644
--- a/procedures/retrieveEntityOverrides.sql
+++ b/procedures/retrieveEntityOverrides.sql
@@ -4,6 +4,8 @@
  *
  * Copyright (C) 2018 Research Group Biomedical Physics,
  * Max-Planck-Institute for Dynamics and Self-Organization Göttingen
+ * Copyright (C) 2020 Indiscale GmbH <info@indiscale.com>
+ * Copyright (C) 2020 Timm Fitschen <t.fitschen@indiscale.com>
  *
  * This program is free software: you can redistribute it and/or modify
  * it under the terms of the GNU Affero General Public License as
@@ -54,6 +56,7 @@ retrieveOverridesBody: BEGIN
                 LEAVE retrieveOverridesBody;
             END IF;
 
+            -- name
             SELECT
                 NULL AS collection_override,
                 name AS name_override,
@@ -68,6 +71,7 @@ retrieveOverridesBody: BEGIN
 
             UNION ALL
 
+            -- description
             SELECT
                 NULL AS collection_override,
                 NULL AS name_override,
@@ -82,6 +86,7 @@ retrieveOverridesBody: BEGIN
 
             UNION ALL
 
+            -- data type
             SELECT
                 NULL AS collection_override,
                 NULL AS name_override,
@@ -102,6 +107,7 @@ retrieveOverridesBody: BEGIN
 
             UNION ALL
 
+            -- collection
             SELECT
                 collection AS collection_override,
                 NULL AS name_override,
@@ -114,7 +120,6 @@ retrieveOverridesBody: BEGIN
             AND entity_id = EntityID
             AND _iversion = IVersion;
 
-
             LEAVE retrieveOverridesBody;
         END IF;
     END IF;
diff --git a/procedures/retrieveEntityParents.sql b/procedures/retrieveEntityParents.sql
index 6c50e97..16466fc 100644
--- a/procedures/retrieveEntityParents.sql
+++ b/procedures/retrieveEntityParents.sql
@@ -5,6 +5,7 @@
  * Copyright (C) 2018 Research Group Biomedical Physics,
  * Max-Planck-Institute for Dynamics and Self-Organization Göttingen
  * Copyright (C) 2020 IndiScale GmbH <info@indiscale.com>
+ * Copyright (C) 2020 Timm Fitschen <t.fitschen@indiscale.com>
  *
  * This program is free software: you can redistribute it and/or modify
  * it under the terms of the GNU Affero General Public License as
@@ -80,13 +81,13 @@ retrieveEntityParentsBody: BEGIN
                 ( SELECT value FROM archive_name_data
                     WHERE domain_id = 0
                     AND entity_id = ParentID
-                    AND property_id = 20 ) AS ParentName,
+                    AND property_id = 20
+                    AND _iversion = IVersion) AS ParentName,
                 e.description AS ParentDescription,
                 e.role AS ParentRole,
                 (SELECT acl FROM entity_acl AS a WHERE a.id = e.acl) AS ACL
-                FROM archive_isa AS i
-                JOIN entities AS e
-                ON (i.parent = e.id)
+                FROM archive_isa AS i JOIN entities AS e
+                    ON (i.parent = e.id)
                 WHERE i.child = EntityID
                 AND i.child_iversion = IVersion;
 
@@ -103,9 +104,8 @@ retrieveEntityParentsBody: BEGIN
         e.description AS ParentDescription,
         e.role AS ParentRole,
         (SELECT acl FROM entity_acl AS a WHERE a.id = e.acl) AS ACL
-        FROM isa_cache AS i
-        JOIN entities AS e
-        ON (i.parent = e.id)
+        FROM isa_cache AS i JOIN entities AS e
+            ON (i.parent = e.id)
         WHERE i.child = EntityID
         AND i.rpath = EntityID;
 END
diff --git a/procedures/retrieveEntityProperties.sql b/procedures/retrieveEntityProperties.sql
index e149702..3d8eeff 100644
--- a/procedures/retrieveEntityProperties.sql
+++ b/procedures/retrieveEntityProperties.sql
@@ -4,6 +4,8 @@
  *
  * Copyright (C) 2018 Research Group Biomedical Physics,
  * Max-Planck-Institute for Dynamics and Self-Organization Göttingen
+ * Copyright (C) 2020 IndiScale GmbH <info@indiscale.com>
+ * Copyright (C) 2020 Timm Fitschen <t.fitschen@indiscale.com>
  *
  * This program is free software: you can redistribute it and/or modify
  * it under the terms of the GNU Affero General Public License as
@@ -140,6 +142,7 @@ retrieveEntityPropertiesBody: BEGIN
             SELECT
                 property_id AS PropertyID,
                 IF(value_iversion IS NULL, value,
+                    -- make it "value@version" if necessary
                     CONCAT(value, "@", _get_version(value, value_iversion)))
                     AS PropertyValue,
                 status AS PropertyStatus,
diff --git a/procedures/updateEntity.sql b/procedures/updateEntity.sql
index 9260c25..226208e 100644
--- a/procedures/updateEntity.sql
+++ b/procedures/updateEntity.sql
@@ -4,6 +4,8 @@
  *
  * Copyright (C) 2018 Research Group Biomedical Physics,
  * Max-Planck-Institute for Dynamics and Self-Organization Göttingen
+ * Copyright (C) 2020 IndiScale GmbH <info@indiscale.com>
+ * Copyright (C) 2020 Timm Fitschen <t.fitschen@indiscale.com>
  *
  * This program is free software: you can redistribute it and/or modify
  * it under the terms of the GNU Affero General Public License as
@@ -21,16 +23,16 @@
  * ** end header
  */
 
-
-
-
-
-
-
-
 DROP PROCEDURE IF EXISTS db_2_0.updateEntity;
 delimiter //
 
+/*
+ * Update an entity (that is, its metadata like name, description, ...).
+ *
+ * At the moment, the version ID is generated internally.
+ *
+ * Selects the new version identifier for the entity.
+ */
 CREATE PROCEDURE db_2_0.updateEntity(
     in EntityID INT UNSIGNED,
     in EntityName VARCHAR(255),
@@ -54,8 +56,7 @@ BEGIN
             FROM entity_version
             WHERE entity_id = EntityID;
 
-
-        -- move old data to archive
+        -- move old data to archives
         INSERT INTO archive_entities (id, description, role,
                 acl, _iversion)
             SELECT e.id, e.description, e.role, e.acl, OldIVersion
@@ -81,8 +82,6 @@ BEGIN
             AND e.property_id = EntityID;
 
 
-
-
         SET Transaction = @SRID;
         SELECT e.version INTO ParentVersion
             FROM entity_version as e
@@ -96,7 +95,7 @@ BEGIN
     UPDATE entities e
         SET e.description = EntityDescription,
             e.role=EntityRole,
-            e.acl = ACLID 
+            e.acl = ACLID
         WHERE e.id = EntityID;
 
     -- clean up primary name, because updateEntity might be called without a
diff --git a/tests/test_0_setup.sql b/tests/test_0_setup.sql
index 9b98f5d..4068859 100644
--- a/tests/test_0_setup.sql
+++ b/tests/test_0_setup.sql
@@ -1,3 +1,25 @@
+/**
+ * ** header v3.0
+ * This file is a part of the CaosDB Project.
+ *
+ * Copyright (C) 2020 IndiScale GmbH <info@indiscale.com>
+ * Copyright (C) 2020 Timm Fitschen <t.fitschen@indiscale.com>
+ *
+ * This program is free software: you can redistribute it and/or modify
+ * it under the terms of the GNU Affero General Public License as
+ * published by the Free Software Foundation, either version 3 of the
+ * License, or (at your option) any later version.
+ *
+ * This program is distributed in the hope that it will be useful,
+ * but WITHOUT ANY WARRANTY; without even the implied warranty of
+ * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.  See the
+ * GNU Affero General Public License for more details.
+ *
+ * You should have received a copy of the GNU Affero General Public License
+ * along with this program. If not, see <https://www.gnu.org/licenses/>.
+ *
+ * ** end header
+ */
 
 /**
  * Execute an SQL statement and pass if the statement throws an SQLEXCEPTION.
diff --git a/tests/test_entity_versioning.sql b/tests/test_entity_versioning.sql
index 0446dce..0c5147c 100644
--- a/tests/test_entity_versioning.sql
+++ b/tests/test_entity_versioning.sql
@@ -1,3 +1,26 @@
+/**
+ * ** header v3.0
+ * This file is a part of the CaosDB Project.
+ *
+ * Copyright (C) 2020 IndiScale GmbH <info@indiscale.com>
+ * Copyright (C) 2020 Timm Fitschen <t.fitschen@indiscale.com>
+ *
+ * This program is free software: you can redistribute it and/or modify
+ * it under the terms of the GNU Affero General Public License as
+ * published by the Free Software Foundation, either version 3 of the
+ * License, or (at your option) any later version.
+ *
+ * This program is distributed in the hope that it will be useful,
+ * but WITHOUT ANY WARRANTY; without even the implied warranty of
+ * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.  See the
+ * GNU Affero General Public License for more details.
+ *
+ * You should have received a copy of the GNU Affero General Public License
+ * along with this program. If not, see <https://www.gnu.org/licenses/>.
+ *
+ * ** end header
+ */
+
 USE _caosdb_schema_unit_tests;
 BEGIN;
 CALL tap.no_plan();
@@ -17,7 +40,7 @@ CALL tap.no_plan();
 DELETE FROM entity_version;
 DELETE FROM transactions;
 DELETE FROM feature_config WHERE _key = "ENTITY_VERSIONING";
-INSERT INTO transactions (srid,seconds,nanos,username,realm) VALUES 
+INSERT INTO transactions (srid,seconds,nanos,username,realm) VALUES
 ("SRIDbla", 1234, 2345, "me", "home"),
 ("SRIDblub", 2345, 3465, "me", "home"),
 ("SRIDblieb", 3456, 4576, "you", "home");
@@ -37,7 +60,7 @@ SELECT tap.eq(@x, NULL, "no parent for the first version");
 
 -- add a second version
 SELECT count(*) INTO @x FROM entity_version;
-SELECT tap.eq(@x, 1, "one version there yet");
+SELECT tap.eq(@x, 1, "one version there already");
 CALL insert_single_child_version(@EntityID, "hashblub", "versionblub", "versionbla", "SRIDblub");
 
 SELECT _ipparent INTO @x from entity_version WHERE version="versionblub";
@@ -45,12 +68,15 @@ SELECT tap.eq(@x, 1, "the original entity is the parent");
 
 -- error: parent does not exist
 SELECT count(*) INTO @x FROM entity_version;
-SELECT tap.eq(@x, 2, "two version there yet");
+SELECT tap.eq(@x, 2, "two versions there already");
 
-CALL tap._assert_throws(concat("CALL insert_single_child_version(", @EntityID, ', "hashblieb", "versionblieb", "non-existing-parent", "SRIDBlieb")'), "non existing parent throws");
+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(@x, 2, "still two versions there");
 
 
 -- TEST get_primary_parent_version
@@ -196,11 +222,12 @@ SET @TheUser = "TheUser"; -- used to identify the matching entry in transaction_
 -- fill transaction_log: one entity with two updates (and one insert) and another entity with insert and delete.
 INSERT INTO transaction_log (transaction, entity_id, username, realm, seconds, nanos)
     -- the first entry is the one which is be found by _fix_unversioned
-    VALUES ("Update", @EntityID, @TheUser, "CaosDB", 23458, 254),
-    -- the rest is dummy data
-        ("Update", @EntityID, "OtherUser", "CaosDB", 2345, 633), -- not the latest transaction
-        ("Insert", @EntityID, "OtherUser", "CaosDB", 245, 633), -- not the latest transaction
-        ("Insert", @EntityID + 1, @TheUser, "CaosDB", 2325, 653), -- not the right entity, inserted before our target
+    VALUES
+        ("Update", @EntityID, @TheUser,     "CaosDB",  23458, 254),
+        -- the rest is dummy data
+        ("Update", @EntityID, "OtherUser",  "CaosDB",   2345, 633), -- not the latest transaction
+        ("Insert", @EntityID, "OtherUser",  "CaosDB",    245, 633), -- not the latest transaction
+        ("Insert", @EntityID + 1, @TheUser, "CaosDB",   2325, 653), -- not the right entity, inserted before our target
         ("Delete", @EntityID + 1, @TheUser, "CaosDB", 232526, 653); -- not the right entity, deleted after our target
 
 
@@ -214,12 +241,16 @@ SELECT tap.eq(COUNT(*), 0, "still, no transaction there") FROM transactions;
 
 -- call _fix_unversioned
 CALL _fix_unversioned();
-SELECT tap.eq(COUNT(*), @NumOfEntities, "after _fix_unversioned, one entry for our test entity in entity_version") FROM entity_version;
-SELECT tap.eq(COUNT(*), 2, "after _fix_unversioned, one entry for our test entity in transactions, one for the standard entities.") FROM transactions;
+SELECT tap.eq(COUNT(*), @NumOfEntities,
+    "after _fix_unversioned, one entry for our test entity in entity_version")
+    FROM entity_version;
+SELECT tap.eq(COUNT(*), 2,
+    "after _fix_unversioned, one entry for our test entity in transactions, one for the standard entities.")
+    FROM transactions;
 
 SELECT tap.eq(entity_id, @EntityID, "versioned entity has correct id") FROM entity_version WHERE entity_id > 99;
 SELECT tap.ok(srid IS NOT NULL, "srid was generated and user/time matches entries from transaction_log")
-    FROM transactions AS t JOIN transaction_log AS l 
+    FROM transactions AS t JOIN transaction_log AS l
     ON (l.seconds = t.seconds AND l.nanos = t.nanos AND l.username = t.username AND l.realm = t.realm)
     WHERE l.entity_id = @EntityID AND l.username = @TheUser;
 
@@ -249,7 +280,7 @@ SELECT entity_id INTO @EntityID2 FROM name_data WHERE value="EntityName2";
 
 INSERT INTO transaction_log (transaction, entity_id, username, realm, seconds,
         nanos)
-    -- the first entry is the one which is be found by _fix_unversioned
+    -- the first entry is the one which will be found by _fix_unversioned
     VALUES ("INSERT", @EntityID1, "User", "CaosDB", 10000, 250),
         ("INSERT", @EntityID2, "User", "CaosDB", 10000, 250),
         ("UPDATE", @EntityID2, "User", "CaosDB", 20000, 250);
diff --git a/tests/test_insert_update_delete.sql b/tests/test_insert_update_delete.sql
index a43e028..a11b05e 100644
--- a/tests/test_insert_update_delete.sql
+++ b/tests/test_insert_update_delete.sql
@@ -29,7 +29,6 @@ SELECT tap.eq(acl, @ACLID1, "correct acl id had been assigned")
 
 
 -- TEST insertEntityProperty
-
 CALL insertEntity("AProperty", "APropDesc", "PROPERTY", "{acl1}");
 SELECT entity_id INTO @PropID FROM name_data WHERE value="AProperty";
 INSERT INTO data_type (domain_id, entity_id, property_id, datatype) VALUES (0, 0, @PropID, @TextDatatypeID);
@@ -41,7 +40,6 @@ SELECT COUNT(*) INTO @x FROM null_data;
 SELECT tap.eq(@x, 1, "One row in null_data table");
 
 -- TEST updateEntity
-
 CALL updateEntity(@EntityID, "NewEntityName", "NewEntityDesc", "RECORD", NULL, NULL, "{acl2}");
 
 SELECT tap.eq(COUNT(entity_id), 0, "Old Entity name not present")
@@ -58,20 +56,17 @@ CALL updateEntity(@EntityID, "NewEntityName", "NewEntityDesc", "RECORD", NULL, N
 
 
 -- TEST deleteEntityProperties
-
 CALL deleteEntityProperties(@EntityID);
 SELECT COUNT(*) INTO @x FROM null_data;
 SELECT tap.eq(@x, 0, "data removed from null_data table");
 
 -- TEST deleteEntity
-
 CALL deleteEntity(@EntityID);
 CALL deleteEntity(@PropID);
 SELECT COUNT(id) INTO @x FROM entities WHERE id>100;
 SELECT tap.eq(@x, 0, "entity deleted");
 
 
-
 -- TESTS END
 
 CALL tap.finish();
diff --git a/tests/test_reference_values.sql b/tests/test_reference_values.sql
index e59c1f1..47b4db4 100644
--- a/tests/test_reference_values.sql
+++ b/tests/test_reference_values.sql
@@ -1,3 +1,26 @@
+/**
+ * ** header v3.0
+ * This file is a part of the CaosDB Project.
+ *
+ * Copyright (C) 2020 IndiScale GmbH <info@indiscale.com>
+ * Copyright (C) 2020 Timm Fitschen <t.fitschen@indiscale.com>
+ *
+ * This program is free software: you can redistribute it and/or modify
+ * it under the terms of the GNU Affero General Public License as
+ * published by the Free Software Foundation, either version 3 of the
+ * License, or (at your option) any later version.
+ *
+ * This program is distributed in the hope that it will be useful,
+ * but WITHOUT ANY WARRANTY; without even the implied warranty of
+ * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.  See the
+ * GNU Affero General Public License for more details.
+ *
+ * You should have received a copy of the GNU Affero General Public License
+ * along with this program. If not, see <https://www.gnu.org/licenses/>.
+ *
+ * ** end header
+ */
+
 USE _caosdb_schema_unit_tests;
 
 BEGIN;
@@ -8,10 +31,9 @@ CALL tap.no_plan();
 -- #####################################################################
 
 -- SETUP
-
 DELETE FROM entity_version;
 DELETE FROM transactions;
-INSERT INTO transactions (srid,seconds,nanos,username,realm) VALUES 
+INSERT INTO transactions (srid,seconds,nanos,username,realm) VALUES
 ("SRIDbla", 1234, 2345, "me", "home"),
 ("SRIDblub", 2345, 3465, "me", "home"),
 ("SRIDblieb", 3456, 4576, "you", "home");
@@ -22,7 +44,6 @@ 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);
@@ -36,7 +57,6 @@ 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;
 
@@ -44,7 +64,6 @@ 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");
 
@@ -110,13 +129,9 @@ CALL tap._assert_throws('
         NULL, "FIX", NULL, NULL, NULL, NULL, 0)', "non-existing-version id");
 
 
-
-
 -- #####################################################################
 -- TEST retrieveEntityProperty without Versioning
 -- #####################################################################
 
-
-
 CALL tap.finish();
 ROLLBACK;
-- 
GitLab