diff --git a/CHANGELOG.md b/CHANGELOG.md
index cc36c949648c9fb41391e01636d63ad307cf7f48..e312119a9a430febc8ca4ced11de5498983f81c5 100644
--- a/CHANGELOG.md
+++ b/CHANGELOG.md
@@ -9,14 +9,44 @@ and this project adheres to [Semantic Versioning](https://semver.org/spec/v2.0.0
 
 ### Added ###
 
+* Added a `_get_head_iversion` for non-api usage.
+
 ### Changed ###
 
+* Added a `versioned` flag to the following procedures:
+    * `applyBackReference`
+    * `applyIDFilter`
+    * `applyPOV`
+    * `applyRefPOV`
+    * `makeStmt`
+    * `calcComplementUnion`
+    * `calcDifference`
+    * `calcIntersection`
+    * `finishSubProperty`
+    * `getChildren`
+    * `initEmptyTargetSet`
+    * `initDisjunctionFilter`
+    * `initEntity`
+    * `initQuery`
+    * `createTmpTable`
+* Added a `direct` column to `archive_isa` table
+
 ### Deprecated ###
 
 ### Removed ###
 
+* unused procedures:
+    * `initNegationFilter`
+    * `initConjunctionFilter`
+    * `finishNegationFilter`
+
 ### Fixed ###
 
+* Semi-fix in `retrieveEntityParents`. The old implementation was buggy and
+  would return no parent name or even a wrong one for old entity versions in
+  some cases. The semi-fix will allways return the current name of the parent
+  (even if this is historically not always correct). A real fix awaits the
+  implementation of versioned isa-relations which is already planned.
 * Bug in `retrieveOverrides` function where selecting the datatype of an old
   version resultet in an error. See corresponding test in `caosdb-pyinttest`
   `tests/test_versioning.py::test_datatype_without_name`
diff --git a/README_SETUP.md b/README_SETUP.md
index 6a28c66f2dd95483656da8544414d9b43deb88c2..f5a9ab95c89fc7c1c6edbc217a2c3f239425dfd1 100644
--- a/README_SETUP.md
+++ b/README_SETUP.md
@@ -73,5 +73,11 @@ with the then current version of the stored entities.
 ## Unit tests
 
 * We use [MyTAP-1.0](https://hepabolu.github.io/mytap/) for unit tests.
+* Requirements:
+    * mysqladmin
+    * mysqldump
+    * mysql client program
 * Tests are in `tests/test_*.sql`.
 * Run `make test`.
+    * Alternatively, to run the tests in a containerized MariaDB instance, run `make test-docker`,
+      followed by `make test-docker-stop`.
diff --git a/doc/table_structure.md b/doc/table_structure.md
index 59958f5ff1b97caf9c791a1fbb5efce8fa2ca930..798404bc8c0ac19c7acfa64833082effedc9f0cd 100644
--- a/doc/table_structure.md
+++ b/doc/table_structure.md
@@ -101,7 +101,10 @@ There are a few extra tables for implementing versioning.  Also there is a speci
 `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 ###
+The `_iversion` is an incremental version counter, starting implicitly at 1.  Previous versions of
+entities are stored, along with their `_iversion`, in the `archive_*` tables.
+
+### `transactions` ###
 
 Replacement for `transaction_log`, holds ID, user and time of transaction:
 
@@ -123,15 +126,15 @@ Versioning info for entities:
 - `_ipparent` :: Primary parent ID (internal) for this version, i.e. predecessor
 - `srid` :: Server request / transaction ID which created this version
 
-### `archive_foo_data` ###
+### `archive_footable` ###
 
-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`.
+Older (i.e. not current) data, from previous versions of an entity which were stored in `footable`.
+- `domain_id` :: Same as in `footable`.
+- `entity_id` :: Same as in `footable`.
+- `property_id` :: Same as in `footable`.
 - `value` :: The value at the given version.
 - `status` :: The value at the given version.
-- `pidx` :: Same as in `foo_data`.
+- `pidx` :: Same as in `footable`.
 - `_iversion` :: Version index of this version.
 - ... :: Data type specific columns may also be there.
 
diff --git a/patches/patch20201110-4.0.0-rc1/patch.sh b/patches/patch20201110-4.0.0-rc1/patch.sh
new file mode 100755
index 0000000000000000000000000000000000000000..c784a055d2db19d6010647439c603daf9b7a0c27
--- /dev/null
+++ b/patches/patch20201110-4.0.0-rc1/patch.sh
@@ -0,0 +1,50 @@
+#!/bin/bash
+#
+# ** header v3.0
+# This file is a part of the CaosDB Project.
+#
+# 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
+# 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
+#
+# Update mysql schema to version v4.0.0-rc1
+NEW_VERSION="v4.0.0-rc1"
+OLD_VERSION="v3.0.0-rc2"
+
+if [ -z "$UTILSPATH" ]; then
+ UTILSPATH="../utils"
+fi
+
+. $UTILSPATH/patch_header.sh $*
+
+
+check_version $OLD_VERSION
+
+# * Add a `direct` column to `archive_isa` table
+# * Remove unused procedures:
+#    * `initNegationFilter`
+#    * `initConjunctionFilter`
+#    * `finishNegationFilter`
+mysql_execute_file $PATCH_DIR/update_archive_isa.sql
+
+
+update_version $NEW_VERSION
+
+success
+
diff --git a/patches/patch20201110-4.0.0-rc1/update_archive_isa.sql b/patches/patch20201110-4.0.0-rc1/update_archive_isa.sql
new file mode 100644
index 0000000000000000000000000000000000000000..9beaa857a28ec520a26b6e912e7ce0c9b918b76e
--- /dev/null
+++ b/patches/patch20201110-4.0.0-rc1/update_archive_isa.sql
@@ -0,0 +1,27 @@
+/*
+ * 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/>.
+ */
+
+-- remove unused procedures
+DROP PROCEDURE IF EXISTS db_2_0.initNegationFilter;
+DROP PROCEDURE IF EXISTS db_2_0.initConjunctionFilter;
+DROP PROCEDURE IF EXISTS db_2_0.finishNegationFilter;
+
+ALTER TABLE archive_isa
+    ADD COLUMN `direct` BOOLEAN DEFAULT TRUE;
diff --git a/procedures/deleteIsaCache.sql b/procedures/deleteIsaCache.sql
index c0fc831fb3482419a2c8215a06c693cdef16179c..1ffff23e0b6e876ad8aaef21554a26f723cc6c94 100644
--- a/procedures/deleteIsaCache.sql
+++ b/procedures/deleteIsaCache.sql
@@ -50,12 +50,11 @@ BEGIN
             FROM entity_version
             WHERE entity_id = EntityID;
 
-        -- 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
+        -- move to archive_isa before deleting
+        INSERT IGNORE INTO archive_isa (child, child_iversion, parent, direct)
+            SELECT e.child, IVersion AS child_iversion, e.parent, rpath = EntityID
             FROM isa_cache AS e
-            WHERE e.child = EntityID
-            AND e.rpath = CAST(EntityID AS CHAR);
+            WHERE e.child = EntityID;
     END IF;
 
     DELETE FROM isa_cache
diff --git a/procedures/entityVersioning.sql b/procedures/entityVersioning.sql
index b009d3f2ab8dd58ecb2199e57c40b99419007a0d..baf1e56f5fd0f3d64446df484602921f367255e2 100644
--- a/procedures/entityVersioning.sql
+++ b/procedures/entityVersioning.sql
@@ -226,6 +226,38 @@ BEGIN
 END;
 //
 
+DROP FUNCTION IF EXISTS db_2_0._get_head_iversion //
+
+/**
+ * Get the _iversion number of the HEAD of an entity.
+ *
+ * Parameters
+ * ----------
+ * EntityID
+ *   The entity id.
+ *
+ * Returns
+ * -------
+ * The _iversion of the HEAD.
+ */
+CREATE FUNCTION db_2_0._get_head_iversion(
+    EntityID INT UNSIGNED)
+RETURNS INT UNSIGNED
+READS SQL DATA
+BEGIN
+    -- This implementation assumes that the history is linear and the highest
+    -- _iversion number is always the head. 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._iversion
+            FROM entity_version AS e
+            WHERE e.entity_id = EntityID
+            ORDER BY e._iversion DESC
+            LIMIT 1
+        );
+END;
+
 
 DROP FUNCTION IF EXISTS db_2_0.get_head_relative //
 
diff --git a/procedures/query/applyBackReference.sql b/procedures/query/applyBackReference.sql
index 9a2450750b42963fcff5de1e02e0054097ecc7fa..2d74f74db8cc43e1b0c54c61d09c75042c2247ab 100644
--- a/procedures/query/applyBackReference.sql
+++ b/procedures/query/applyBackReference.sql
@@ -4,6 +4,9 @@
  *
  * 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>
+ * Copyright (C) 2020 Daniel Hornung <d.hornung@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
@@ -24,39 +27,205 @@
 DROP PROCEDURE IF EXISTS db_2_0.applyBackReference;
 DELIMITER //
 
-CREATE PROCEDURE db_2_0.applyBackReference(in sourceSet VARCHAR(255), targetSet VARCHAR(255), in propertiesTable VARCHAR(255), in entitiesTable VARCHAR(255), in subQuery BOOLEAN) 
+/**
+ * Process a set of entities, keeping those which are referenced in a specific way.
+ *
+ * This procedure filters a source table and writes the result into a target table.  If
+ * the target table is not given, all non-matching entries are deleted from the source table
+ * instead.
+ *
+ * Candidate entities are allowed to pass if there is an entity from the entities table which
+ * references the candidate as one of the properties in the properties table.
+ *
+ * Parameters
+ * ----------
+ * sourceSet : table
+ * The name of the table which shall be filtered, must have column `id`.
+ *
+ * targetSet : table
+ * The name of the result table, must have column `id`.
+ *
+ * propertiesTable : table
+ * References as Properties in this table are counted.
+ *
+ * entitiesTable : table
+ * References by Entities in this table are counted.
+ *
+ * subQuery : boolean
+ * Create a temporary target table and select as `list`, instead of using the given targetSet.  The
+ * `versioned` parameter has no effect in this case.
+ *
+ * versioned : boolean
+ * If True, if a reference is versioned (references to specific versions of entities), the target
+ * candidate's version must match.  Therefore, the sourceSet and targetSet must have a `_iversion`
+ * column as well (unless sourceSet is the `entities` table).
+ *
+ */
+CREATE PROCEDURE db_2_0.applyBackReference(in sourceSet VARCHAR(255), targetSet VARCHAR(255),
+    in propertiesTable VARCHAR(255), in entitiesTable VARCHAR(255), in subQuery BOOLEAN,
+    in versioned BOOLEAN)
 BEGIN
-	DECLARE newTableName VARCHAR(255) DEFAULT NULL;
+    DECLARE newTableName VARCHAR(255) DEFAULT NULL;
+
+
+    IF subQuery IS TRUE THEN
+        call registerTempTableName(newTableName);
+
+        SET @createBackRefSubQueryTableStr = CONCAT('CREATE TEMPORARY TABLE `',newTableName,'` ( entity_id INT UNSIGNED NOT NULL, id INT UNSIGNED NOT NULL, CONSTRAINT `',newTableName,'PK` PRIMARY KEY (id, entity_id))');
+
+        PREPARE createBackRefSubQueryTable FROM @createBackRefSubQueryTableStr;
+        EXECUTE createBackRefSubQueryTable;
+        DEALLOCATE PREPARE createBackRefSubQueryTable;
 
+        SET @backRefSubResultSetStmtStr = CONCAT('INSERT IGNORE INTO `',
+            newTableName,
+            '` (id,entity_id) SELECT entity_id AS id, value AS entity_id FROM `reference_data` AS data ',
+            'WHERE EXISTS (SELECT 1 FROM `',
+                sourceSet,
+                '` AS source WHERE source.id=data.value LIMIT 1)',
+            IF(propertiesTable IS NULL,
+                '',
+                CONCAT(' AND EXISTS (SELECT 1 FROM `',
+                    propertiesTable,
+                    '` AS p WHERE p.id=data.property_id LIMIT 1)')),
+            IF(entitiesTable IS NULL,
+                '',
+                CONCAT(' AND EXISTS (SELECT 1 FROM `',
+                    entitiesTable,
+                    '` AS e WHERE e.id=data.entity_id LIMIT 1)'))
+        );
 
-	IF subQuery IS TRUE THEN
-		call registerTempTableName(newTableName);
+        PREPARE backRefSubResultSetStmt FROM @backRefSubResultSetStmtStr;
+        EXECUTE backRefSubResultSetStmt;
+        DEALLOCATE PREPARE backRefSubResultSetStmt;
 
-		SET @createBackRefSubQueryTableStr = CONCAT('CREATE TEMPORARY TABLE `',newTableName,'` ( entity_id INT UNSIGNED NOT NULL, id INT UNSIGNED NOT NULL, CONSTRAINT `',newTableName,'PK` PRIMARY KEY (id, entity_id))');
+        SELECT newTableName as list;
+    ELSE
+        IF versioned THEN
+            IF sourceSet = "entities" THEN
+                -- Find any referenced entity, current or archived
+                SET @stmtBackRefStr = CONCAT('INSERT IGNORE INTO `',
+                    targetSet,
+                    '` (id, _iversion) SELECT source.id, _get_head_iversion(source.id)',
+                    -- current entities
+                    ' FROM entities AS source WHERE EXISTS (',
+                        'SELECT 1 FROM `reference_data` AS data WHERE data.value=source.id AND (',
+                            'data.value_iversion IS NULL OR data.value_iversion=_get_head_iversion(source.id))',
+                    IF(entitiesTable IS NULL,
+                        '',
+                        CONCAT(' AND EXISTS (SELECT 1 FROM `',
+                            entitiesTable,
+                            '` AS e WHERE e.id=data.entity_id LIMIT 1)')),
+                    IF(propertiesTable IS NULL,
+                        '',
+                        CONCAT(' AND EXISTS (SELECT 1 FROM `',
+                            propertiesTable,
+                            '` AS p WHERE p.id=data.property_id LIMIT 1)')),
+                    ') UNION ALL ',
+                    -- and archived entities
+                    'SELECT source.id, source._iversion FROM archive_entities AS source WHERE EXISTS (',
+                        'SELECT 1 FROM `reference_data` AS data WHERE data.value=source.id AND ',
+                          '(data.value_iversion IS NULL OR data.value_iversion=source._iversion)',
+                    IF(entitiesTable IS NULL,
+                        '',
+                        CONCAT(' AND EXISTS (SELECT 1 FROM `',
+                            entitiesTable,
+                            '` AS e WHERE e.id=data.entity_id LIMIT 1)')),
+                    IF(propertiesTable IS NULL,
+                        '',
+                        CONCAT(' AND EXISTS (SELECT 1 FROM `',
+                            propertiesTable,
+                            '` AS p WHERE p.id=data.property_id LIMIT 1)')),
 
-		PREPARE createBackRefSubQueryTable FROM @createBackRefSubQueryTableStr;
-		EXECUTE createBackRefSubQueryTable;
-		DEALLOCATE PREPARE createBackRefSubQueryTable;
+                    ')');
+            ELSEIF targetSet IS NULL OR sourceSet = targetSet THEN
+                SET @stmtBackRefStr = CONCAT('DELETE FROM `',
+                    sourceSet,
+                    '` WHERE NOT EXISTS (SELECT 1 FROM `reference_data` AS data WHERE data.value=`',
+                    sourceSet,
+                    '`.`id` AND ( data.value_iversion IS NULL OR data.value_iversion=`',
+                    sourceSet,
+                    '`._iversion)',
+                    IF(entitiesTable IS NULL,
+                        '',
+                        CONCAT(' AND EXISTS (SELECT 1 FROM `',
+                            entitiesTable,
+                            '` AS e WHERE e.id=data.entity_id LIMIT 1)')),
+                    IF(propertiesTable IS NULL,
+                        '',
+                        CONCAT(' AND EXISTS (SELECT 1 FROM `',
+                            propertiesTable,
+                            '` AS p WHERE p.id=data.property_id LIMIT 1)')),
+                    ')');
+            ELSE
+                SET @stmtBackRefStr = CONCAT('INSERT IGNORE INTO `',
+                    targetSet,
+                    '` (id, _iversion) SELECT source.id, source._iversion FROM `',
+                    sourceSet,
+                    '` AS source WHERE EXISTS (',
+                    'SELECT 1 FROM `reference_data` AS data WHERE data.value=source.id AND',
+                    ' (data.value_iversion IS NULL OR data.value_iversion=source._iversion)',
+                    IF(entitiesTable IS NULL,
+                        '',
+                        CONCAT(' AND EXISTS (SELECT 1 FROM `',
+                            entitiesTable,
+                            '` AS e WHERE e.id=data.entity_id LIMIT 1)')),
+                    IF(propertiesTable IS NULL,
+                        '',
+                        CONCAT(' AND EXISTS (SELECT 1 FROM `',
+                            propertiesTable,
+                            '` AS p WHERE p.id=data.property_id LIMIT 1)')),
 
-		SET @backRefSubResultSetStmtStr = CONCAT('INSERT IGNORE INTO `',newTableName,'` (id,entity_id) SELECT entity_id AS id, value AS entity_id FROM `reference_data` AS data WHERE EXISTS (SELECT 1 FROM `',sourceSet,'` AS source WHERE source.id=data.value LIMIT 1)', IF(propertiesTable IS NULL,'',CONCAT(' AND EXISTS (SELECT 1 FROM `',propertiesTable,'` AS p WHERE p.id=data.property_id LIMIT 1)')), IF(entitiesTable IS NULL,'',CONCAT(' AND EXISTS (SELECT 1 FROM `',entitiesTable,'` AS e WHERE e.id=data.entity_id LIMIT 1)')));
+                    ')');
+            END IF;
+        ELSE
+            -- unversioned queries
+            IF targetSet IS NULL OR sourceSet = targetSet THEN
+                -- delete from sourceSet
+                SET @stmtBackRefStr = CONCAT('DELETE FROM `',
+                    sourceSet,
+                    '` WHERE NOT EXISTS (SELECT 1 FROM `reference_data` AS data WHERE data.value=`',
+                    sourceSet,
+                    '`.`id`',
+                    IF(entitiesTable IS NULL,
+                        '',
+                        CONCAT('
+                            AND EXISTS (SELECT 1 FROM `',
+                            entitiesTable,
+                            '` AS e WHERE e.id=data.entity_id LIMIT 1)')),
+                    IF(propertiesTable IS NULL,
+                        '',
+                        CONCAT('
+                            AND EXISTS (SELECT 1 FROM `',
+                            propertiesTable,
+                            '` AS p WHERE p.id=data.property_id LIMIT 1)')),
+                    ')');
+            ELSE
+                -- write to targetSet
+                SET @stmtBackRefStr = CONCAT('INSERT IGNORE INTO `',
+                    targetSet,
+                    '` (id) SELECT id FROM `',
+                    sourceSet,
+                    '` AS source WHERE EXISTS (SELECT 1 FROM `reference_data` AS data WHERE data.value=source.id',
+                    IF(entitiesTable IS NULL,
+                        '',
+                        CONCAT(' AND EXISTS (SELECT 1 FROM `',
+                            entitiesTable,
+                            '` AS e WHERE e.id=data.entity_id LIMIT 1)')),
+                    IF(propertiesTable IS NULL,
+                        '',
+                        CONCAT(' AND EXISTS (SELECT 1 FROM `',
+                            propertiesTable,
+                            '` AS p WHERE p.id=data.property_id LIMIT 1)')),
+                    ')');
+            END IF;
+        END IF;
 
-		PREPARE backRefSubResultSetStmt FROM @backRefSubResultSetStmtStr;
-		EXECUTE backRefSubResultSetStmt;
-		DEALLOCATE PREPARE backRefSubResultSetStmt;
+        PREPARE stmtBackRef FROM @stmtBackRefStr;
+        EXECUTE stmtBackRef;
+        DEALLOCATE PREPARE stmtBackRef;
+    END IF;
 
-		SELECT newTableName as list;	
-	ELSE 
-	    IF targetSet IS NULL OR sourceSet = targetSet THEN
-        	SET @stmtBackRefStr = CONCAT('DELETE FROM `', sourceSet, '` WHERE NOT EXISTS (SELECT 1 FROM `reference_data` AS data WHERE data.value=`', sourceSet, '`.`id`', IF(entitiesTable IS NULL, '', CONCAT(' AND EXISTS (SELECT 1 FROM `', entitiesTable, '` AS e WHERE e.id=data.entity_id LIMIT 1)')), IF(propertiesTable IS NULL, '', CONCAT(' AND EXISTS (SELECT 1 FROM `', propertiesTable, '` AS p WHERE p.id=data.property_id LIMIT 1)')), ')');
-    	ELSE
-        	SET @stmtBackRefStr = CONCAT('INSERT IGNORE INTO `', targetSet, '` (id) SELECT id FROM `',sourceSet,'` AS source WHERE EXISTS (SELECT 1 FROM `reference_data` AS data WHERE data.value=source.id', IF(entitiesTable IS NULL, '', CONCAT(' AND EXISTS (SELECT 1 FROM `', entitiesTable, '` AS e WHERE e.id=data.entity_id LIMIT 1)')), IF(propertiesTable IS NULL, '', CONCAT(' AND EXISTS (SELECT 1 FROM `', propertiesTable, '` AS p WHERE p.id=data.property_id LIMIT 1)')), ')');
-    	END IF;
-    
-    	PREPARE stmtBackRef FROM @stmtBackRefStr;
-    	EXECUTE stmtBackRef;
-    	DEALLOCATE PREPARE stmtBackRef;
-	END IF;
-	
 END;
 //
 
diff --git a/procedures/query/applyIDFilter.sql b/procedures/query/applyIDFilter.sql
index 56adf53d19916049accbaf71e866ab36efb6abd2..c9b876420493a61da7ff174e58b750976b79520f 100644
--- a/procedures/query/applyIDFilter.sql
+++ b/procedures/query/applyIDFilter.sql
@@ -25,32 +25,106 @@ DROP PROCEDURE IF EXISTS db_2_0.applyIDFilter;
 
 DELIMITER //
 
-CREATE PROCEDURE db_2_0.applyIDFilter(in sourceSet VARCHAR(255), in targetSet VARCHAR(255), in o CHAR(2), in vInt BIGINT, in agg CHAR(3))
+/**
+ * Filter the sourceSet into targetSet by ID.
+ *
+ * This can be done by operator-value tests or by aggregate functions.
+ *
+ * The `versioned` flag currently only has the effect that an `_iversion` column is also copied to
+ * the target.
+ */
+CREATE PROCEDURE db_2_0.applyIDFilter(in sourceSet VARCHAR(255), in targetSet VARCHAR(255),
+    in o CHAR(2), in vInt BIGINT, in agg CHAR(3), in versioned BOOLEAN)
 IDFILTER_LABEL: BEGIN
 DECLARE data VARCHAR(20000) DEFAULT NULL;
 DECLARE aggVal VARCHAR(255) DEFAULT NULL;
 
 #-- get aggVal if possible
 IF agg IS NOT NULL THEN
-	SET @stmtIDAggValStr = CONCAT("SELECT ", agg, "(id) INTO @sAggVal FROM `", sourceSet, "`");
-	PREPARE stmtIDAggVal FROM @stmtIDAggValStr;
-	EXECUTE stmtIDAggVal;
+    IF versioned THEN
+        -- TODO versioned queries
+        SELECT 1 FROM id_agg_with_versioning_not_implemented;
+    END IF;
+    SET @stmtIDAggValStr = CONCAT(
+        "SELECT ",
+        agg,
+        "(id) INTO @sAggVal FROM `",
+        sourceSet,
+        "`");
+    PREPARE stmtIDAggVal FROM @stmtIDAggValStr;
+    EXECUTE stmtIDAggVal;
     DEALLOCATE PREPARE stmtIDAggVal;
     SET aggVal = @sAggVal;
 END IF;
 
 #-- generate stmt string
 IF targetSet IS NULL OR targetSet = sourceSet THEN
-    SET data = CONCAT("DELETE FROM `",sourceSet,"` WHERE ",IF(o IS NULL OR vInt IS NULL,"1=1",CONCAT("NOT id",o,vInt)),IF(aggVal IS NULL, "", CONCAT(" AND id!=",aggVal)));
+    SET data = CONCAT(
+        "DELETE FROM `",
+        sourceSet,
+        "` WHERE ",
+        IF(o IS NULL OR vInt IS NULL,
+            "1=1",
+            CONCAT("NOT id",
+                o,
+                vInt)),
+        IF(aggVal IS NULL,
+            "",
+            CONCAT(" AND id!=",
+                aggVal)));
+ELSEIF versioned AND sourceSet = "entities" THEN
+
+    -- ################# VERSIONING #####################
+    SET data = CONCAT(
+        "INSERT IGNORE INTO `",
+        targetSet,
+        '` (id, _iversion) SELECT id, _get_head_iversion(id) FROM `entities` WHERE ',
+        IF(o IS NULL OR vInt IS NULL,
+            "1=1",
+            CONCAT("id",
+                o,
+                vInt)),
+        IF(aggVal IS NULL,
+            "",
+            CONCAT(" AND id=",
+                aggVal)),
+        ' UNION SELECT id, _iversion FROM `archive_entities` WHERE ',
+        IF(o IS NULL OR vInt IS NULL,
+            "1=1",
+            CONCAT("id",
+                o,
+                vInt)),
+        IF(aggVal IS NULL,
+            "",
+            CONCAT(" AND id=",
+                aggVal)));
+    -- ##################################################
+
 ELSE
-    SET data = CONCAT("INSERT IGNORE INTO `",targetSet,"` SELECT data.id as id FROM `",sourceSet,"` AS data WHERE ",IF(o IS NULL OR vInt IS NULL,"1=1",CONCAT("data.id",o,vInt)),IF(aggVal IS NULL, "", CONCAT(" AND data.id=", aggVal)));
+    SET data = CONCAT(
+        "INSERT IGNORE INTO `",
+        targetSet,
+        IF(versioned,
+            '` (id, _iversion) SELECT data.id, data._iversion FROM `',
+            '` (id) SELECT data.id FROM `'),
+        sourceSet,
+        "` AS data WHERE ",
+        IF(o IS NULL OR vInt IS NULL,
+            "1=1",
+            CONCAT("data.id",
+                o,
+                vInt)),
+        IF(aggVal IS NULL,
+            "",
+            CONCAT(" AND data.id=",
+                aggVal)));
 END IF;
 
 Set @stmtIDFilterStr = data;
 PREPARE stmtIDFilter FROM @stmtIDFilterStr;
 EXECUTE stmtIDFilter;
 DEALLOCATE PREPARE stmtIDFilter;
-	
+
 END;
 //
 
diff --git a/procedures/query/applyPOV.sql b/procedures/query/applyPOV.sql
index bf49d930a7daab9d1cd81de482b5dc6d8dd4f462..732854be91b5dcda817da3faa00c9ba727a31e3e 100644
--- a/procedures/query/applyPOV.sql
+++ b/procedures/query/applyPOV.sql
@@ -27,6 +27,19 @@
 DROP PROCEDURE IF EXISTS db_2_0.applyPOV;
 DELIMITER //
 
+/**
+ * Apply a Property-Operator-Value filter to sourceSet.
+ *
+ * The result is written to targetSet (non-matching rows are deleted in sourceSet if no targetSet is
+ * given).
+ *
+ * Parameters
+ * ----------
+ *
+ * versioned : boolean
+ * If True, sourceSet and targetSet have an _iversion column, otherwise that column will be ignored
+ * (or only HEAD will be inserted into targetSet).
+ */
 CREATE PROCEDURE db_2_0.applyPOV(in sourceSet VARCHAR(255), /* (?) Name of the table that the POV will be applied to. This can be a temporary table. */
                                  in targetSet VARCHAR(255), /* (?) Name of the result table of this POV. */
                                  in propertiesTable VARCHAR(255),
@@ -51,7 +64,8 @@ CREATE PROCEDURE db_2_0.applyPOV(in sourceSet VARCHAR(255), /* (?) Name of the t
                                  in vDateTime VARCHAR(255),
                                  in vDateTimeDotNotation VARCHAR(255),
                                  in agg CHAR(3), /* an SQL aggregate function or NULL when no aggregation should be used */
-                                 in pname VARCHAR(255)) /* name of the property, this name is only used for reporting more meaningful warnings */
+                                 in pname VARCHAR(255), /* name of the property, this name is only used for reporting more meaningful warnings */
+                                 in versioned BOOLEAN)
 POV_LABEL: BEGIN
     DECLARE data TEXT DEFAULT NULL; /*data subselect statement string*/
     DECLARE sTextData VARCHAR(20000) DEFAULT NULL; /*SELECT PREFIX for data subselect plus WHERE CLAUSE for text_data*/
@@ -71,7 +85,7 @@ POV_LABEL: BEGIN
 
     IF o = '->' THEN
         #-- special case: pure reference property
-        call applyRefPOV(sourceSet,targetSet, propertiesTable, refIdsTable);
+        call applyRefPOV(sourceSet,targetSet, propertiesTable, refIdsTable, versioned);
         LEAVE POV_LABEL;
     ELSEIF o = '0' THEN
         #-- special case: property IS NULL
@@ -98,17 +112,57 @@ POV_LABEL: BEGIN
              SELECT DISTINCT -> No duplicate values
              UNION ALL -> Allow also duplicate values
         */
-        SET sTextData = 'SELECT DISTINCT domain_id, entity_id, property_id FROM `text_data` AS subdata WHERE subdata.value IS NOT NULL UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `name_data` AS subdata WHERE subdata.value IS NOT NULL UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `enum_data` AS subdata WHERE subdata.value IS NOT NULL UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `integer_data` AS subdata WHERE subdata.value IS NOT NULL UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `double_data` AS subdata WHERE subdata.value IS NOT NULL UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `date_data` AS subdata WHERE subdata.value IS NOT NULL UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `datetime_data` AS subdata WHERE subdata.value IS NOT NULL UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `reference_data` AS subdata WHERE subdata.value IS NOT NULL';
-
-    ELSEIF o = "(" or o = "!(" THEN
-        SET sTextData = IF(vText IS NULL, ' SELECT DISTINCT domain_id, entity_id, property_id FROM `date_data`',
-                                          IF(vDateTimeDotNotation IS NULL, NULL,
-                                                                           CONCAT(' SELECT DISTINCT domain_id, entity_id, property_id FROM `date_data` AS subdata WHERE ', getDateWhereClause(vDateTimeDotNotation, o))));
-        SET sDatetimeData = IF(vText IS NULL, ' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `datetime_data`',
-                                              IF(vDateTime IS NULL, NULL,
-                                                                    CONCAT(' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `datetime_data` AS subdata WHERE ', getDateTimeWhereClause(vDateTime, o))));
+        SET sTextData = CONCAT(
+        'SELECT DISTINCT domain_id, entity_id, property_id FROM `text_data` AS subdata ',
+            'WHERE subdata.value IS NOT NULL UNION ALL ',
+        'SELECT DISTINCT domain_id, entity_id, property_id FROM `name_data` AS subdata ',
+            'WHERE subdata.value IS NOT NULL UNION ALL ',
+        'SELECT DISTINCT domain_id, entity_id, property_id FROM `enum_data` AS subdata ',
+            'WHERE subdata.value IS NOT NULL UNION ALL ',
+        'SELECT DISTINCT domain_id, entity_id, property_id FROM `integer_data` AS subdata ',
+            'WHERE subdata.value IS NOT NULL UNION ALL ',
+        'SELECT DISTINCT domain_id, entity_id, property_id FROM `double_data` AS subdata ',
+            'WHERE subdata.value IS NOT NULL UNION ALL ',
+        'SELECT DISTINCT domain_id, entity_id, property_id FROM `date_data` AS subdata ',
+            'WHERE subdata.value IS NOT NULL UNION ALL ',
+        'SELECT DISTINCT domain_id, entity_id, property_id FROM `datetime_data` AS subdata ',
+            'WHERE subdata.value IS NOT NULL UNION ALL ',
+        'SELECT DISTINCT domain_id, entity_id, property_id FROM `reference_data` AS subdata ',
+            'WHERE subdata.value IS NOT NULL');
+
+    ELSEIF o = "(" or o = "!(" THEN  -- datetime intervals
+        IF versioned THEN
+            SET sTextData = IF(vText IS NULL,
+            CONCAT(
+                ' SELECT DISTINCT domain_id, entity_id, _get_head_iversion(entity_id) ',
+                'AS _iversion, property_id FROM `date_data` UNION ALL ',
+                'SELECT DISTINCT domain_id, entity_id, _iversion, property_id FROM `archive_date_data`'),
+            IF(vDateTimeDotNotation IS NULL, NULL,  -- vText and vDateTimeDotNotation are both given
+                CONCAT(' SELECT DISTINCT domain_id, entity_id, _get_head_iversion(entity_id) ',
+                       'AS _iversion, property_id FROM `date_data` AS subdata WHERE ',
+                       getDateWhereClause(vDateTimeDotNotation, o), ' UNION ALL ',
+                       'SELECT DISTINCT domain_id, entity_id, _iversion, property_id FROM `archive_date_data` ',
+                       'AS subdata WHERE ', getDateWhereClause(vDateTimeDotNotation, o))));
+            SET sDatetimeData = IF(vText IS NULL, ' UNION ALL SELECT DISTINCT domain_id, entity_id, _get_head_iversion(entity_id) AS _iversion, property_id FROM `datetime_data` UNION ALL SELECT DISTINCT domain_id, entity_id, _iversion, property_id FROM `archive_datetime_data`',
+                                                  IF(vDateTime IS NULL, NULL,
+                                                                        CONCAT(' UNION ALL SELECT DISTINCT domain_id, entity_id, _get_head_iversion(entity_id) AS _iversion, property_id FROM `datetime_data` AS subdata WHERE ', getDateTimeWhereClause(vDateTime, o), ' UNION ALL SELECT DISTINCT domain_id, entity_id,_iversion, property_id FROM `archive_datetime_data` AS subdata WHERE ', getDateTimeWhereClause(vDateTime, o))));
+        ELSE  -- unversioned
+            SET sTextData = IF(vText IS NULL,
+                ' SELECT DISTINCT domain_id, entity_id, property_id FROM `date_data`',
+                IF(vDateTimeDotNotation IS NULL, NULL,
+                    CONCAT(' SELECT DISTINCT domain_id, entity_id, property_id FROM `date_data` AS subdata WHERE ',
+                             getDateWhereClause(vDateTimeDotNotation, o))));
+            SET sDatetimeData = IF(vText IS NULL,
+                ' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `datetime_data`',
+                IF(vDateTime IS NULL, NULL,
+                   CONCAT(' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `datetime_data` ',
+                           'AS subdata WHERE ', getDateTimeWhereClause(vDateTime, o))));
+        END IF;
         SET vText = NULL;
     ELSEIF agg IS NOT NULL THEN
+        IF versioned THEN
+            SELECT 1 FROM versioned_agg_pov_filter_not_implemented;
+        END IF;
         #-- find aggregated value (min/max...)
 
         #-- construct where clause
@@ -116,7 +170,7 @@ POV_LABEL: BEGIN
         SET aggValueWhereClause = CONCAT(IF(aggValueWhereClause IS NULL, '', aggValueWhereClause), getAggValueWhereClause(sourceSet, propertiesTable));
 
         #-- construct statement
-        SET @aggValueStmtStr = CONCAT('SELECT ',agg,'(subdata.value), ', agg, '(convert_unit(subdata.unit_sig,subdata.value)), COUNT(DISTINCT standard_unit(subdata.unit_sig)), max(standard_unit(subdata.unit_sig)) INTO @sAggValue, @sAggValueConvert, @distinctUnits, @StdUnitSig FROM (SELECT entity_id, property_id, value, unit_sig FROM `integer_data` UNION SELECT entity_id, property_id, value, unit_sig FROM `double_data`) AS subdata WHERE ', aggValueWhereClause);
+        SET @aggValueStmtStr = CONCAT('SELECT ',agg,'(subdata.value), ', agg, '(convert_unit(subdata.unit_sig,subdata.value)), COUNT(DISTINCT standard_unit(subdata.unit_sig)), max(standard_unit(subdata.unit_sig)) INTO @sAggValue, @sAggValueConvert, @distinctUnits, @StdUnitSig FROM (SELECT entity_id, property_id, value, unit_sig FROM `integer_data` UNION ALL SELECT entity_id, property_id, value, unit_sig FROM `double_data`) AS subdata WHERE ', aggValueWhereClause);
 
         #-- run statement
         PREPARE stmtAggValueStmt FROM @aggValueStmtStr;
@@ -145,15 +199,34 @@ POV_LABEL: BEGIN
         SET vText = NULL;
     ELSE
         #-- generate statement parts
-        SET sTextData = IF(vText IS NULL, 'SELECT DISTINCT domain_id, entity_id, property_id FROM `text_data`', CONCAT('SELECT DISTINCT domain_id, entity_id, property_id FROM `text_data` AS subdata WHERE subdata.value ',o,' ?'));
-        SET sNameData = IF(vText IS NULL, ' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `name_data`', CONCAT(' UNION SELECT DISTINCT domain_id, entity_id, property_id FROM `name_data` AS subdata WHERE subdata.value ', o, ' ?'));
-        SET sEnumData = IF(vText IS NULL, ' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `enum_data`', CONCAT(' UNION SELECT DISTINCT domain_id, entity_id, property_id FROM `enum_data` AS subdata WHERE subdata.value ', o, ' ?'));
-        SET sIntData = IF(vText IS NULL, ' UNION ALL SELECT DISTINCT subdata.domain_id, subdata.entity_id, subdata.property_id FROM `integer_data` AS subdata', IF(vInt IS NULL AND vDoubleStdUnit IS NULL, NULL, CONCAT(' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `integer_data` AS subdata WHERE ', getDoubleWhereClause(vInt, unit_sig, vDoubleStdUnit, stdUnit_sig, o))));
-        SET sDoubleData = IF(vText IS NULL, ' UNION ALL SELECT DISTINCT subdata.domain_id, subdata.entity_id, subdata.property_id FROM `double_data` AS subdata', IF(vDouble IS NULL, NULL, CONCAT(' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `double_data` AS subdata WHERE ', getDoubleWhereClause(vDouble,unit_sig,vDoubleStdUnit,stdUnit_sig,o))));
-        SET sDatetimeData = IF(vText IS NULL,' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `datetime_data`', IF(vDateTime IS NULL, NULL, CONCAT(' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `datetime_data` AS subdata WHERE ',getDateTimeWhereClause(vDateTime,o))));
-        SET sDateData = IF(vText IS NULL,' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `date_data`', IF(vDateTimeDotNotation IS NULL, NULL, CONCAT(' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `date_data` AS subdata WHERE ',getDateWhereClause(vDateTimeDotNotation,o))));
-        SET sRefData = IF(vText IS NULL, ' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `reference_data`', IF(refIdsTable IS NULL, NULL, CONCAT(' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `reference_data` AS subdata WHERE EXISTS (SELECT 1 FROM `', refIdsTable, '` AS refIdsTable WHERE subdata.value=refIdsTable.id LIMIT 1)')));
-        SET sNullData = IF(vText IS NULL, ' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `null_data`', NULL);
+        IF versioned THEN
+            SET sTextData = IF(vText IS NULL,
+            'SELECT DISTINCT domain_id, entity_id, _get_head_iversion(entity_id) AS _iversion, property_id FROM `text_data` UNION ALL SELECT DISTINCT domain_id, entity_id, _iversion, property_id FROM `archive_text_data` ',
+            CONCAT(
+            'SELECT DISTINCT domain_id, entity_id, _get_head_iversion(entity_id) AS _iversion, property_id ',
+              'FROM `text_data` AS subdata WHERE subdata.value ', o,' ? ',
+            'UNION ALL SELECT DISTINCT domain_id, entity_id, _iversion, property_id ',
+              'FROM `archive_text_data` AS subdata WHERE subdata.value ', o, '?'
+            ));
+            SET sNameData = IF(vText IS NULL, ' UNION ALL SELECT DISTINCT domain_id, entity_id, _get_head_iversion(entity_id) AS _iversion, property_id FROM `name_data` UNION ALL SELECT DISTINCT domain_id, entity_id, _iversion, property_id FROM `archive_name_data` ', CONCAT(' UNION ALL SELECT DISTINCT domain_id, entity_id, _get_head_iversion(entity_id) AS _iversion, property_id FROM `name_data` AS subdata WHERE subdata.value ', o, ' ? UNION ALL SELECT DISTINCT domain_id, entity_id, _iversion, property_id FROM `archive_name_data` AS subdata WHERE subdata.value ', o, '?'));
+            SET sEnumData = IF(vText IS NULL, ' UNION ALL SELECT DISTINCT domain_id, entity_id, _get_head_iversion(entity_id) AS _iversion, property_id FROM `enum_data` UNION ALL SELECT DISTINCT domain_id, entity_id, _iversion, property_id FROM `archive_enum_data` ', CONCAT(' UNION ALL SELECT DISTINCT domain_id, entity_id, _get_head_iversion(entity_id) AS _iversion, property_id FROM `enum_data` AS subdata WHERE subdata.value ', o, ' ? UNION ALL SELECT DISTINCT domain_id, entity_id, _iversion, property_id FROM `archive_enum_data` AS subdata WHERE subdata.value ', o, '?'));
+            SET sRefData = IF(vText IS NULL, ' UNION ALL SELECT DISTINCT domain_id, entity_id, _get_head_iversion(entity_id) AS _iversion, property_id FROM `reference_data` UNION ALL SELECT DISTINCT domain_id, entity_id, _iversion, property_id FROM `archive_reference_data`', IF(refIdsTable IS NULL, NULL, CONCAT(' UNION ALL SELECT DISTINCT domain_id, entity_id, _get_head_iversion(entity_id) AS _iversion, property_id FROM `reference_data` AS subdata WHERE EXISTS (SELECT 1 FROM `', refIdsTable, '` AS refIdsTable WHERE subdata.value=refIdsTable.id LIMIT 1) UNION ALL SELECT DISTINCT domain_id, entity_id, _iversion, property_id FROM `archive_reference_data` AS subdata WHERE EXISTS (SELECT 1 FROM `', refIdsTable, '` AS refIdsTable WHERE subdata.value=refIdsTable.id LIMIT 1)')));
+            SET sDoubleData = IF(vText IS NULL, ' UNION ALL SELECT DISTINCT subdata.domain_id, subdata.entity_id, _get_head_iversion(subdata.entity_id) AS _iversion, subdata.property_id FROM `double_data` AS subdata UNION ALL SELECT DISTINCT domain_id, entity_id, _iversion, property_id FROM `archive_double_data` ', IF(vDouble IS NULL, NULL, CONCAT(' UNION ALL SELECT DISTINCT domain_id, entity_id, _get_head_iversion(entity_id), property_id FROM `double_data` AS subdata WHERE ', getDoubleWhereClause(vDouble,unit_sig,vDoubleStdUnit,stdUnit_sig,o), ' UNION ALL SELECT DISTINCT domain_id, entity_id, _iversion, property_id FROM `archive_double_data` AS subdata WHERE ', getDoubleWhereClause(vDouble, unit_sig, vDoubleStdUnit, stdUnit_sig, o))));
+            SET sIntData = IF(vText IS NULL, ' UNION ALL SELECT DISTINCT subdata.domain_id, subdata.entity_id, _get_head_iversion(subdata.entity_id) AS _iversion, subdata.property_id FROM `integer_data` AS subdata UNION ALL SELECT DISTINCT domain_id, entity_id, _iversion, property_id FROM `archive_integer_data`', IF(vInt IS NULL AND vDoubleStdUnit IS NULL, NULL, CONCAT(' UNION ALL SELECT DISTINCT domain_id, entity_id, _get_head_iversion(entity_id) AS _iversion, property_id FROM `integer_data` AS subdata WHERE ', getDoubleWhereClause(vInt, unit_sig, vDoubleStdUnit, stdUnit_sig, o), ' UNION ALL SELECT DISTINCT domain_id, entity_id, _iversion, property_id FROM `archive_integer_data` AS subdata WHERE ', getDoubleWhereClause(vInt, unit_sig, vDoubleStdUnit, stdUnit_sig, o))));
+            SET sDatetimeData = IF(vText IS NULL,' UNION ALL SELECT DISTINCT domain_id, entity_id, _get_head_iversion(entity_id) AS _iversion, property_id FROM `datetime_data` UNION ALL SELECT DISTINCT domain_id, entity_id, _iversion, property_id FROM `archive_datetime_data`', IF(vDateTime IS NULL, NULL, CONCAT(' UNION ALL SELECT DISTINCT domain_id, entity_id, _get_head_iversion(entity_id) AS _iversion, property_id FROM `datetime_data` AS subdata WHERE ',getDateTimeWhereClause(vDateTime,o), ' UNION ALL SELECT DISTINCT domain_id, entity_id, _iversion, property_id FROM `archive_datetime_data` AS subdata WHERE ',getDateTimeWhereClause(vDateTime,o))));
+            SET sDateData = IF(vText IS NULL,' UNION ALL SELECT DISTINCT domain_id, entity_id, _get_head_iversion(entity_id) AS _iversion, property_id FROM `date_data` UNION ALL SELECT DISTINCT domain_id, entity_id, _iversion, property_id FROM `archive_date_data`', IF(vDateTimeDotNotation IS NULL, NULL, CONCAT(' UNION ALL SELECT DISTINCT domain_id, entity_id, _get_head_iversion(entity_id) AS _iversion, property_id FROM `date_data` AS subdata WHERE ', getDateWhereClause(vDateTimeDotNotation,o), ' UNION ALL SELECT DISTINCT domain_id, entity_id, _iversion, property_id FROM `archive_date_data` AS subdata WHERE ', getDateWhereClause(vDateTimeDotNotation,o))));
+            SET sNullData = IF(vText IS NULL, ' UNION ALL SELECT DISTINCT domain_id, entity_id, _get_head_iversion(entity_id) AS _iversion, property_id FROM `null_data` UNION ALL SELECT DISTINCT domain_id, entity_id, _iversion, property_id FROM `archive_null_data`', NULL);
+        ELSE
+            SET sTextData = IF(vText IS NULL, 'SELECT DISTINCT domain_id, entity_id, property_id FROM `text_data`', CONCAT('SELECT DISTINCT domain_id, entity_id, property_id FROM `text_data` AS subdata WHERE subdata.value ',o,' ?'));
+            SET sNameData = IF(vText IS NULL, ' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `name_data`', CONCAT(' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `name_data` AS subdata WHERE subdata.value ', o, ' ?'));
+            SET sEnumData = IF(vText IS NULL, ' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `enum_data`', CONCAT(' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `enum_data` AS subdata WHERE subdata.value ', o, ' ?'));
+            SET sRefData = IF(vText IS NULL, ' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `reference_data`', IF(refIdsTable IS NULL, NULL, CONCAT(' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `reference_data` AS subdata WHERE EXISTS (SELECT 1 FROM `', refIdsTable, '` AS refIdsTable WHERE subdata.value=refIdsTable.id LIMIT 1)')));
+            SET sDoubleData = IF(vText IS NULL, ' UNION ALL SELECT DISTINCT subdata.domain_id, subdata.entity_id, subdata.property_id FROM `double_data` AS subdata', IF(vDouble IS NULL, NULL, CONCAT(' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `double_data` AS subdata WHERE ', getDoubleWhereClause(vDouble,unit_sig,vDoubleStdUnit,stdUnit_sig,o))));
+            SET sIntData = IF(vText IS NULL, ' UNION ALL SELECT DISTINCT subdata.domain_id, subdata.entity_id, subdata.property_id FROM `integer_data` AS subdata', IF(vInt IS NULL AND vDoubleStdUnit IS NULL, NULL, CONCAT(' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `integer_data` AS subdata WHERE ', getDoubleWhereClause(vInt, unit_sig, vDoubleStdUnit, stdUnit_sig, o))));
+            SET sDatetimeData = IF(vText IS NULL,' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `datetime_data`', IF(vDateTime IS NULL, NULL, CONCAT(' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `datetime_data` AS subdata WHERE ',getDateTimeWhereClause(vDateTime,o))));
+            SET sDateData = IF(vText IS NULL,' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `date_data`', IF(vDateTimeDotNotation IS NULL, NULL, CONCAT(' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `date_data` AS subdata WHERE ',getDateWhereClause(vDateTimeDotNotation,o))));
+            SET sNullData = IF(vText IS NULL, ' UNION ALL SELECT DISTINCT domain_id, entity_id, property_id FROM `null_data`', NULL);
+        END IF;
 
     END IF;
 
@@ -170,34 +243,80 @@ POV_LABEL: BEGIN
             );
 
 
-    call createTmpTable(keepTabl);
-
-    #-- generate statement from statement parts
-    SET @stmtPOVkeepTblStr = CONCAT("INSERT IGNORE INTO `", keepTabl, "` (id) SELECT DISTINCT entity_id AS id FROM ", data, " as data", IF(propertiesTable IS NULL, '', CONCAT(' WHERE EXISTS (Select 1 from `', propertiesTable, '` AS prop WHERE prop.id = data.property_id AND (prop.id2=data.entity_id OR prop.id2=0))')));
+    call createTmpTable(keepTabl, versioned);
+    IF versioned THEN
+        #-- generate statement from statement parts
+        SET @stmtPOVkeepTblStr = CONCAT(
+            'INSERT IGNORE INTO `', keepTabl, '` (id, _iversion) SELECT entity_id AS id, _iversion FROM ', data,
+            ' as data', IF(propertiesTable IS NULL, '', CONCAT(
+                ' WHERE EXISTS (Select 1 from `', propertiesTable, '` AS prop ',
+                  'WHERE prop.id = data.property_id AND (prop.id2=data.entity_id OR prop.id2=0))')));
 
-    SET @stmtPOVStr = CONCAT(
-            IF(targetSet IS NULL,
-                CONCAT('DELETE FROM `',sourceSet,'` WHERE NOT EXISTS (SELECT 1 FROM `'),
-                CONCAT('INSERT IGNORE INTO `',targetSet,'` (id) SELECT id FROM `',sourceSet,'` WHERE EXISTS (SELECT 1 FROM `')),
-            keepTabl,
-            '` AS data WHERE data.id=`', sourceSet, '`.`id` LIMIT 1)'
-        );
+        IF targetSet IS NOT NULL THEN
+            SET @stmtPOVStr = CONCAT('INSERT IGNORE INTO `',
+                    targetSet,
+                    '` (id, _iversion) SELECT source.id, source._iversion FROM `',
+                    keepTabl,
+                    '` AS source');
+        ELSE
+        -- unversioned shall not return any versions other than HEAD
+            SET @stmtPOVStr = CONCAT('DELETE FROM `',
+                    sourceSet,
+                    '` WHERE NOT EXISTS (SELECT 1 FROM `',
+                    keepTabl,
+                    '` AS data WHERE data.id=`',
+                    sourceSet,
+                    '`.`id` AND data._iversion=`',
+                    sourceSet,
+                    '`._iversion LIMIT 1)');
 
+        END IF;
 
-    #-- prepare and execute
-    PREPARE stmt3 FROM @stmtPOVStr;
-    PREPARE stmtPOVkeepTbl FROM @stmtPOVkeepTblStr;
-    IF vText IS NULL THEN
-        EXECUTE stmtPOVkeepTbl;
+        #-- prepare and execute
+        PREPARE stmt3 FROM @stmtPOVStr;
+        PREPARE stmtPOVkeepTbl FROM @stmtPOVkeepTblStr;
+        IF vText IS NULL THEN
+            EXECUTE stmtPOVkeepTbl;
+        ELSE
+            SET @vText = vText;
+            EXECUTE stmtPOVkeepTbl USING @vText, @vText, @vText, @vText, @vText, @vText;
+        END IF;
+        EXECUTE stmt3;
+        DEALLOCATE PREPARE stmt3;
+        DEALLOCATE PREPARE stmtPOVkeepTbl;
     ELSE
-        SET @vText = vText;
-        EXECUTE stmtPOVkeepTbl USING @vText, @vText, @vText;
-    END IF;
-    EXECUTE stmt3;
-    DEALLOCATE PREPARE stmt3;
-    DEALLOCATE PREPARE stmtPOVkeepTbl;
+        #-- generate statement from statement parts
+        SET @stmtPOVkeepTblStr = CONCAT('INSERT IGNORE INTO `', keepTabl, '` (id) SELECT DISTINCT entity_id AS id FROM ', data, ' as data', IF(propertiesTable IS NULL, '', CONCAT(' WHERE EXISTS (Select 1 from `', propertiesTable, '` AS prop WHERE prop.id = data.property_id AND (prop.id2=data.entity_id OR prop.id2=0))')));
 
-    /* Question: why select AS and not select INTO? */
+        SET @stmtPOVStr = CONCAT(
+                IF(targetSet IS NULL,
+                    CONCAT('DELETE FROM `',
+                        sourceSet,
+                        '` WHERE NOT EXISTS (SELECT 1 FROM `'),
+                    CONCAT('INSERT IGNORE INTO `',
+                        targetSet,
+                        '` (id) SELECT id FROM `',
+                        sourceSet,
+                        '` WHERE EXISTS (SELECT 1 FROM `')),
+                keepTabl,
+                '` AS data WHERE data.id=`',
+                sourceSet,
+                '`.`id` LIMIT 1)'
+            );
+
+        #-- prepare and execute
+        PREPARE stmt3 FROM @stmtPOVStr;
+        PREPARE stmtPOVkeepTbl FROM @stmtPOVkeepTblStr;
+        IF vText IS NULL THEN
+            EXECUTE stmtPOVkeepTbl;
+        ELSE
+            SET @vText = vText;
+            EXECUTE stmtPOVkeepTbl USING @vText, @vText, @vText;
+        END IF;
+        EXECUTE stmt3;
+        DEALLOCATE PREPARE stmt3;
+        DEALLOCATE PREPARE stmtPOVkeepTbl;
+    END IF;
 
     SELECT @stmtPOVkeepTblStr as applyPOVStmt1, @stmtPOVStr as applyPOVStmt2, keepTabl as applyPOVIntermediateResultSet;
 
diff --git a/procedures/query/applyRefPOV.sql b/procedures/query/applyRefPOV.sql
index 0771d3d02051ac1388cf0792bdc680b9b9f9f1bd..a367408c37da4f839c432e366e8564255cd9b628 100644
--- a/procedures/query/applyRefPOV.sql
+++ b/procedures/query/applyRefPOV.sql
@@ -23,14 +23,28 @@
 DROP PROCEDURE IF EXISTS db_2_0.applyRefPOV;
 DELIMITER //
 
-CREATE PROCEDURE db_2_0.applyRefPOV(in sourceSet VARCHAR(255), in targetSet VARCHAR(255), in properties VARCHAR(255), in refs VARCHAR(255))
+CREATE PROCEDURE db_2_0.applyRefPOV(in sourceSet VARCHAR(255), in targetSet VARCHAR(255),
+                                    in properties VARCHAR(255), in refs VARCHAR(255),
+                                    in versioned BOOLEAN)
 BEGIN
-    DECLARE data VARCHAR(20000) DEFAULT CONCAT('(SELECT domain_id, entity_id, property_id FROM `reference_data` AS subdata WHERE EXISTS (SELECT 1 FROM `', refs, '` AS refs WHERE subdata.value=refs.id LIMIT 1))');
-    SET @stmtRefPOVStr = makeStmt(sourceSet,targetSet,data,properties);
+    DECLARE data VARCHAR(20000) DEFAULT CONCAT(
+        '(SELECT domain_id, entity_id, property_id FROM `reference_data` AS subdata ',
+        'WHERE EXISTS (SELECT 1 FROM `', refs, '` AS refs WHERE subdata.value=refs.id LIMIT 1))');
+
+    IF versioned THEN
+        SET data = CONCAT(
+            '(SELECT domain_id, entity_id, _get_head_iversion(entity_id) AS _iversion, property_id ',
+                'FROM `reference_data` AS subdata WHERE EXISTS (',
+                    'SELECT 1 FROM `', refs, '` AS refs WHERE subdata.value=refs.id LIMIT 1) ',
+            'UNION ALL SELECT domain_id, entity_id, _iversion, property_id ',
+                'FROM `archive_reference_data` AS subdata WHERE EXISTS (',
+                    'SELECT 1 FROM `', refs, '` AS refs WHERE subdata.value=refs.id LIMIT 1))');
+    END IF;
+    SET @stmtRefPOVStr = makeStmt(sourceSet,targetSet,data,properties, versioned);
 
     PREPARE stmt4 FROM @stmtRefPOVStr;
     EXECUTE stmt4;
-		
+
     SELECT @stmtRefPOVstr as applyRefPOVStmt;
 
 END;
diff --git a/procedures/query/applyTransactionFilter.sql b/procedures/query/applyTransactionFilter.sql
index b40b287b25bdd703337d50f3ca19d25d71bfcada..49a4edb931136b1e24afdf38acfdf90445159df1 100644
--- a/procedures/query/applyTransactionFilter.sql
+++ b/procedures/query/applyTransactionFilter.sql
@@ -39,7 +39,7 @@ BEGIN
 		')'
 	);
 
-	SET @stmtTransactionStr = makeStmt(sourceSet,targetSet,data,NULL);
+	SET @stmtTransactionStr = makeStmt(sourceSet, targetSet, data, NULL, FALSE);
 	PREPARE stmtTransactionFilter from @stmtTransactionStr;
 	IF userName IS NOT NULL THEN
 		SET @userName = userName;
diff --git a/procedures/query/calcComplementUnion.sql b/procedures/query/calcComplementUnion.sql
index b0e70f744087672519957d0b9b6713d8ef3574a3..daaafa1934e58d53dbcc5cd17551c9353efa4571 100644
--- a/procedures/query/calcComplementUnion.sql
+++ b/procedures/query/calcComplementUnion.sql
@@ -23,15 +23,33 @@
 
 
 DROP PROCEDURE IF EXISTS db_2_0.calcComplementUnion;
+-- Apparently this code is not used anymore
 DELIMITER //
 
-CREATE PROCEDURE db_2_0.calcComplementUnion(in targetSet VARCHAR(255), in subResultSet VARCHAR(255), in universe VARCHAR(255))
+CREATE PROCEDURE db_2_0.calcComplementUnion(in targetSet VARCHAR(255), in subResultSet VARCHAR(255), in universe VARCHAR(255), in versioned BOOLEAN)
 BEGIN
-    SET @stmtComplementUnionStr = CONCAT('INSERT IGNORE INTO `', targetSet, '` SELECT id FROM `',universe, '` AS universe WHERE NOT EXISTS ( SELECT 1 FROM `', subResultSet,'` AS diff WHERE diff.id=universe.id)');
+    IF versioned AND universe = "entities" THEN
+        SET @stmtComplementUnionStr = CONCAT(
+            'INSERT IGNORE INTO `', targetSet,
+            '` SELECT e.id, _get_head_iversion(e.id) FROM entities as e WHERE NOT EXISTS ( SELECT 1 FROM `',
+            subResultSet,
+            '` AS diff WHERE diff.id=e.id AND diff._iversion = _get_head_iversion(e.id)) UNION ALL SELECT e.id, e._iversion FROM archive_entities AS e WHERE NOT EXISTS ( SELECT 1 FROM `',
+            subResultSet,
+            '` as diff WHERE e.id = diff.id AND e._iversion = diff._iversion)');
+    ELSEIF versioned THEN
+        SET @stmtComplementUnionStr = CONCAT(
+            'INSERT IGNORE INTO `', targetSet,
+            '` SELECT id FROM `',universe,
+            '` AS universe WHERE NOT EXISTS ( SELECT 1 FROM `',
+                subResultSet,'`
+                AS diff WHERE diff.id=universe.id AND diff._iversion = universe.id_version)');
+    ELSE
+        SET @stmtComplementUnionStr = CONCAT('INSERT IGNORE INTO `', targetSet, '` SELECT id FROM `',universe, '` AS universe WHERE NOT EXISTS ( SELECT 1 FROM `', subResultSet,'` AS diff WHERE diff.id=universe.id)');
+    END IF;
     PREPARE stmtComplementUnion FROM @stmtComplementUnionStr;
     EXECUTE stmtComplementUnion;
     DEALLOCATE PREPARE stmtComplementUnion;
-    
+
 END;
 //
 
diff --git a/procedures/query/calcDifference.sql b/procedures/query/calcDifference.sql
index 279b8cbac73c43893086187a38ec693978e16791..c9788df0c4ea30e041441407c6f474a60cf01cfa 100644
--- a/procedures/query/calcDifference.sql
+++ b/procedures/query/calcDifference.sql
@@ -27,13 +27,20 @@
 DROP PROCEDURE IF EXISTS db_2_0.calcDifference;
 DELIMITER //
 
-CREATE PROCEDURE db_2_0.calcDifference(in resultSetTable VARCHAR(255), in diff VARCHAR(255))
+/**
+ * Delete rows from `resultSetTable` which have a matching ID (an version) in `diff`.
+ */
+CREATE PROCEDURE db_2_0.calcDifference(in resultSetTable VARCHAR(255), in diff VARCHAR(255), in versioned BOOLEAN)
 BEGIN
-    SET @diffStmtStr = CONCAT('DELETE FROM `', resultSetTable, '` WHERE EXISTS ( SELECT 1 FROM `', diff,'` AS diff WHERE diff.id=`',resultSetTable,'`.`id`)');
+    IF versioned THEN
+        SET @diffStmtStr = CONCAT('DELETE FROM `', resultSetTable, '` WHERE EXISTS ( SELECT 1 FROM `', diff,'` AS diff WHERE diff.id=`',resultSetTable,'`.`id` AND diff._iversion=`', resultSetTable, '`.`_iversion`)');
+    ELSE
+        SET @diffStmtStr = CONCAT('DELETE FROM `', resultSetTable, '` WHERE EXISTS ( SELECT 1 FROM `', diff,'` AS diff WHERE diff.id=`',resultSetTable,'`.`id`)');
+    END IF;
     PREPARE diffStmt FROM @diffStmtStr;
     EXECUTE diffStmt;
     DEALLOCATE PREPARE diffStmt;
-    
+
 END;
 //
 
diff --git a/procedures/query/calcIntersection.sql b/procedures/query/calcIntersection.sql
index e9f8616a6dc00dbd465151e2d637f1f74fb8d2a2..4cc90095bed2ea1bf9f2fa2f3190c8b62a974b38 100644
--- a/procedures/query/calcIntersection.sql
+++ b/procedures/query/calcIntersection.sql
@@ -25,9 +25,24 @@
 DROP PROCEDURE IF EXISTS db_2_0.calcIntersection;
 DELIMITER //
 
-CREATE PROCEDURE db_2_0.calcIntersection(in resultSetTable VARCHAR(255), in intersectWith VARCHAR(255))
+/**
+ * Drop rows in `resultSetTable` which do not have a matching ID (and version) in `intersectWith`.
+ */
+CREATE PROCEDURE db_2_0.calcIntersection(in resultSetTable VARCHAR(255), in intersectWith VARCHAR(255), in versioned BOOLEAN)
 BEGIN
-    SET @diffStmtStr = CONCAT('DELETE FROM `', resultSetTable, '` WHERE NOT EXISTS ( SELECT 1 FROM `', intersectWith,'` AS diff WHERE diff.id=`',resultSetTable,'`.`id`)');
+    IF versioned THEN
+        SET @diffStmtStr = CONCAT('DELETE FROM `',
+            resultSetTable,
+            '` WHERE NOT EXISTS ( SELECT 1 FROM `',
+            intersectWith,
+            '` AS diff WHERE diff.id=`',
+            resultSetTable,
+            '`.`id` AND diff._iversion=`',
+            resultSetTable,
+            '`.`_iversion`)');
+    ELSE
+        SET @diffStmtStr = CONCAT('DELETE FROM `', resultSetTable, '` WHERE NOT EXISTS ( SELECT 1 FROM `', intersectWith,'` AS diff WHERE diff.id=`',resultSetTable,'`.`id`)');
+    END IF;
     PREPARE diffStmt FROM @diffStmtStr;
     EXECUTE diffStmt;
 
diff --git a/procedures/query/calcUnion.sql b/procedures/query/calcUnion.sql
index 7db35bb774659ae4d27ead20b92029991ef1fed3..006fb11aaa4695630db5d796d7048f7c9ca7ee5e 100644
--- a/procedures/query/calcUnion.sql
+++ b/procedures/query/calcUnion.sql
@@ -26,13 +26,16 @@
 DROP PROCEDURE IF EXISTS db_2_0.calcUnion;
 DELIMITER //
 
+/**
+ * Add the rows from `sourceSet` to `targetSet`.
+ */
 CREATE PROCEDURE db_2_0.calcUnion(in targetSet VARCHAR(255), in sourceSet VARCHAR(255))
 BEGIN
-    SET @diffStmtStr = CONCAT('INSERT IGNORE INTO `', targetSet, '` (id) SELECT id FROM `',sourceSet,'`');
+    SET @diffStmtStr = CONCAT('INSERT IGNORE INTO `', targetSet, '` SELECT * FROM `',sourceSet,'`');
     PREPARE diffStmt FROM @diffStmtStr;
     EXECUTE diffStmt;
     DEALLOCATE PREPARE diffStmt;
-    
+
 END;
 //
 
diff --git a/procedures/query/cleanUpQuery.sql b/procedures/query/cleanUpQuery.sql
index 7de562e8c1c210d91a6613319cb8254d780e4c83..7cf78a5951f306f373896cc3d854deeee16c206c 100644
--- a/procedures/query/cleanUpQuery.sql
+++ b/procedures/query/cleanUpQuery.sql
@@ -27,15 +27,20 @@
 DROP PROCEDURE IF EXISTS db_2_0.cleanUpQuery;
 DELIMITER //
 
+/**
+ * Drop temporary tables and warnings, existing warnings are returned in the result set.
+ */
 CREATE PROCEDURE db_2_0.cleanUpQuery()
 BEGIN
-   SELECT * from warnings;
+    CREATE TEMPORARY TABLE IF NOT EXISTS warnings (warning TEXT NOT NULL);
+    SELECT * from warnings;
 
-   SET @pstmtstr = CONCAT('DROP TEMPORARY TABLE IF EXISTS `warnings`', IF(@tempTableList IS NULL, '', CONCAT(',',@tempTableList)));
-   PREPARE pstmt FROM @pstmtstr;
-   EXECUTE pstmt;
+    SET @pstmtstr = CONCAT('DROP TEMPORARY TABLE IF EXISTS `warnings`',
+        IF(@tempTableList IS NULL, '', CONCAT(',',@tempTableList)));
+    PREPARE pstmt FROM @pstmtstr;
+    EXECUTE pstmt;
 
-   SET @tempTableList = NULL;
+    SET @tempTableList = NULL;
 END;
 //
 DELIMITER ;
diff --git a/procedures/query/createTmpTable.sql b/procedures/query/createTmpTable.sql
index 180f9bab2bc27b2ada5324598dc136034ba485ab..2c342964e68fc6522962da5c046f25350c5f26b5 100644
--- a/procedures/query/createTmpTable.sql
+++ b/procedures/query/createTmpTable.sql
@@ -27,7 +27,10 @@ DELIMITER //
 CREATE PROCEDURE db_2_0.registerTempTableName(out newTableName VARCHAR(255))
 BEGIN
     SET newTableName = md5(CONCAT(RAND(),CURRENT_TIMESTAMP()));
-    SET @tempTableList = IF(@tempTableList IS NULL, CONCAT('`',newTableName,'`'), CONCAT(@tempTableList, ',`', newTableName, '`'));
+    SET @tempTableList = IF(@tempTableList IS NULL,
+        CONCAT('`',newTableName,'`'),
+        CONCAT(@tempTableList, ',`', newTableName, '`')
+    );
 END;
 //
 DELIMITER ;
@@ -35,12 +38,23 @@ DELIMITER ;
 DROP PROCEDURE IF EXISTS db_2_0.createTmpTable;
 DELIMITER //
 
-CREATE PROCEDURE db_2_0.createTmpTable(out newTableName VARCHAR(255))
+/**
+ * If not versioned: Creates a temporary table for query results with only a single `id` column.
+ *
+ * If versioned: Creates a temporary table for query results with an `id`
+ * column and an `_iversion` column.
+ */
+CREATE PROCEDURE db_2_0.createTmpTable(out newTableName VARCHAR(255), in versioned BOOLEAN)
 BEGIN
     call registerTempTableName(newTableName);
-    
-    SET @createTableStmtStr = CONCAT('CREATE TEMPORARY TABLE `', newTableName,'` ( id INT UNSIGNED PRIMARY KEY)' );
-    
+
+    IF versioned THEN
+        SET @createTableStmtStr = CONCAT('CREATE TEMPORARY TABLE `', newTableName,
+            '` ( id INT UNSIGNED, _iversion INT UNSIGNED, PRIMARY KEY (id, _iversion))' );
+    ELSE
+        SET @createTableStmtStr = CONCAT('CREATE TEMPORARY TABLE `', newTableName,'` ( id INT UNSIGNED PRIMARY KEY)' );
+    END IF;
+
     PREPARE createTableStmt FROM @createTableStmtStr; 
     EXECUTE createTableStmt;
     DEALLOCATE PREPARE createTableStmt;
@@ -51,14 +65,22 @@ DELIMITER ;
 
 
 
+/**
+ * Creates a temporary table for intermediate query results with three columns
+ *     id - for entity ids (e.g. property ids or reference values)
+ *     id2 - for entity ids (usually those entities which have the other id as property or value)
+ *     domain - for domain ids
+ */
 DROP PROCEDURE IF EXISTS db_2_0.createTmpTable2;
 DELIMITER //
 
 CREATE PROCEDURE db_2_0.createTmpTable2(out newTableName VARCHAR(255))
 BEGIN
     call registerTempTableName(newTableName);
-	SET @createTableStmtStr = CONCAT('CREATE TEMPORARY TABLE `', newTableName,'` ( id INT UNSIGNED, id2 INT UNSIGNED, domain INT UNSIGNED, CONSTRAINT `', newTableName,'PK` PRIMARY KEY (id,id2,domain) )' );
-    
+    SET @createTableStmtStr = CONCAT('CREATE TEMPORARY TABLE `', newTableName,
+        '` ( id INT UNSIGNED, id2 INT UNSIGNED, domain INT UNSIGNED, CONSTRAINT `',
+        newTableName,'PK` PRIMARY KEY (id,id2,domain) )' );
+
     PREPARE createTableStmt FROM @createTableStmtStr; 
     EXECUTE createTableStmt;
     DEALLOCATE PREPARE createTableStmt;
diff --git a/procedures/query/finishSubProperty.sql b/procedures/query/finishSubProperty.sql
index 635aba4f030eab0f7e3c6f547e4d1df0b3a15584..73a9ee62c9204ae6a2a250fec25c6100a0ed44a4 100644
--- a/procedures/query/finishSubProperty.sql
+++ b/procedures/query/finishSubProperty.sql
@@ -24,15 +24,16 @@
 DROP PROCEDURE IF EXISTS db_2_0.finishSubProperty;
 DELIMITER //
 
-CREATE PROCEDURE db_2_0.finishSubProperty(in sourceSet VARCHAR(255),in targetSet VARCHAR(255), in list VARCHAR(255))
+CREATE PROCEDURE db_2_0.finishSubProperty(in sourceSet VARCHAR(255),in targetSet VARCHAR(255),
+                                          in list VARCHAR(255), in versioned BOOLEAN)
 BEGIN
     DECLARE data VARCHAR(20000) DEFAULT CONCAT('`',list,'`');
-    SET @finishSubPropertyStmtStr = makeStmt(sourceSet, targetSet, data, NULL);
+    SET @finishSubPropertyStmtStr = makeStmt(sourceSet, targetSet, data, NULL, versioned);
 
-	PREPARE finishSubPropertyStmt FROM @finishSubPropertyStmtStr;
-	EXECUTE finishSubPropertyStmt;
+    PREPARE finishSubPropertyStmt FROM @finishSubPropertyStmtStr;
+    EXECUTE finishSubPropertyStmt;
     DEALLOCATE PREPARE finishSubPropertyStmt;
-        
+
     SELECT @finishSubPropertyStmtStr AS finishSubPropertyStmt;
 
 END;
diff --git a/procedures/query/getChildren.sql b/procedures/query/getChildren.sql
index 1a61995ebd76105bb07a93ab96247f8463de1b96..0ab6784fd9e0af95046b90aa62e13d69072a0922 100644
--- a/procedures/query/getChildren.sql
+++ b/procedures/query/getChildren.sql
@@ -23,28 +23,64 @@
 
 Drop Procedure if exists db_2_0.getChildren;
 Delimiter //
-Create Procedure db_2_0.getChildren(in tableName varchar(255))
+/**
+ * Find and return all children of the IDs given in `tableName`.
+ *
+ * If the `versioned` parameter is `TRUE`, also all archived (non-HEAD) children are added.
+ */
+Create Procedure db_2_0.getChildren(in tableName varchar(255), in versioned BOOLEAN)
 
 BEGIN
+    DECLARE found_children INT UNSIGNED DEFAULT 0;
 
-    CREATE TEMPORARY TABLE dependTemp (id INT UNSIGNED PRIMARY KEY);
-
+    DROP TEMPORARY TABLE IF EXISTS dependTemp;
+    CREATE TEMPORARY TABLE dependTemp (id INT UNSIGNED, _iversion INT UNSIGNED, PRIMARY KEY(id, _iversion));
 
 
-    SET @initDepend = CONCAT('INSERT IGNORE INTO dependTemp (id) SELECT i.child FROM isa_cache AS i INNER JOIN `', tableName, '` AS t ON (i.parent=t.id);');
+    SET @initDepend = CONCAT(
+        'INSERT IGNORE INTO dependTemp (id, _iversion) SELECT i.child, ',
+        IF(versioned,
+            '_get_head_iversion(i.child)',
+            '0'),
+        ' FROM isa_cache AS i INNER JOIN `',
+        tableName,
+        '` AS t ON (i.parent=t.id);');
     PREPARE initDependStmt FROM @initDepend;
 
-	EXECUTE initDependStmt;
-	IF ROW_COUNT() != 0 THEN
-    	SET @transfer = CONCAT('INSERT IGNORE INTO `', tableName, '` (id) SELECT id FROM dependTemp');
+    EXECUTE initDependStmt;
+    SET found_children = found_children + ROW_COUNT();
+
+    -- ################# VERSIONING #####################
+
+    IF versioned IS TRUE THEN
+        SET @initDepend = CONCAT(
+            'INSERT IGNORE INTO dependTemp (id, _iversion) ',
+            'SELECT i.child, i.child_iversion FROM archive_isa AS i INNER JOIN `',
+            tableName,
+            '` AS t ON (i.parent=t.id);');
+        PREPARE initDependStmt FROM @initDepend;
+
+        EXECUTE initDependStmt;
+        SET found_children = found_children + ROW_COUNT();
+    END IF;
+
+    -- ##################################################
+
+
+    IF found_children != 0 THEN
+        SET @transfer = CONCAT(
+            'INSERT IGNORE INTO `',
+            tableName,
+            IF(versioned,
+                '` (id, _iversion) SELECT id, _iversion FROM dependTemp',
+                '` (id) SELECT id FROM dependTemp'));
         PREPARE transferstmt FROM @transfer;
-		EXECUTE transferstmt;
-		DEALLOCATE PREPARE transferstmt;
-	END IF;
+        EXECUTE transferstmt;
+        DEALLOCATE PREPARE transferstmt;
+    END IF;
 
 
-	DEALLOCATE PREPARE initDependStmt;
-	DROP TEMPORARY TABLE dependTemp;
+    DEALLOCATE PREPARE initDependStmt;
 
 END;
 //
diff --git a/procedures/query/initBackReference.sql b/procedures/query/initBackReference.sql
index 47038ad4c13fc934e0d9820eed27028ff848e9cb..63fa9292a71688a7a53f8851bb5a375e1aa76fe0 100644
--- a/procedures/query/initBackReference.sql
+++ b/procedures/query/initBackReference.sql
@@ -25,20 +25,22 @@ DROP PROCEDURE IF EXISTS db_2_0.initBackReference;
 DELIMITER //
 CREATE PROCEDURE db_2_0.initBackReference(in pid INT UNSIGNED, in pname VARCHAR(255), in entity_id INT UNSIGNED, in ename VARCHAR(255))
 BEGIN
-	DECLARE propertiesTable VARCHAR(255) DEFAULT NULL;
-	DECLARE entitiesTable VARCHAR(255) DEFAULT NULL;
+    DECLARE propertiesTable VARCHAR(255) DEFAULT NULL;
+    DECLARE entitiesTable VARCHAR(255) DEFAULT NULL;
 
     IF pname IS NOT NULL THEN
-        call createTmpTable(propertiesTable);
+        -- TODO versioning for properties
+        call createTmpTable(propertiesTable, FALSE);
         call initSubEntity(pid, pname, propertiesTable);
     END IF;
 
     IF ename IS NOT NULL THEN
-        call createTmpTable(entitiesTable);
+        -- TODO versioning for referencing entities
+        call createTmpTable(entitiesTable, FALSE);
         call initSubEntity(entity_id, ename, entitiesTable);
     END IF;
 
-	SELECT propertiesTable, entitiesTable;
+    SELECT propertiesTable, entitiesTable;
 
 
 END //
diff --git a/procedures/query/initDisjunctionFilter.sql b/procedures/query/initDisjunctionFilter.sql
index 7a5a45bd125563b847d69ca404d0c28294c64fc6..be7a0ebad9d3f9b278a4ea7de5418ade1b627f31 100644
--- a/procedures/query/initDisjunctionFilter.sql
+++ b/procedures/query/initDisjunctionFilter.sql
@@ -26,7 +26,7 @@
 DROP PROCEDURE IF EXISTS db_2_0.initEmptyTargetSet;
 DELIMITER //
 
-CREATE PROCEDURE db_2_0.initEmptyTargetSet(in targetSet VARCHAR(255))
+CREATE PROCEDURE db_2_0.initEmptyTargetSet(in targetSet VARCHAR(255), in versioned BOOLEAN)
 BEGIN
     DECLARE newTableName VARCHAR(255) DEFAULT targetSet;
     IF targetSet IS NOT NULL THEN
@@ -36,10 +36,10 @@ BEGIN
         EXECUTE stmtIsNotEmpty;
         DEALLOCATE PREPARE stmtIsNotEmpty;
         IF @isNotEmptyVar IS NOT NULL THEN /*if targetSet is not empty*/
-            call createTmpTable(newTableName);
+            call createTmpTable(newTableName, versioned);
         END IF;
     ELSE
-        call createTmpTable(newTableName);
+        call createTmpTable(newTableName, versioned);
     END IF;
     SELECT newTableName AS newTableName;
 END;
@@ -49,49 +49,9 @@ DELIMITER ;
 DROP PROCEDURE IF EXISTS db_2_0.initDisjunctionFilter;
 DELIMITER //
 
-CREATE PROCEDURE db_2_0.initDisjunctionFilter()
+CREATE PROCEDURE db_2_0.initDisjunctionFilter(in versioned BOOLEAN)
 BEGIN
-    call initEmptyTargetSet(NULL);
+    call initEmptyTargetSet(NULL, versioned);
 END;
 //
 DELIMITER ;
-
-DROP PROCEDURE IF EXISTS db_2_0.initNegationFilter;
-DELIMITER //
-
-CREATE PROCEDURE db_2_0.initNegationFilter(in sourceSet VARCHAR(255))
-BEGIN
-    DECLARE newTableName VARCHAR(255) DEFAULT NULL;
-    call createTmpTable(newTableName);
-    call copyTable(sourceSet, newTableName);
-    SELECT newTableName AS newTableName;
-END;
-//
-DELIMITER ;
-
-DROP PROCEDURE IF EXISTS db_2_0.initConjunctionFilter;
-DELIMITER //
-
-CREATE PROCEDURE db_2_0.initConjunctionFilter(in sourceSet VARCHAR(255))
-BEGIN
-    DECLARE newTableName VARCHAR(255) DEFAULT NULL;
-    call createTmpTable(newTableName);
-    call copyTable(sourceSet, newTableName);
-    SELECT newTableName AS newTableName;
-END;
-//
-DELIMITER ;
-
-DROP PROCEDURE IF EXISTS db_2_0.finishNegationFilter;
-DELIMITER //
-
-CREATE PROCEDURE db_2_0.finishNegationFilter(in sourceSet VARCHAR(255), in targetSet VARCHAR(255), in subResultSet VARCHAR(255))
-BEGIN
-    IF targetSet IS NULL OR sourceSet = targetSet THEN
-        call calcDifference(sourceSet, subResultSet);
-    ELSE
-        call calcComplementUnion(targetSet,subResultSet,sourceSet);
-    END IF;
-END;
-// 
-DELIMITER ;
diff --git a/procedures/query/initEntity.sql b/procedures/query/initEntity.sql
index f8877303a6d47a3cbf620b45c2fd8484caa1804b..b96b30dfbc1110575bac7bf4eacf16e95fa65b83 100644
--- a/procedures/query/initEntity.sql
+++ b/procedures/query/initEntity.sql
@@ -24,29 +24,44 @@
 DROP PROCEDURE IF EXISTS db_2_0.initEntity;
 DELIMITER //
 
-CREATE PROCEDURE db_2_0.initEntity(in eid INT UNSIGNED, in ename VARCHAR(255), in enameLike VARCHAR(255), in enameRegexp VARCHAR(255), in resultset VARCHAR(255))
+/**
+ * Insert the specified (by `ename`, `enameLike`, `enameRegexp` or `eid`) Entities into `resultset`.
+ *
+ * If `versioned` is `TRUE`, also add archived entities (for example if the name was changed in the
+ * past).
+ */
+CREATE PROCEDURE db_2_0.initEntity(in eid INT UNSIGNED, in ename VARCHAR(255),
+                                   in enameLike VARCHAR(255), in enameRegexp VARCHAR(255),
+                                   in resultset VARCHAR(255), in versioned BOOLEAN)
 initEntityLabel: BEGIN
+    DECLARE select_columns VARCHAR(255) DEFAULT '` (id) SELECT entity_id FROM name_data ';
     SET @initEntityStmtStr = NULL;
 
     -- Prepare a statement which resolves the name or pattern to ids. The ids
     -- are collected in a temporary table (resultset).
+    IF versioned IS TRUE THEN
+        SET select_columns = '` (id, _iversion) SELECT entity_id, _get_head_iversion(entity_id) FROM name_data ';
+    END IF;
     IF ename IS NOT NULL THEN
         SET @initEntityStmtStr = CONCAT(
             'INSERT IGNORE INTO `',
             resultset,
-            '` (id) SELECT entity_id FROM name_data WHERE value=?; ');
+            select_columns,
+            'WHERE value=?; ');
         SET @query_param = ename;
     ELSEIF enameLike IS NOT NULL THEN
         SET @initEntityStmtStr = CONCAT(
             'INSERT IGNORE INTO `',
             resultset,
-            '` (id) SELECT entity_id FROM name_data WHERE value LIKE ?;');
+            select_columns,
+            'WHERE value LIKE ?;');
         SET @query_param = enameLike;
     ELSEIF enameRegexp IS NOT NULL THEN 
         SET @initEntityStmtStr = CONCAT(
             'INSERT IGNORE INTO `',
             resultset,
-            '` (id) SELECT entity_id FROM name_data WHERE value REGEXP ?;');
+            select_columns,
+            'WHERE value REGEXP ?;');
         SET @query_param = enameRegexp;
     END IF;
 
@@ -58,15 +73,58 @@ initEntityLabel: BEGIN
     END IF;
 
     IF eid IS NOT NULL THEN
-        SET @initEntityStmtStr = CONCAT('INSERT IGNORE INTO `',resultset,'` (id) SELECT id FROM entities WHERE id=',eid,';');
+        -- add an explicitely given id to the resultset (if it exists)
+        SET @initEntityStmtStr = CONCAT(
+            'INSERT IGNORE INTO `',
+            resultset,
+            IF(versioned,
+                '` (id, _iversion) SELECT id, _get_head_iversion(id) ',
+                '` (id) SELECT id '),
+            'FROM entities WHERE id=',eid,';');
         PREPARE initEntityStmt FROM @initEntityStmtStr;
         EXECUTE initEntityStmt;
         DEALLOCATE PREPARE initEntityStmt;
     END IF;
 
 
+    -- ################# VERSIONING #####################
+    -- Same as above, but from `archive_name_data` instead of `name_data`.
+    IF versioned IS TRUE THEN
+        SET select_columns = '` (id, _iversion) SELECT entity_id, _iversion FROM archive_name_data ';
+        IF ename IS NOT NULL THEN
+            SET @initEntityStmtStr = CONCAT(
+                'INSERT IGNORE INTO `',
+                resultset,
+                select_columns,
+                'WHERE value=?; ');
+            SET @query_param = ename;
+        ELSEIF enameLike IS NOT NULL THEN
+            SET @initEntityStmtStr = CONCAT(
+                'INSERT IGNORE INTO `',
+                resultset,
+                select_columns,
+                'WHERE value LIKE ?;');
+            SET @query_param = enameLike;
+        ELSEIF enameRegexp IS NOT NULL THEN
+            SET @initEntityStmtStr = CONCAT(
+                'INSERT IGNORE INTO `',
+                resultset,
+                'WHERE value REGEXP ?;');
+            SET @query_param = enameRegexp;
+        END IF;
+
+        -- execute the statement
+        IF @initEntityStmtStr IS NOT NULL THEN
+            PREPARE initEntityStmt FROM @initEntityStmtStr;
+            EXECUTE initEntityStmt USING @query_param;
+            DEALLOCATE PREPARE initEntityStmt;
+        END IF;
+    END IF;
+    -- ##################################################
+
+
     IF @initEntityStmtStr IS NOT NULL THEN
-        call getChildren(resultset);
+        call getChildren(resultset, versioned);
     END IF;
 
 END;
diff --git a/procedures/query/initPOV.sql b/procedures/query/initPOV.sql
index d1fa16300e4ef36902fd702739e389d336f1b3f5..0d7dea3dd4b140e519a2a0c06ca9842980044ba2 100644
--- a/procedures/query/initPOV.sql
+++ b/procedures/query/initPOV.sql
@@ -29,7 +29,7 @@ CREATE PROCEDURE db_2_0.initPOVPropertiesTable(in pid INT UNSIGNED, in pname VAR
 BEGIN
     DECLARE propertiesTable VARCHAR(255) DEFAULT NULL; /*table for property ids*/
     DECLARE replTbl VARCHAR(255) DEFAULT NULL;
-   	DECLARE ecount INT DEFAULT 0;
+    DECLARE ecount INT DEFAULT 0;
     DECLARE t1 BIGINT DEFAULT 0;
     DECLARE t2 BIGINT DEFAULT 0;
     DECLARE t3 BIGINT DEFAULT 0;
@@ -62,9 +62,10 @@ BEGIN
         -- expand with all children
         SELECT conv( concat( substring(uid,16,3), substring(uid,10,4), substring(uid,1,8)),16,10) div 10000 - (141427 * 24 * 60 * 60 * 1000) as current_mills INTO t3 from (select uuid() uid) as alias;
         IF ecount > 0 THEN
-            call getChildren(propertiesTable);
+            -- TODO versioned queries
+            call getChildren(propertiesTable, False);
         END IF;
-        
+
         -- expand with all replacements
         SELECT conv( concat( substring(uid,16,3), substring(uid,10,4), substring(uid,1,8)),16,10) div 10000 - (141427 * 24 * 60 * 60 * 1000) as current_mills INTO t4 from (select uuid() uid) as alias;
         IF ecount > 0 THEN
@@ -93,10 +94,11 @@ DROP PROCEDURE IF EXISTS db_2_0.initPOVRefidsTable //
 CREATE PROCEDURE db_2_0.initPOVRefidsTable(in vInt INT UNSIGNED, in vText VARCHAR(255))
 BEGIN
     DECLARE refIdsTable VARCHAR(255) DEFAULT NULL; /*table for referenced entity ids*/
-	
+
     #-- for reference properties: the value is interpreted as a record type name.
     IF vText IS NOT NULL THEN
-        call createTmpTable(refIdsTable);
+        -- TODO versioned queries
+        call createTmpTable(refIdsTable, FALSE);
         call initSubEntity(vInt, vText, refIdsTable);
         #-- now, all ids are in the refIdsTable
     END IF;
diff --git a/procedures/query/initQuery.sql b/procedures/query/initQuery.sql
index b233972d2ca7bb72aab768ef5be300273f5ec382..37653a36624a7995ca74eee7030b5f795ad8908e 100644
--- a/procedures/query/initQuery.sql
+++ b/procedures/query/initQuery.sql
@@ -32,11 +32,11 @@
 DROP PROCEDURE IF EXISTS db_2_0.initQuery;
 DELIMITER //
 
-CREATE PROCEDURE db_2_0.initQuery()
+CREATE PROCEDURE db_2_0.initQuery(in versioned BOOLEAN)
 BEGIN
     CREATE TEMPORARY TABLE IF NOT EXISTS warnings (warning TEXT NOT NULL);
-	
-	call createTmpTable(@resultSet);
+
+    call createTmpTable(@resultSet, versioned);
     SELECT @resultSet as tablename;
 
 END;
diff --git a/procedures/query/initSubEntity.sql b/procedures/query/initSubEntity.sql
index 543a0ce0f4745561ad0fa489da580d5e30fc3267..3cb31aa2c9d7e8fcc4bf8de26bc726862044e1fc 100644
--- a/procedures/query/initSubEntity.sql
+++ b/procedures/query/initSubEntity.sql
@@ -56,7 +56,8 @@ BEGIN
     END IF;
 
     IF ecount > 0 THEN
-        call getChildren(tableName);
+        -- TODO versioning
+        call getChildren(tableName, False);
     END IF;
 
 END;
diff --git a/procedures/query/makeStmt.sql b/procedures/query/makeStmt.sql
index 7ef80bfb9db6a0026642f6cc64eeaf560b9fbfe8..f6d6ab743a7ee5ef10b383f5e88716d1c2dc0f40 100644
--- a/procedures/query/makeStmt.sql
+++ b/procedures/query/makeStmt.sql
@@ -23,16 +23,53 @@
 DROP FUNCTION IF EXISTS db_2_0.makeStmt;
 DELIMITER //
 
-CREATE FUNCTION db_2_0.makeStmt(sourceSet VARCHAR(255), targetSet VARCHAR(255), data VARCHAR(20000), properties VARCHAR(20000)) RETURNS VARCHAR(20000) NO SQL
-BEGIN		
-
+/**
+ * Create and return a statement string which generalizes the source -> target procedure.
+ *
+ * Parameters
+ * ----------
+ *
+ * sourceSet : table
+ * The source table.
+ *
+ * targetSet : table
+ * The table into which the results shall be copied.  If `NULL`, delete all non-matching rows from
+ * `sourceSet`.
+ *
+ * data : table
+ * Table whose IDs are a whitelist for which IDs shall be copied from `sourceSet` to `targetSet`.
+ *
+ * properties : table
+ * Table with a whitelist of properties.  If not `NULL`, the `property_id` of `data` must be an ID
+ * in `properties`.
+ * TODO Add documentation about the `id2` meaning of `properties`.
+ *
+ * versiones : boolean
+ * If `True` and if `sourceSet` is the `entities` table, the ID and version are copied directly from
+ * `data` to `targetSet`, which must not be `NULL`.  Property filtering is done as usual.
+ */
+CREATE FUNCTION db_2_0.makeStmt(sourceSet VARCHAR(255), targetSet VARCHAR(255), data VARCHAR(20000),
+                                properties VARCHAR(20000), versioned BOOLEAN)
+RETURNS VARCHAR(20000) NO SQL
+BEGIN
+        IF sourceSet = "entities" AND versioned THEN
+            RETURN CONCAT('INSERT IGNORE INTO `',
+                targetSet,
+                '` (id, _iversion) SELECT entity_id, _iversion FROM ',
+                data,
+                IF(properties IS NULL, '',
+                    CONCAT(' AS data JOIN `', properties, '` AS prop ON (data.property_id = prop.id) WHERE ',
+                           'data.entity_id = prop.id2 OR prop.id2 = 0')));
+        END IF;
         RETURN CONCAT(
             IF(targetSet IS NULL,
                 CONCAT('DELETE FROM `',sourceSet,'` WHERE NOT EXISTS (SELECT 1 FROM '), 
-                CONCAT('INSERT IGNORE INTO `',targetSet,'` (id) SELECT id FROM `',sourceSet,'` WHERE EXISTS (SELECT 1 FROM ')),
+                CONCAT('INSERT IGNORE INTO `',targetSet,'` (id) SELECT id FROM `',sourceSet,'` ',
+                       'WHERE EXISTS (SELECT 1 FROM ')),
             IF(properties IS NULL,
                 CONCAT(data,' as data WHERE '),
-                CONCAT('`',properties,'` as prop JOIN ',data,' as data ON (data.property_id=prop.id) WHERE (data.entity_id=prop.id2 OR prop.id2=0) AND ')),
+                CONCAT('`',properties,'` as prop JOIN ',data,' as data ON (data.property_id=prop.id) WHERE ',
+                       '(data.entity_id=prop.id2 OR prop.id2=0) AND ')),
             'data.entity_id=`', sourceSet, '`.`id` LIMIT 1)'
         );
 
diff --git a/procedures/retrieveEntityParents.sql b/procedures/retrieveEntityParents.sql
index 16466fc991693766c1bfded1acdeec453e2cd655..8303f872d5902a91e767df4a3b1e1461860e3fee 100644
--- a/procedures/retrieveEntityParents.sql
+++ b/procedures/retrieveEntityParents.sql
@@ -78,18 +78,24 @@ retrieveEntityParentsBody: BEGIN
 
             SELECT
                 i.parent AS ParentID,
-                ( SELECT value FROM archive_name_data
+                ( SELECT value FROM name_data
                     WHERE domain_id = 0
                     AND entity_id = ParentID
                     AND property_id = 20
-                    AND _iversion = IVersion) AS ParentName,
+                ) AS ParentName, -- This is not necessarily the name of the parent at the time of
+                                 -- IVersion but it is a good guess. Future implementations of the
+                                 -- archive_isa table should also store the IVersion of the
+                                 -- parents. Only then the historically correct ParentName can be
+                                 -- reconstructed.
                 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)
                 WHERE i.child = EntityID
-                AND i.child_iversion = IVersion;
+                AND i.child_iversion = IVersion
+                AND i.direct IS TRUE
+                ;
 
             LEAVE retrieveEntityParentsBody;
         END IF;
diff --git a/tests/test_autotap.sql b/tests/test_autotap.sql
index 26af8b87fbf61e98ef34f0a2a6b37efb296452c1..6345bf004944747489a7879b4180c75d3020f351 100644
--- a/tests/test_autotap.sql
+++ b/tests/test_autotap.sql
@@ -33,6 +33,84 @@ SELECT tap.has_schema('_caosdb_schema_unit_tests','');
 -- TABLES 
 -- ***************************************************************
 
+-- ***************************************************************
+-- TABLE _caosdb_schema_unit_tests.archive_isa
+-- ***************************************************************
+
+SELECT tap.has_table('_caosdb_schema_unit_tests','archive_isa','');
+SELECT tap.table_collation_is('_caosdb_schema_unit_tests','archive_isa','utf8_unicode_ci','');
+SELECT tap.table_engine_is('_caosdb_schema_unit_tests','archive_isa','InnoDB','');
+
+-- COLUMNS
+SELECT tap.columns_are('_caosdb_schema_unit_tests','archive_isa','`child`,`child_iversion`,`parent`,`direct`','');
+
+-- COLUMN archive_isa.child
+
+SELECT tap.has_column('_caosdb_schema_unit_tests','archive_isa','child','');
+SELECT tap.col_column_type_is('_caosdb_schema_unit_tests','archive_isa','child','int(10) unsigned','');
+SELECT tap.col_extra_is('_caosdb_schema_unit_tests','archive_isa','child','','');
+SELECT tap.col_default_is('_caosdb_schema_unit_tests','archive_isa','child',NULL,'');
+SELECT tap.col_charset_is('_caosdb_schema_unit_tests','archive_isa','child',NULL,'');
+SELECT tap.col_collation_is('_caosdb_schema_unit_tests','archive_isa','child',NULL,'');
+
+-- COLUMN archive_isa.child_iversion
+
+SELECT tap.has_column('_caosdb_schema_unit_tests','archive_isa','child_iversion','');
+SELECT tap.col_column_type_is('_caosdb_schema_unit_tests','archive_isa','child_iversion','int(10) unsigned','');
+SELECT tap.col_extra_is('_caosdb_schema_unit_tests','archive_isa','child_iversion','','');
+SELECT tap.col_default_is('_caosdb_schema_unit_tests','archive_isa','child_iversion',NULL,'');
+SELECT tap.col_charset_is('_caosdb_schema_unit_tests','archive_isa','child_iversion',NULL,'');
+SELECT tap.col_collation_is('_caosdb_schema_unit_tests','archive_isa','child_iversion',NULL,'');
+
+-- COLUMN archive_isa.parent
+
+SELECT tap.has_column('_caosdb_schema_unit_tests','archive_isa','parent','');
+SELECT tap.col_column_type_is('_caosdb_schema_unit_tests','archive_isa','parent','int(10) unsigned','');
+SELECT tap.col_extra_is('_caosdb_schema_unit_tests','archive_isa','parent','','');
+SELECT tap.col_default_is('_caosdb_schema_unit_tests','archive_isa','parent',NULL,'');
+SELECT tap.col_charset_is('_caosdb_schema_unit_tests','archive_isa','parent',NULL,'');
+SELECT tap.col_collation_is('_caosdb_schema_unit_tests','archive_isa','parent',NULL,'');
+
+-- COLUMN archive_isa.direct
+
+SELECT tap.has_column('_caosdb_schema_unit_tests','archive_isa','direct','');
+SELECT tap.col_column_type_is('_caosdb_schema_unit_tests','archive_isa','direct','tinyint(1)','');
+SELECT tap.col_extra_is('_caosdb_schema_unit_tests','archive_isa','direct','','');
+SELECT tap.col_default_is('_caosdb_schema_unit_tests','archive_isa','direct',1,'');
+SELECT tap.col_charset_is('_caosdb_schema_unit_tests','archive_isa','direct',NULL,'');
+SELECT tap.col_collation_is('_caosdb_schema_unit_tests','archive_isa','direct',NULL,'');
+
+-- INDEXES
+SELECT tap.indexes_are('_caosdb_schema_unit_tests','archive_isa','`parent`,`child`','');
+
+-- INDEX archive_isa.child
+
+SELECT tap.has_index('_caosdb_schema_unit_tests','archive_isa','child','');
+SELECT tap.index_is_type('_caosdb_schema_unit_tests','archive_isa','child','BTREE','');
+SELECT tap.is_indexed('_caosdb_schema_unit_tests','archive_isa','`child`,`child_iversion`','');
+
+-- INDEX archive_isa.parent
+
+SELECT tap.has_index('_caosdb_schema_unit_tests','archive_isa','parent','');
+SELECT tap.index_is_type('_caosdb_schema_unit_tests','archive_isa','parent','BTREE','');
+SELECT tap.is_indexed('_caosdb_schema_unit_tests','archive_isa','`parent`','');
+
+-- CONSTRAINTS
+SELECT tap.constraints_are('_caosdb_schema_unit_tests','archive_isa','`archive_isa_ibfk_1`,`archive_isa_ibfk_2`','');
+
+-- CONSTRAINT archive_isa.archive_isa_ibfk_1
+
+SELECT tap.has_constraint('_caosdb_schema_unit_tests','archive_isa','archive_isa_ibfk_1','');
+SELECT tap.constraint_type_is('_caosdb_schema_unit_tests','archive_isa','archive_isa_ibfk_1','FOREIGN KEY','');
+SELECT tap.fk_on_delete('_caosdb_schema_unit_tests','archive_isa','archive_isa_ibfk_1','CASCADE','');
+SELECT tap.fk_on_update('_caosdb_schema_unit_tests','archive_isa','archive_isa_ibfk_1','RESTRICT','');
+
+-- CONSTRAINT archive_isa.archive_isa_ibfk_2
+
+SELECT tap.has_constraint('_caosdb_schema_unit_tests','archive_isa','archive_isa_ibfk_2','');
+SELECT tap.constraint_type_is('_caosdb_schema_unit_tests','archive_isa','archive_isa_ibfk_2','FOREIGN KEY','');
+SELECT tap.fk_on_delete('_caosdb_schema_unit_tests','archive_isa','archive_isa_ibfk_2','CASCADE','');
+SELECT tap.fk_on_update('_caosdb_schema_unit_tests','archive_isa','archive_isa_ibfk_2','RESTRICT','');
 -- ***************************************************************
 -- TABLE _caosdb_schema_unit_tests.collection_type
 -- ***************************************************************
@@ -2539,13 +2617,6 @@ SELECT tap.procedure_is_deterministic('_caosdb_schema_unit_tests','entityACL','N
 SELECT tap.procedure_security_type_is('_caosdb_schema_unit_tests','entityACL','DEFINER','');
 SELECT tap.procedure_sql_data_access_is('_caosdb_schema_unit_tests','entityACL','CONTAINS SQL','');
 
--- PROCEDURES _caosdb_schema_unit_tests.finishNegationFilter
-
-SELECT tap.has_procedure('_caosdb_schema_unit_tests','finishNegationFilter','');
-SELECT tap.procedure_is_deterministic('_caosdb_schema_unit_tests','finishNegationFilter','NO','');
-SELECT tap.procedure_security_type_is('_caosdb_schema_unit_tests','finishNegationFilter','DEFINER','');
-SELECT tap.procedure_sql_data_access_is('_caosdb_schema_unit_tests','finishNegationFilter','CONTAINS SQL','');
-
 -- PROCEDURES _caosdb_schema_unit_tests.finishSubProperty
 
 SELECT tap.has_procedure('_caosdb_schema_unit_tests','finishSubProperty','');
@@ -2595,13 +2666,6 @@ SELECT tap.procedure_is_deterministic('_caosdb_schema_unit_tests','initBackRefer
 SELECT tap.procedure_security_type_is('_caosdb_schema_unit_tests','initBackReference','DEFINER','');
 SELECT tap.procedure_sql_data_access_is('_caosdb_schema_unit_tests','initBackReference','CONTAINS SQL','');
 
--- PROCEDURES _caosdb_schema_unit_tests.initConjunctionFilter
-
-SELECT tap.has_procedure('_caosdb_schema_unit_tests','initConjunctionFilter','');
-SELECT tap.procedure_is_deterministic('_caosdb_schema_unit_tests','initConjunctionFilter','NO','');
-SELECT tap.procedure_security_type_is('_caosdb_schema_unit_tests','initConjunctionFilter','DEFINER','');
-SELECT tap.procedure_sql_data_access_is('_caosdb_schema_unit_tests','initConjunctionFilter','CONTAINS SQL','');
-
 -- PROCEDURES _caosdb_schema_unit_tests.initDisjunctionFilter
 
 SELECT tap.has_procedure('_caosdb_schema_unit_tests','initDisjunctionFilter','');
@@ -2609,13 +2673,6 @@ SELECT tap.procedure_is_deterministic('_caosdb_schema_unit_tests','initDisjuncti
 SELECT tap.procedure_security_type_is('_caosdb_schema_unit_tests','initDisjunctionFilter','DEFINER','');
 SELECT tap.procedure_sql_data_access_is('_caosdb_schema_unit_tests','initDisjunctionFilter','CONTAINS SQL','');
 
--- PROCEDURES _caosdb_schema_unit_tests.initNegationFilter
-
-SELECT tap.has_procedure('_caosdb_schema_unit_tests','initNegationFilter','');
-SELECT tap.procedure_is_deterministic('_caosdb_schema_unit_tests','initNegationFilter','NO','');
-SELECT tap.procedure_security_type_is('_caosdb_schema_unit_tests','initNegationFilter','DEFINER','');
-SELECT tap.procedure_sql_data_access_is('_caosdb_schema_unit_tests','initNegationFilter','CONTAINS SQL','');
-
 -- PROCEDURES _caosdb_schema_unit_tests.initPOVRefidsTable
 
 SELECT tap.has_procedure('_caosdb_schema_unit_tests','initPOVRefidsTable','');