diff --git a/patches/patch20221122-6.0-SNAPSHOT/create_entity_ids_table.sql b/patches/patch20221122-6.0-SNAPSHOT/create_entity_ids_table.sql
index 2bca8175c7a8dc81e7994ecad0739f9dd2a99416..cbc6ded2d5900e10db6d5335927d4882696b0f8b 100644
--- a/patches/patch20221122-6.0-SNAPSHOT/create_entity_ids_table.sql
+++ b/patches/patch20221122-6.0-SNAPSHOT/create_entity_ids_table.sql
@@ -17,7 +17,6 @@ CREATE TABLE `entity_ids` (
 ) ENGINE=InnoDB;
 
 -- fill all existing entities into the new entity_ids table.
-INSERT INTO entity_ids (id, internal_id) SELECT id, id FROM entities WHERE id>0;
-INSERT INTO entity_ids (id, internal_id) SELECT id, id FROM entities WHERE id=0;
+INSERT INTO entity_ids (id, internal_id) SELECT id, id FROM entities WHERE id>0 AND role!="DOMAIN";
 UPDATE entity_ids SET id = internal_id;
 -- ALTER TABLE entity_ids CHANGE id id int(10) unsigned NOT NULL AUTO_INCREMENT  COMMENT 'External ID of an entity. This is the id of an entity which is exposed via the CaosDB API.';
diff --git a/procedures/entityVersioning.sql b/procedures/entityVersioning.sql
index 67711856c7ad09e604781a3888a973da26017778..22274f23fbf7a0feb56635e2f5479c26076bf2e6 100644
--- a/procedures/entityVersioning.sql
+++ b/procedures/entityVersioning.sql
@@ -297,7 +297,7 @@ READS SQL DATA
 BEGIN
     DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL;
 
-    SELECT internal_id INTO InternalEntityID FROM entity_ids WHERE id = EntityID;
+    SELECT temp.internal_id INTO InternalEntityID FROM (SELECT internal_id AS internal_id FROM entity_ids WHERE id = EntityID UNION SELECT EntityID AS internal_id) AS temp LIMIT 1;
 
     -- This implementation assumes that the distance from the head equals the
     -- difference between the _iversion numbers. This will not be correct anymore
diff --git a/procedures/insertEntityProperty.sql b/procedures/insertEntityProperty.sql
index 02c31bca70517e28cdd02083afefe9fe5bca10a7..f3d56e392936e103a68e57f06ff53afd9da79ed6 100644
--- a/procedures/insertEntityProperty.sql
+++ b/procedures/insertEntityProperty.sql
@@ -47,9 +47,9 @@ BEGIN
     DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL;
     DECLARE InternalDomainID INT UNSIGNED DEFAULT 0;
 
-    SELECT internal_id INTO InternalDomainID from entity_ids WHERE id = DomainID;
-    SELECT internal_id INTO InternalEntityID from entity_ids WHERE id = EntityID;
-    SELECT internal_id INTO InternalPropertyID from entity_ids WHERE id = PropertyID;
+    SELECT temp.internal_id INTO InternalDomainID FROM (SELECT internal_id AS internal_id FROM entity_ids WHERE id = DomainID UNION SELECT DomainID AS internal_id) AS temp LIMIT 1;
+    SELECT temp.internal_id INTO InternalEntityID FROM (SELECT internal_id AS internal_id FROM entity_ids WHERE id = EntityID UNION SELECT EntityID AS internal_id) AS temp LIMIT 1;
+    SELECT temp.internal_id INTO InternalPropertyID FROM (SELECT internal_id AS internal_id FROM entity_ids WHERE id = PropertyID UNION SELECT PropertyID AS internal_id) AS temp LIMIT 1;
 
     CASE Datatable
     WHEN 'double_data' THEN
@@ -81,7 +81,7 @@ BEGIN
             END IF;
 
         ELSE
-            SELECT internal_id INTO ReferenceValue FROM entity_ids WHERE id = PropertyValue;
+            SELECT temp.internal_id INTO ReferenceValue FROM (SELECT internal_id AS internal_id FROM entity_ids WHERE id = PropertyValue UNION SELECT PropertyValue AS internal_id) AS temp LIMIT 1;
         END IF;
 
 
diff --git a/procedures/registerSubdomain.sql b/procedures/registerSubdomain.sql
index 3d3f44db4a8ec6389e1ace7950fc65f8f10dcb74..547d9534427bf7d73f095c04c85091586b450c09 100644
--- a/procedures/registerSubdomain.sql
+++ b/procedures/registerSubdomain.sql
@@ -34,20 +34,17 @@ delimiter //
 CREATE PROCEDURE db_5_0.registerSubdomain(in amount INT UNSIGNED)
 BEGIN
     DECLARE ED INTEGER DEFAULT NULL;
-    DECLARE NewID INT UNSIGNED DEFAULT NULL;
 
     SELECT COUNT(id) INTO ED FROM entities WHERE Role='DOMAIN' AND id!=0;
 
     WHILE ED < amount DO
         INSERT INTO entities (description, role, acl) VALUES
             (NULL, 'DOMAIN', 0);
-        SET NewID = LAST_INSERT_ID();
 
-        INSERT INTO entity_ids (internal_id) VALUES (NewID);
         SET ED = ED + 1;
     END WHILE;
 
-    SELECT e.id as DomainID FROM entities AS i LEFT JOIN entity_ids AS e ON e.internal_id = i.id WHERE i.Role='DOMAIN' and e.internal_id!=0;
+    SELECT e.id as DomainID FROM entities AS e WHERE e.Role='DOMAIN' and e.id!=0;
 
 END;
 //
diff --git a/procedures/retrieveChildren.sql b/procedures/retrieveChildren.sql
new file mode 100644
index 0000000000000000000000000000000000000000..6721b928e1b4ee8191d042d515b0b8720de5aed1
--- /dev/null
+++ b/procedures/retrieveChildren.sql
@@ -0,0 +1,43 @@
+/*
+ * This file is a part of the CaosDB Project.
+ *
+ * Copyright (C) 2023 IndiScale GmbH <info@indiscale.com>
+ * Copyright (C) 2023 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/>.
+ */
+
+/* Retrieve the IDs of all direct children.
+
+Parameters
+==========
+
+ParentID : INT UNSIGNED
+    The ID of the parent.
+*/
+
+DROP PROCEDURE IF EXISTS db_5_0.retrieveChildren;
+delimiter //
+
+CREATE PROCEDURE db_5_0.retrieveChildren(in ParentID INT UNSIGNED)
+BEGIN
+    DECLARE InternalParentID INT UNSIGNED DEFAULT NULL;
+
+    SELECT internal_id INTO InternalParentID from entity_ids WHERE id = ParentID;
+
+    SELECT eids.id FROM isa_cache AS i JOIN entity_ids AS eids ON i.child = eids.internal_id WHERE i.parent=InternalParentID and i.rpath=i.child;
+
+END;
+//
+delimiter ;
diff --git a/procedures/retrieveEntityOverrides.sql b/procedures/retrieveEntityOverrides.sql
index 182cbc4e82e1dbc88f2fb49156fed4c07dbd60ba..cc8bfbe232bea819e2e896a0c19e2f9f52d9c67b 100644
--- a/procedures/retrieveEntityOverrides.sql
+++ b/procedures/retrieveEntityOverrides.sql
@@ -37,15 +37,15 @@ retrieveOverridesBody: BEGIN
     DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL;
     DECLARE InternalDomainID INT UNSIGNED DEFAULT NULL;
 
-    SELECT internal_id INTO InternalEntityID from entity_ids WHERE id = EntityID;
-    SELECT internal_id INTO InternalDomainID from entity_ids WHERE id = DomainID;
+    SELECT temp.internal_id INTO InternalDomainID FROM (SELECT internal_id AS internal_id FROM entity_ids WHERE id = DomainID UNION SELECT DomainID AS internal_id) AS temp LIMIT 1;
+    SELECT temp.internal_id INTO InternalEntityID FROM (SELECT internal_id AS internal_id FROM entity_ids WHERE id = EntityID UNION SELECT EntityID AS internal_id) AS temp LIMIT 1;
 
     IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN
         IF Version IS NOT NULL THEN
             IF InternalDomainID = 0 THEN
-                SELECT get_head_version(InternalEntityID) = Version INTO IsHead;
+                SELECT get_head_version(EntityID) = Version INTO IsHead;
             ELSE
-                SELECT get_head_version(InternalDomainID) = Version INTO IsHead;
+                SELECT get_head_version(DomainID) = Version INTO IsHead;
             END IF;
         END IF;
 
@@ -68,6 +68,7 @@ retrieveOverridesBody: BEGIN
                 NULL AS desc_override,
                 NULL AS type_override,
                 EntityID AS entity_id,
+                property_id AS InternalPropertyID,
                 ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS property_id
             FROM archive_name_overrides
             WHERE domain_id = InternalDomainID
@@ -83,6 +84,7 @@ retrieveOverridesBody: BEGIN
                 description AS desc_override,
                 NULL AS type_override,
                 EntityID AS entity_id,
+                property_id AS InternalPropertyID,
                 ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS property_id
             FROM archive_desc_overrides
             WHERE domain_id = InternalDomainID
@@ -102,6 +104,7 @@ retrieveOverridesBody: BEGIN
                     AND property_id = 20
                     LIMIT 1), datatype) AS type_override,
                 EntityID AS entity_id,
+                property_id AS InternalPropertyID,
                 ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS property_id
             FROM archive_data_type
             WHERE domain_id = InternalDomainID
@@ -117,6 +120,7 @@ retrieveOverridesBody: BEGIN
                 NULL AS desc_override,
                 NULL AS type_override,
                 EntityID AS entity_id,
+                property_id AS InternalPropertyID,
                 ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS property_id
             FROM archive_collection_type
             WHERE domain_id = InternalDomainID
@@ -133,6 +137,7 @@ retrieveOverridesBody: BEGIN
         NULL AS desc_override,
         NULL AS type_override,
         EntityID AS entity_id,
+        property_id AS InternalPropertyID,
         ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS property_id
     FROM name_overrides
     WHERE domain_id = InternalDomainID
@@ -146,6 +151,7 @@ retrieveOverridesBody: BEGIN
         description AS desc_override,
         NULL AS type_override,
         EntityID AS entity_id,
+        property_id AS InternalPropertyID,
         ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS property_id
     FROM desc_overrides
     WHERE domain_id = InternalDomainID
@@ -162,6 +168,7 @@ retrieveOverridesBody: BEGIN
             AND entity_ID = datatype
             AND property_id = 20 LIMIT 1), datatype) AS type_override,
         EntityID AS entity_id,
+        property_id AS InternalPropertyID,
         ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS property_id
     FROM data_type
     WHERE domain_id = InternalDomainID
@@ -175,6 +182,7 @@ retrieveOverridesBody: BEGIN
         NULL AS desc_override,
         NULL AS type_override,
         EntityID AS entity_id,
+        property_id AS InternalPropertyID,
         ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS property_id
     FROM collection_type
     WHERE domain_id = InternalDomainID
diff --git a/procedures/retrieveEntityProperties.sql b/procedures/retrieveEntityProperties.sql
index 775dd19f9dc4ba11ec866d1da005562668bb7863..78e9cf4fff9e12cd59281cff43c8f20eedb4497f 100644
--- a/procedures/retrieveEntityProperties.sql
+++ b/procedures/retrieveEntityProperties.sql
@@ -39,7 +39,7 @@ retrieveEntityPropertiesBody: BEGIN
     DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL;
     DECLARE InternalDomainID INT UNSIGNED DEFAULT 0;
 
-    SELECT internal_id INTO InternalEntityID from entity_ids WHERE id = EntityID;
+    SELECT temp.internal_id INTO InternalEntityID FROM (SELECT internal_id AS internal_id FROM entity_ids WHERE id = EntityID UNION SELECT EntityID AS internal_id) AS temp LIMIT 1;
     SELECT internal_id INTO InternalDomainID from entity_ids WHERE id = DomainID;
 
     IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN
@@ -65,6 +65,7 @@ retrieveEntityPropertiesBody: BEGIN
 
             #-- double properties
             SELECT
+                property_id AS InternalPropertyID,
                 ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID,
                 value AS PropertyValue,
                 status AS PropertyStatus,
@@ -78,6 +79,7 @@ retrieveEntityPropertiesBody: BEGIN
 
             #-- integer properties
             SELECT
+                property_id AS InternalPropertyID,
                 ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID,
                 value AS PropertyValue,
                 status AS PropertyStatus,
@@ -91,6 +93,7 @@ retrieveEntityPropertiesBody: BEGIN
 
             #-- date properties
             SELECT
+                property_id AS InternalPropertyID,
                 ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID,
                 CONCAT(value, '.NULL.NULL') AS PropertyValue,
                 status AS PropertyStatus,
@@ -104,6 +107,7 @@ retrieveEntityPropertiesBody: BEGIN
 
             #-- datetime properties
             SELECT
+                property_id AS InternalPropertyID,
                 ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID,
                 CONCAT(value, 'UTC', IF(value_ns IS NULL, '', value_ns))
                     AS PropertyValue,
@@ -118,6 +122,7 @@ retrieveEntityPropertiesBody: BEGIN
 
             #-- text properties
             SELECT
+                property_id AS InternalPropertyID,
                 ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID,
                 value AS PropertyValue,
                 status AS PropertyStatus,
@@ -131,6 +136,7 @@ retrieveEntityPropertiesBody: BEGIN
 
             #-- enum properties
             SELECT
+                property_id AS InternalPropertyID,
                 ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID,
                 value AS PropertyValue,
                 status AS PropertyStatus,
@@ -144,9 +150,12 @@ retrieveEntityPropertiesBody: BEGIN
 
             #-- reference properties
             SELECT
+                property_id AS InternalPropertyID,
                 ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID,
-                IF(value_iversion IS NULL, 
-                    ( SELECT id FROM entity_ids WHERE internal_id = value ),
+                IF(value_iversion IS NULL,
+                    IF(status = "REPLACEMENT",
+                        value,
+                        ( SELECT id FROM entity_ids WHERE internal_id = value )),
                     -- make it "value@version" if necessary
                     CONCAT(
                         ( SELECT id FROM entity_ids WHERE internal_id = value ),
@@ -163,6 +172,7 @@ retrieveEntityPropertiesBody: BEGIN
 
             #-- null properties
             SELECT
+                property_id AS InternalPropertyID,
                 ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID,
                 NULL AS PropertyValue,
                 status AS PropertyStatus,
@@ -176,6 +186,7 @@ retrieveEntityPropertiesBody: BEGIN
 
             #-- name properties
             SELECT
+                property_id AS InternalPropertyID,
                 ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID,
                 value AS PropertyValue,
                 status AS PropertyStatus,
@@ -192,6 +203,7 @@ retrieveEntityPropertiesBody: BEGIN
 
     #-- double properties
     SELECT
+        property_id AS InternalPropertyID,
         ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID,
         value AS PropertyValue,
         status AS PropertyStatus,
@@ -204,6 +216,7 @@ retrieveEntityPropertiesBody: BEGIN
 
     #-- integer properties
     SELECT
+        property_id AS InternalPropertyID,
         ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID,
         value AS PropertyValue,
         status AS PropertyStatus,
@@ -216,6 +229,7 @@ retrieveEntityPropertiesBody: BEGIN
 
     #-- date properties
     SELECT
+        property_id AS InternalPropertyID,
         ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID,
         CONCAT(value, '.NULL.NULL') AS PropertyValue,
         status AS PropertyStatus,
@@ -228,6 +242,7 @@ retrieveEntityPropertiesBody: BEGIN
 
     #-- datetime properties
     SELECT
+        property_id AS InternalPropertyID,
         ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID,
         CONCAT(value, 'UTC', IF(value_ns IS NULL, '', value_ns))
             AS PropertyValue,
@@ -241,6 +256,7 @@ retrieveEntityPropertiesBody: BEGIN
 
     #-- text properties
     SELECT
+        property_id AS InternalPropertyID,
         ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID,
         value AS PropertyValue,
         status AS PropertyStatus,
@@ -253,6 +269,7 @@ retrieveEntityPropertiesBody: BEGIN
 
     #-- enum properties
     SELECT
+        property_id AS InternalPropertyID,
         ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID,
         value AS PropertyValue,
         status AS PropertyStatus,
@@ -265,9 +282,12 @@ retrieveEntityPropertiesBody: BEGIN
 
     #-- reference properties
     SELECT
+        property_id AS InternalPropertyID,
         ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID,
         IF(value_iversion IS NULL,
-            ( SELECT id FROM entity_ids WHERE internal_id = value ),
+            IF(status = "REPLACEMENT",
+                value,
+                ( SELECT id FROM entity_ids WHERE internal_id = value )),
             -- make it "value@version" if necessary
             CONCAT(
                 ( SELECT id FROM entity_ids WHERE internal_id = value ),
@@ -283,6 +303,7 @@ retrieveEntityPropertiesBody: BEGIN
 
     #-- null properties
     SELECT
+        property_id AS InternalPropertyID,
         ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID,
         NULL AS PropertyValue,
         status AS PropertyStatus,
@@ -295,6 +316,7 @@ retrieveEntityPropertiesBody: BEGIN
 
     #-- name properties
     SELECT
+        property_id AS InternalPropertyID,
         ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID,
         value AS PropertyValue,
         status AS PropertyStatus,