From e62d1799809226f34652d260ab3d9dedcb80f01e Mon Sep 17 00:00:00 2001 From: Timm Fitschen <t.fitschen@indiscale.com> Date: Tue, 10 Nov 2020 12:34:54 +0100 Subject: [PATCH] WIP: versioned backref --- procedures/query/applyBackReference.sql | 150 ++++++++++++++++++++---- procedures/query/initBackReference.sql | 6 +- 2 files changed, 128 insertions(+), 28 deletions(-) diff --git a/procedures/query/applyBackReference.sql b/procedures/query/applyBackReference.sql index 9a24507..3a62957 100644 --- a/procedures/query/applyBackReference.sql +++ b/procedures/query/applyBackReference.sql @@ -24,39 +24,139 @@ 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) +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); + 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))'); + 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; + 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)'))); + 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; - DEALLOCATE PREPARE backRefSubResultSetStmt; + PREPARE backRefSubResultSetStmt FROM @backRefSubResultSetStmtStr; + EXECUTE backRefSubResultSetStmt; + DEALLOCATE PREPARE backRefSubResultSetStmt; + + SELECT newTableName as list; + ELSE + IF versioned THEN + IF sourceSet = "entities" THEN + 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))', + 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 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)')), + + ')'); + 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=_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)')), + + ')'); + END IF; + 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; + END IF; + + 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/initBackReference.sql b/procedures/query/initBackReference.sql index 47038ad..11283fe 100644 --- a/procedures/query/initBackReference.sql +++ b/procedures/query/initBackReference.sql @@ -25,8 +25,8 @@ 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); @@ -38,7 +38,7 @@ BEGIN call initSubEntity(entity_id, ename, entitiesTable); END IF; - SELECT propertiesTable, entitiesTable; + SELECT propertiesTable, entitiesTable; END // -- GitLab