diff --git a/procedures/query/applyIDFilter.sql b/procedures/query/applyIDFilter.sql
index 0badff0a12d9747cde4277f9d657d54eb47871e6..c9b876420493a61da7ff174e58b750976b79520f 100644
--- a/procedures/query/applyIDFilter.sql
+++ b/procedures/query/applyIDFilter.sql
@@ -25,7 +25,16 @@ 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), in versioned BOOLEAN)
+/**
+ * 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;
diff --git a/procedures/query/applyPOV.sql b/procedures/query/applyPOV.sql
index 81f587060f8327916873e2c417c6bf186b8c6703..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),
@@ -99,23 +112,51 @@ 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';
+        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
+    ELSEIF o = "(" or o = "!(" THEN  -- datetime intervals
         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 `date_data` UNION ALL SELECT DISTINCT domain_id, entity_id, _iversion, property_id FROM `archive_date_data`',
-                                              IF(vDateTimeDotNotation IS NULL, NULL,
-                                                                               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 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
-            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))));
+        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
@@ -159,7 +200,14 @@ POV_LABEL: BEGIN
     ELSE
         #-- generate statement parts
         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 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)')));
@@ -195,12 +243,14 @@ POV_LABEL: BEGIN
             );
 
 
-
-
     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 @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))')));
 
         IF targetSet IS NOT NULL THEN
             SET @stmtPOVStr = CONCAT('INSERT IGNORE INTO `',
@@ -209,6 +259,7 @@ POV_LABEL: BEGIN
                     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 `',
@@ -235,7 +286,7 @@ POV_LABEL: BEGIN
         DEALLOCATE PREPARE stmtPOVkeepTbl;
     ELSE
         #-- 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))')));
+        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))')));
 
         SET @stmtPOVStr = CONCAT(
                 IF(targetSet IS NULL,
diff --git a/procedures/query/applyRefPOV.sql b/procedures/query/applyRefPOV.sql
index 1770d928c868c7125f04638b0f69b9c0314c6251..a367408c37da4f839c432e366e8564255cd9b628 100644
--- a/procedures/query/applyRefPOV.sql
+++ b/procedures/query/applyRefPOV.sql
@@ -23,12 +23,22 @@
 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), in versioned BOOLEAN)
+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))');
+    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))');
+        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);
 
diff --git a/procedures/query/applyTransactionFilter.sql b/procedures/query/applyTransactionFilter.sql
index 56299d726f83b84c723ca23e0c94027b787139a5..49a4edb931136b1e24afdf38acfdf90445159df1 100644
--- a/procedures/query/applyTransactionFilter.sql
+++ b/procedures/query/applyTransactionFilter.sql
@@ -39,7 +39,7 @@ BEGIN
 		')'
 	);
 
-	SET @stmtTransactionStr = makeStmt(sourceSet,targetSet,data,NULL,FALSE);
+	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/calcDifference.sql b/procedures/query/calcDifference.sql
index 6814befff636e13f3a742baa57a21eca486a116c..c9788df0c4ea30e041441407c6f474a60cf01cfa 100644
--- a/procedures/query/calcDifference.sql
+++ b/procedures/query/calcDifference.sql
@@ -27,6 +27,9 @@
 DROP PROCEDURE IF EXISTS db_2_0.calcDifference;
 DELIMITER //
 
+/**
+ * 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
     IF versioned THEN
diff --git a/procedures/query/calcIntersection.sql b/procedures/query/calcIntersection.sql
index 0f53be233e537a20a1b5e04f3299382c283691cc..4cc90095bed2ea1bf9f2fa2f3190c8b62a974b38 100644
--- a/procedures/query/calcIntersection.sql
+++ b/procedures/query/calcIntersection.sql
@@ -25,6 +25,9 @@
 DROP PROCEDURE IF EXISTS db_2_0.calcIntersection;
 DELIMITER //
 
+/**
+ * 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
     IF versioned THEN
diff --git a/procedures/query/calcUnion.sql b/procedures/query/calcUnion.sql
index 885a7130a4b89717fe8c0908d39f28869fbd2175..006fb11aaa4695630db5d796d7048f7c9ca7ee5e 100644
--- a/procedures/query/calcUnion.sql
+++ b/procedures/query/calcUnion.sql
@@ -26,6 +26,9 @@
 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, '` SELECT * FROM `',sourceSet,'`');
diff --git a/procedures/query/cleanUpQuery.sql b/procedures/query/cleanUpQuery.sql
index cdb143f442998634d3eae21bfc36264e3bf4f71a..7cf78a5951f306f373896cc3d854deeee16c206c 100644
--- a/procedures/query/cleanUpQuery.sql
+++ b/procedures/query/cleanUpQuery.sql
@@ -27,6 +27,9 @@
 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
     CREATE TEMPORARY TABLE IF NOT EXISTS warnings (warning TEXT NOT NULL);
diff --git a/procedures/query/createTmpTable.sql b/procedures/query/createTmpTable.sql
index b0564c894a1dbb862a06d246c0f7e6ce8e617325..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 ;
@@ -46,7 +49,8 @@ BEGIN
     call registerTempTableName(newTableName);
 
     IF versioned THEN
-        SET @createTableStmtStr = CONCAT('CREATE TEMPORARY TABLE `', newTableName,'` ( id INT UNSIGNED, _iversion INT UNSIGNED, PRIMARY KEY (id, _iversion))' );
+        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;
@@ -73,7 +77,9 @@ 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;
diff --git a/procedures/query/finishSubProperty.sql b/procedures/query/finishSubProperty.sql
index e63cd413d4b543a0a5a2edffeb5b3462d8fbaef2..73a9ee62c9204ae6a2a250fec25c6100a0ed44a4 100644
--- a/procedures/query/finishSubProperty.sql
+++ b/procedures/query/finishSubProperty.sql
@@ -24,7 +24,8 @@
 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), in versioned BOOLEAN)
+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, versioned);
diff --git a/procedures/query/getChildren.sql b/procedures/query/getChildren.sql
index 1c5bdd0eaa448370a104eef207944eb1d0c79551..0ab6784fd9e0af95046b90aa62e13d69072a0922 100644
--- a/procedures/query/getChildren.sql
+++ b/procedures/query/getChildren.sql
@@ -23,6 +23,11 @@
 
 Drop Procedure if exists db_2_0.getChildren;
 Delimiter //
+/**
+ * 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
diff --git a/procedures/query/initEntity.sql b/procedures/query/initEntity.sql
index 8dfe5fd61a476041c803b90de8374bcfc7b31660..b96b30dfbc1110575bac7bf4eacf16e95fa65b83 100644
--- a/procedures/query/initEntity.sql
+++ b/procedures/query/initEntity.sql
@@ -24,15 +24,23 @@
 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), in versioned BOOLEAN)
+/**
+ * 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 ";
+    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 ";
+        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(
@@ -80,8 +88,9 @@ initEntityLabel: BEGIN
 
 
     -- ################# 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 ";
+        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 `',
@@ -96,7 +105,7 @@ initEntityLabel: BEGIN
                 select_columns,
                 'WHERE value LIKE ?;');
             SET @query_param = enameLike;
-        ELSEIF enameRegexp IS NOT NULL THEN 
+        ELSEIF enameRegexp IS NOT NULL THEN
             SET @initEntityStmtStr = CONCAT(
                 'INSERT IGNORE INTO `',
                 resultset,
diff --git a/procedures/query/makeStmt.sql b/procedures/query/makeStmt.sql
index f30549a89033c7c5485d2278ad31d9f8b2fcba05..f6d6ab743a7ee5ef10b383f5e88716d1c2dc0f40 100644
--- a/procedures/query/makeStmt.sql
+++ b/procedures/query/makeStmt.sql
@@ -23,24 +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), versioned BOOLEAN) RETURNS VARCHAR(20000) NO SQL
+/**
+ * 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')));
+                    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 fb5a176e867a48a83de0644466be3425164e7df8..8303f872d5902a91e767df4a3b1e1461860e3fee 100644
--- a/procedures/retrieveEntityParents.sql
+++ b/procedures/retrieveEntityParents.sql
@@ -82,7 +82,11 @@ retrieveEntityParentsBody: BEGIN
                     WHERE domain_id = 0
                     AND entity_id = ParentID
                     AND property_id = 20
-                ) 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.
+                ) 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
@@ -90,7 +94,8 @@ retrieveEntityParentsBody: BEGIN
                     ON (i.parent = e.id)
                 WHERE i.child = EntityID
                 AND i.child_iversion = IVersion
-                AND i.direct IS TRUE;
+                AND i.direct IS TRUE
+                ;
 
             LEAVE retrieveEntityParentsBody;
         END IF;