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 0f58ba6d7873ea2ba2e4a625ad5c2726dd804268..2bca8175c7a8dc81e7994ecad0739f9dd2a99416 100644 --- a/patches/patch20221122-6.0-SNAPSHOT/create_entity_ids_table.sql +++ b/patches/patch20221122-6.0-SNAPSHOT/create_entity_ids_table.sql @@ -10,7 +10,7 @@ DROP PROCEDURE IF EXISTS setPassword; -- new entity_ids table DROP TABLE IF EXISTS `entity_ids`; CREATE TABLE `entity_ids` ( - `id` int(10) unsigned NOT NULL AUTO_INCREMENT, + `id` int(10) unsigned NOT NULL, `internal_id` int(10) unsigned NOT NULL COMMENT 'Internal ID of an entity. This id is used internally in the *_data tables and elsewhere. This ID is never exposed via the CaosDB API.', PRIMARY KEY `entity_ids_pk` (`id`), CONSTRAINT `entity_ids_internal_id` FOREIGN KEY (`internal_id`) REFERENCES `entities` (`id`) diff --git a/procedures/deleteIsaCache.sql b/procedures/deleteIsaCache.sql index 92f2bf6bcb50c9d0ed8260919f4e075f2f1db816..7e8a1a134a892e9195460e0a639b751582ffa3e9 100644 --- a/procedures/deleteIsaCache.sql +++ b/procedures/deleteIsaCache.sql @@ -38,15 +38,12 @@ parameter entity is a child or inside the rpath. Parameters ========== -EntityID : UNSIGNED +InternalEntityID : UNSIGNED Child entity for which all parental relations should be deleted. */ -CREATE PROCEDURE db_5_0.deleteIsa(IN EntityID INT UNSIGNED) +CREATE PROCEDURE db_5_0.deleteIsa(IN InternalEntityID INT UNSIGNED) BEGIN DECLARE IVersion INT UNSIGNED DEFAULT NULL; - DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL; - - SELECT internal_id INTO InternalEntityID from entity_ids WHERE id = EntityID; IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN SELECT max(_iversion) INTO IVersion diff --git a/procedures/entityVersioning.sql b/procedures/entityVersioning.sql index 22ef1758e06cf5b5d2bbb989927f30ad494f2ce2..67711856c7ad09e604781a3888a973da26017778 100644 --- a/procedures/entityVersioning.sql +++ b/procedures/entityVersioning.sql @@ -27,7 +27,7 @@ DROP PROCEDURE IF EXISTS db_5_0.insert_single_child_version // * * Parameters * ---------- - * EntityID + * InternalEntityID * The ID of the versioned entity. * Hash * A hash of the entity. This is currently not implemented properly and only @@ -43,7 +43,7 @@ DROP PROCEDURE IF EXISTS db_5_0.insert_single_child_version // * or updating an entity). */ CREATE PROCEDURE db_5_0.insert_single_child_version( - in EntityID INT UNSIGNED, + in InternalEntityID INT UNSIGNED, in Hash VARBINARY(255), in Version VARBINARY(255), in Parent VARBINARY(255), @@ -52,9 +52,6 @@ CREATE PROCEDURE db_5_0.insert_single_child_version( BEGIN DECLARE newiversion INT UNSIGNED DEFAULT NULL; DECLARE newipparent INT UNSIGNED DEFAULT NULL; - DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL; - - SELECT internal_id INTO InternalEntityID FROM entity_ids WHERE id = EntityID; -- find _ipparent IF Parent IS NOT NULL THEN @@ -117,7 +114,7 @@ DROP FUNCTION IF EXISTS db_5_0.get_iversion // * * Parameters * ---------- - * EntityID + * InternalEntityID * The entity's id. * Version * The (official, externally used) version id. @@ -127,15 +124,11 @@ DROP FUNCTION IF EXISTS db_5_0.get_iversion // * The internal version id. */ CREATE FUNCTION db_5_0.get_iversion( - EntityID INT UNSIGNED, + InternalEntityID INT UNSIGNED, Version VARBINARY(255)) RETURNS INT UNSIGNED READS SQL DATA BEGIN - DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL; - - SELECT internal_id INTO InternalEntityID FROM entity_ids WHERE id = EntityID; - RETURN ( SELECT e._iversion FROM entity_version AS e @@ -251,7 +244,7 @@ DROP FUNCTION IF EXISTS db_5_0._get_head_iversion // * * Parameters * ---------- - * EntityID + * InternalEntityID * The entity id. * * Returns @@ -259,14 +252,10 @@ DROP FUNCTION IF EXISTS db_5_0._get_head_iversion // * The _iversion of the HEAD. */ CREATE FUNCTION db_5_0._get_head_iversion( - EntityID INT UNSIGNED) + InternalEntityID INT UNSIGNED) RETURNS INT UNSIGNED READS SQL DATA BEGIN - DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL; - - SELECT internal_id INTO InternalEntityID FROM entity_ids WHERE id = EntityID; - -- 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 @@ -330,7 +319,7 @@ DROP FUNCTION IF EXISTS db_5_0._get_version // * * Parameters * ---------- - * EntityID + * InternalEntityID * The entity id. * IVersion * Internal version id (integer). @@ -340,15 +329,11 @@ DROP FUNCTION IF EXISTS db_5_0._get_version // * The version id. */ CREATE FUNCTION db_5_0._get_version( - EntityID INT UNSIGNED, + InternalEntityID INT UNSIGNED, IVersion INT UNSIGNED) RETURNS VARBINARY(255) READS SQL DATA BEGIN - DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL; - - SELECT internal_id INTO InternalEntityID FROM entity_ids WHERE id = EntityID; - RETURN ( SELECT version FROM entity_version WHERE entity_id = InternalEntityID @@ -536,11 +521,7 @@ retrieveQueryTemplateDefBody: BEGIN END IF; IF IsHead IS FALSE THEN - -- TODO Use get_iversion(EntityID, Version) instead? Or will that be much slower? - SELECT e._iversion INTO IVersion - FROM entity_version as e - WHERE e.entity_id = InternalEntityID - AND e.version = Version; + SET IVersion = get_iversion(InternalEntityID, Version); IF IVersion IS NULL THEN -- RETURN EARLY - Version does not exist. diff --git a/procedures/insertEntity.sql b/procedures/insertEntity.sql index c65ee528cde5cb440463c60458bd57c829c0ad6b..bbd541124133ce6e9c83ab7bc4144cadeb02c5ca 100644 --- a/procedures/insertEntity.sql +++ b/procedures/insertEntity.sql @@ -44,11 +44,10 @@ ACL : VARBINARY(65525) Select ====== -A tuple (EntityID, Version) +(Version) */ -CREATE PROCEDURE db_5_0.insertEntity(in EntityName VARCHAR(255), in EntityDesc TEXT, in EntityRole VARCHAR(255), in ACL VARBINARY(65525)) +CREATE PROCEDURE db_5_0.insertEntity(in EntityID INT UNSIGNED, in EntityName VARCHAR(255), in EntityDesc TEXT, in EntityRole VARCHAR(255), in ACL VARBINARY(65525)) BEGIN - DECLARE NewEntityID INT UNSIGNED DEFAULT NULL; DECLARE NewACLID INT UNSIGNED DEFAULT NULL; DECLARE Hash VARBINARY(255) DEFAULT NULL; DECLARE Version VARBINARY(255) DEFAULT NULL; @@ -66,14 +65,13 @@ BEGIN -- ... and return the generated id SET InternalEntityID = LAST_INSERT_ID(); - INSERT INTO entity_ids (internal_id) VALUES (InternalEntityID); - SET NewEntityID = LAST_INSERT_ID(); + INSERT INTO entity_ids (internal_id, id) VALUES (InternalEntityID, EntityID); IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN -- TODO this is transaction-scoped variable. Is this a good idea? SET Transaction = @SRID; SET Version = SHA1(UUID()); - CALL insert_single_child_version(NewEntityID, Hash, Version, Null, Transaction); + CALL insert_single_child_version(InternalEntityID, Hash, Version, Null, Transaction); END IF; -- insert the name of the entity into name_data table @@ -84,7 +82,7 @@ BEGIN VALUES (0, InternalEntityID, 20, EntityName, "FIX", 0); END IF; - SELECT NewEntityID as EntityID, Version as Version; + SELECT Version as Version; END; // diff --git a/procedures/query/applyIDFilter.sql b/procedures/query/applyIDFilter.sql index b1c26b7ca63442c2d6b1b8dbc41fbb22d17f6d95..13beb63435571d34d887de2c239222c0646765a7 100644 --- a/procedures/query/applyIDFilter.sql +++ b/procedures/query/applyIDFilter.sql @@ -65,38 +65,43 @@ IF targetSet IS NULL OR targetSet = sourceSet THEN "` WHERE ", IF(o IS NULL OR vInt IS NULL, "1=1", - CONCAT("NOT id", + CONCAT("NOT EXISTS (SELECT 1 FROM entity_ids AS eids WHERE eids.id ", o, - vInt)), + vInt, + " AND eids.internal_id = `", + sourceSet, + "`.id)" + )), IF(aggVal IS NULL, "", - CONCAT(" AND id!=", + CONCAT(" AND `", sourceSet, "`.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 ', + '` (id, _iversion) SELECT e.id, _get_head_iversion(e.id) FROM `entities` AS e JOIN entity_ids AS eids ON (e.id = eids.internal_id) WHERE ', IF(o IS NULL OR vInt IS NULL, "1=1", - CONCAT("id", + CONCAT("eids.id ", o, - vInt)), + vInt + )), IF(aggVal IS NULL, "", - CONCAT(" AND id=", + CONCAT(" AND e.id=", aggVal)), - ' UNION SELECT id, _iversion FROM `archive_entities` WHERE ', + ' UNION SELECT e.id, _iversion FROM `archive_entities` AS e JOIN entity_ids AS eids ON (e.id = eids.internal_id) WHERE ', IF(o IS NULL OR vInt IS NULL, "1=1", - CONCAT("id", + CONCAT("eids.id ", o, - vInt)), + vInt + )), IF(aggVal IS NULL, "", - CONCAT(" AND id=", + CONCAT(" AND e.id=", aggVal))); -- ################################################## @@ -108,10 +113,10 @@ ELSE '` (id, _iversion) SELECT data.id, data._iversion FROM `', '` (id) SELECT data.id FROM `'), sourceSet, - "` AS data WHERE ", + "` AS data JOIN entity_ids AS eids ON (eids.internal_id = data.id) WHERE ", IF(o IS NULL OR vInt IS NULL, "1=1", - CONCAT("data.id", + CONCAT("eids.id", o, vInt)), IF(aggVal IS NULL, diff --git a/procedures/query/applyTransactionFilter.sql b/procedures/query/applyTransactionFilter.sql index 7a428b0702352677826efce0cc60bb794415102d..2f1669a470e88d3125f7a38f4fe5600ab453f5dc 100644 --- a/procedures/query/applyTransactionFilter.sql +++ b/procedures/query/applyTransactionFilter.sql @@ -25,7 +25,7 @@ DELIMITER // CREATE PROCEDURE db_5_0.applyTransactionFilter(in sourceSet VARCHAR(255), targetSet VARCHAR(255), in transaction VARCHAR(255), in operator_u CHAR(2), in realm VARCHAR(255), in userName VARCHAR(255), in ilb BIGINT, in ilb_nanos INT UNSIGNED, in eub BIGINT, in eub_nanos INT UNSIGNED, in operator_t CHAR(2)) BEGIN - DECLARE data TEXT default CONCAT('(SELECT entity_id FROM transaction_log AS t WHERE t.transaction=\'', + DECLARE data TEXT default CONCAT('(SELECT internal_id AS entity_id FROM transaction_log AS t JOIN entity_ids AS eids ON ( t.entity_id = eids.id ) WHERE t.transaction=\'', transaction, '\'', IF(userName IS NOT NULL, diff --git a/procedures/query/initSubEntity.sql b/procedures/query/initSubEntity.sql index a2f5ea67e495e4cc8cc52f0248389bc44792451f..371934bff8e8981fe6e5abd516efdad6c02c28b3 100644 --- a/procedures/query/initSubEntity.sql +++ b/procedures/query/initSubEntity.sql @@ -48,7 +48,7 @@ BEGIN DEALLOCATE PREPARE stmt; IF e_id IS NOT NULL THEN - SET @stmtStr = CONCAT('INSERT IGNORE INTO `', tableName, '` (id) VALUES (', e_id, ')'); + SET @stmtStr = CONCAT('INSERT IGNORE INTO `', tableName, '` (id) SELECT internal_id FROM entity_ids WHERE id = ', e_id, ''); PREPARE stmt FROM @stmtStr; EXECUTE stmt; SET ecount = ecount + ROW_COUNT(); diff --git a/procedures/retrieveEntity.sql b/procedures/retrieveEntity.sql index be4eb7107d49eec7e9b8aad34c0ccdd4f0356c88..4bfde2d27a2f0ee19fd654150ea242fc561ba2bf 100644 --- a/procedures/retrieveEntity.sql +++ b/procedures/retrieveEntity.sql @@ -77,7 +77,7 @@ retrieveEntityBody: BEGIN SET IsHead = FALSE; SET Version = get_head_relative(EntityID, SUBSTR(Version, 6)); ELSE - SELECT get_head_version(InternalEntityID) = Version INTO IsHead; + SELECT get_head_version(EntityID) = Version INTO IsHead; END IF; IF IsHead IS FALSE THEN @@ -155,10 +155,8 @@ retrieveEntityBody: BEGIN WHERE file_id = InternalEntityID LIMIT 1; - SELECT eids.id INTO DatatypeID + SELECT dt.datatype INTO DatatypeID FROM data_type as dt - LEFT JOIN entity_ids eids - ON dt.datatype = eids.internal_id WHERE dt.domain_id=0 AND dt.entity_id=0 AND dt.property_id=InternalEntityID @@ -174,7 +172,7 @@ retrieveEntityBody: BEGIN SELECT ( SELECT value FROM name_data WHERE domain_id = 0 - AND entity_ID = DatatypeID + AND entity_id = DatatypeID AND property_id = 20 LIMIT 1 ) AS Datatype, CollectionName AS Collection, EntityID AS EntityID, diff --git a/procedures/retrieveEntityParents.sql b/procedures/retrieveEntityParents.sql index 9965f1c7cdaefdc8d9c209d0baad0b1b7d3a92e0..6d2c858f5f80c9f10191a25966308aaec1c60612 100644 --- a/procedures/retrieveEntityParents.sql +++ b/procedures/retrieveEntityParents.sql @@ -65,7 +65,7 @@ retrieveEntityParentsBody: BEGIN IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN IF Version IS NOT NULL THEN - SELECT get_head_version(InternalEntityID) = Version INTO IsHead; + SELECT get_head_version(EntityID) = Version INTO IsHead; END IF; IF IsHead IS FALSE THEN diff --git a/procedures/updateEntity.sql b/procedures/updateEntity.sql index 07b6d75eb51a208c9819d494e11617fde8872068..52a69eaf88ebb9d2ff77dcc1fc982e96cb29d0ca 100644 --- a/procedures/updateEntity.sql +++ b/procedures/updateEntity.sql @@ -91,7 +91,7 @@ BEGIN WHERE e.entity_id = InternalEntityID AND e._iversion = OldIVersion; CALL insert_single_child_version( - EntityID, Hash, Version, + InternalEntityID, Hash, Version, ParentVersion, Transaction); END IF;