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
index 56f3e42b01a510476ff28e4f3d4a13909449ee2e..c784a055d2db19d6010647439c603daf9b7a0c27 100755
--- a/patches/patch20201110-4.0.0-rc1/patch.sh
+++ b/patches/patch20201110-4.0.0-rc1/patch.sh
@@ -36,7 +36,11 @@ fi
 
 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
 
 
diff --git a/procedures/query/applyBackReference.sql b/procedures/query/applyBackReference.sql
index 38d8acb95b1020b6d73821098c21e41a88db27d7..1bf1415282599860710219076e7ece49302d5490 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,7 +27,44 @@
 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, in versioned 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 is written 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).  If `sourceSet` is the `entities`
+ * table, unversioned references will result in all versions of a referenced candidate being returned.
+ *
+ */
+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;
 
@@ -38,7 +78,23 @@ BEGIN
         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)')));
+        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)'))
+        );
 
         PREPARE backRefSubResultSetStmt FROM @backRefSubResultSetStmtStr;
         EXECUTE backRefSubResultSetStmt;
@@ -48,9 +104,14 @@ BEGIN
     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) 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))',
+                    '` (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 `',
@@ -61,7 +122,11 @@ BEGIN
                         CONCAT(' AND EXISTS (SELECT 1 FROM `',
                             propertiesTable,
                             '` AS p WHERE p.id=data.property_id LIMIT 1)')),
-                    ') UNION ALL 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)',
+                    ') 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 `',
@@ -98,7 +163,9 @@ BEGIN
                     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=_get_head_iversion(source.id))',
+                    '` 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 `',
@@ -115,6 +182,7 @@ BEGIN
         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=`',
@@ -134,6 +202,7 @@ BEGIN
                             '` 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 `',