From 2280def3a079af53b42df3ff0516cb24d43171ea Mon Sep 17 00:00:00 2001 From: Timm Fitschen <t.fitschen@indiscale.com> Date: Wed, 23 Nov 2022 18:52:52 +0100 Subject: [PATCH] WIP: introduce external ids --- .../create_entity_ids_table.sql | 11 +++ patches/patch20221122-5.0.1/patch.sh | 4 +- procedures/deleteEntity.sql | 18 ++-- procedures/deleteEntityProperties.sql | 89 ++++++++++--------- procedures/deleteIsaCache.sql | 17 ++-- procedures/entityVersioning.sql | 80 +++++++++++++---- procedures/getDependentEntities.sql | 56 ++++++------ procedures/getFileIdByPath.sql | 4 +- procedures/getIdByName.sql | 27 ++++++ procedures/getInfo.sql | 24 ----- procedures/getRole.sql | 44 --------- procedures/insertEntity.sql | 10 ++- procedures/insertEntityDataType.sql | 33 +++++++ procedures/insertEntityProperty.sql | 43 +++++---- procedures/insertFile.sql | 14 +++ procedures/insertIsaCache.sql | 20 +++-- procedures/isSubtype.sql | 12 ++- procedures/overrideName.sql | 61 +++++++++++-- procedures/registerSubdomain.sql | 6 +- procedures/retrieveEntity.sql | 16 ++-- procedures/retrieveEntityParents.sql | 1 - procedures/retrieveEntityProperties.sql | 4 +- procedures/setPassword.sql | 37 -------- procedures/updateEntity.sql | 27 +++--- utils/update_sql_procedures.sh | 2 +- 25 files changed, 391 insertions(+), 269 deletions(-) create mode 100644 procedures/getIdByName.sql delete mode 100644 procedures/getInfo.sql delete mode 100644 procedures/getRole.sql create mode 100644 procedures/insertEntityDataType.sql create mode 100644 procedures/insertFile.sql delete mode 100644 procedures/setPassword.sql diff --git a/patches/patch20221122-5.0.1/create_entity_ids_table.sql b/patches/patch20221122-5.0.1/create_entity_ids_table.sql index b34d982..a60356d 100644 --- a/patches/patch20221122-5.0.1/create_entity_ids_table.sql +++ b/patches/patch20221122-5.0.1/create_entity_ids_table.sql @@ -2,6 +2,10 @@ DROP PROCEDURE IF EXISTS retrieveSubEntity; DROP PROCEDURE IF EXISTS retrieveDatatype; DROP PROCEDURE IF EXISTS retrieveGroup; +DROP PROCEDURE IF EXISTS getInfo; +DROP PROCEDURE IF EXISTS getRole; +DROP PROCEDURE IF EXISTS setPassword; + -- new entity_ids table DROP TABLE IF EXISTS `entity_ids`; @@ -17,3 +21,10 @@ 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; 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.'; + +ALTER TABLE null_data CHANGE property_id property_id INT UNSIGNED NOT NULL; +ALTER TABLE text_data CHANGE property_id property_id INT UNSIGNED NOT NULL; +ALTER TABLE double_data CHANGE property_id property_id INT UNSIGNED NOT NULL; +ALTER TABLE integer_data CHANGE property_id property_id INT UNSIGNED NOT NULL; +ALTER TABLE reference_data CHANGE property_id property_id INT UNSIGNED NOT NULL; +ALTER TABLE enum_data CHANGE property_id property_id INT UNSIGNED NOT NULL; diff --git a/patches/patch20221122-5.0.1/patch.sh b/patches/patch20221122-5.0.1/patch.sh index 07c8872..ca2fb6a 100755 --- a/patches/patch20221122-5.0.1/patch.sh +++ b/patches/patch20221122-5.0.1/patch.sh @@ -31,11 +31,11 @@ fi . $UTILSPATH/patch_header.sh $* -check_version $OLD_VERSION +# check_version $OLD_VERSION mysql_execute_file $PATCH_DIR/create_entity_ids_table.sql -update_version $NEW_VERSION +# update_version $NEW_VERSION success diff --git a/procedures/deleteEntity.sql b/procedures/deleteEntity.sql index 5574f3e..e3c3dab 100644 --- a/procedures/deleteEntity.sql +++ b/procedures/deleteEntity.sql @@ -40,28 +40,34 @@ delimiter // CREATE PROCEDURE db_5_0.deleteEntity(in EntityID INT UNSIGNED) BEGIN + DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL; + + SELECT internal_id INTO InternalEntityID from entity_ids WHERE id = EntityID; -- detele file properties - DELETE FROM files where file_id=EntityID; + DELETE FROM files where file_id=InternalEntityID; -- delete datatype stuff DELETE FROM data_type WHERE ( domain_id = 0 AND entity_id = 0 - AND property_id = EntityID ) - OR datatype = EntityID; + AND property_id = InternalEntityID ) + OR datatype = InternalEntityID; DELETE FROM collection_type WHERE domain_id = 0 AND entity_id = 0 - AND property_id = EntityID; + AND property_id = InternalEntityID; -- delete primary name (in case this is called without a prior call to deleteEntityProperties) DELETE FROM name_data WHERE domain_id = 0 - AND entity_id = EntityID + AND entity_id = InternalEntityID AND property_id = 20; - DELETE FROM entities where id=EntityID; + DELETE FROM entity_ids + WHERE internal_id = InternalEntityID; + + DELETE FROM entities where id=InternalEntityID; -- clean up unused acl DELETE FROM entity_acl diff --git a/procedures/deleteEntityProperties.sql b/procedures/deleteEntityProperties.sql index 147959d..2875ccb 100644 --- a/procedures/deleteEntityProperties.sql +++ b/procedures/deleteEntityProperties.sql @@ -29,13 +29,16 @@ delimiter // CREATE PROCEDURE db_5_0.deleteEntityProperties(in EntityID INT UNSIGNED) BEGIN DECLARE IVersion INT UNSIGNED DEFAULT NULL; + DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL; - CALL deleteIsa(EntityID); + SELECT internal_id INTO InternalEntityID from entity_ids WHERE id = EntityID; + + CALL deleteIsa(InternalEntityID); IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN SELECT max(e._iversion) INTO IVersion -- What's the latest version? FROM entity_version AS e - WHERE e.entity_id = EntityID; + WHERE e.entity_id = InternalEntityID; -- Copy the rows from *_data to archive_*_data --------------------- INSERT INTO archive_reference_data (domain_id, entity_id, @@ -43,142 +46,142 @@ BEGIN SELECT domain_id, entity_id, property_id, value, value_iversion, status, pidx, IVersion AS _iversion FROM reference_data - WHERE (domain_id = 0 AND entity_id = EntityID) - OR domain_id = EntityID; + WHERE (domain_id = 0 AND entity_id = InternalEntityID) + OR domain_id = InternalEntityID; INSERT INTO archive_null_data (domain_id, entity_id, property_id, status, pidx, _iversion) SELECT domain_id, entity_id, property_id, status, pidx, IVersion AS _iversion FROM null_data - WHERE (domain_id = 0 AND entity_id = EntityID) - OR domain_id = EntityID; + WHERE (domain_id = 0 AND entity_id = InternalEntityID) + OR domain_id = InternalEntityID; INSERT INTO archive_text_data (domain_id, entity_id, property_id, value, status, pidx, _iversion) SELECT domain_id, entity_id, property_id, value, status, pidx, IVersion AS _iversion FROM text_data - WHERE (domain_id = 0 AND entity_id = EntityID) - OR domain_id = EntityID; + WHERE (domain_id = 0 AND entity_id = InternalEntityID) + OR domain_id = InternalEntityID; INSERT INTO archive_name_data (domain_id, entity_id, property_id, value, status, pidx, _iversion) SELECT domain_id, entity_id, property_id, value, status, pidx, IVersion AS _iversion FROM name_data - WHERE (domain_id = 0 AND entity_id = EntityID) - OR domain_id = EntityID; + WHERE (domain_id = 0 AND entity_id = InternalEntityID) + OR domain_id = InternalEntityID; INSERT INTO archive_enum_data (domain_id, entity_id, property_id, value, status, pidx, _iversion) SELECT domain_id, entity_id, property_id, value, status, pidx, IVersion AS _iversion FROM enum_data - WHERE (domain_id = 0 AND entity_id = EntityID) - OR domain_id = EntityID; + WHERE (domain_id = 0 AND entity_id = InternalEntityID) + OR domain_id = InternalEntityID; INSERT INTO archive_integer_data (domain_id, entity_id, property_id, value, status, pidx, _iversion, unit_sig) SELECT domain_id, entity_id, property_id, value, status, pidx, IVersion AS _iversion, unit_sig FROM integer_data - WHERE (domain_id = 0 AND entity_id = EntityID) - OR domain_id = EntityID; + WHERE (domain_id = 0 AND entity_id = InternalEntityID) + OR domain_id = InternalEntityID; INSERT INTO archive_double_data (domain_id, entity_id, property_id, value, status, pidx, _iversion, unit_sig) SELECT domain_id, entity_id, property_id, value, status, pidx, IVersion AS _iversion, unit_sig FROM double_data - WHERE (domain_id = 0 AND entity_id = EntityID) - OR domain_id = EntityID; + WHERE (domain_id = 0 AND entity_id = InternalEntityID) + OR domain_id = InternalEntityID; INSERT INTO archive_datetime_data (domain_id, entity_id, property_id, value, value_ns, status, pidx, _iversion) SELECT domain_id, entity_id, property_id, value, value_ns, status, pidx, IVersion AS _iversion FROM datetime_data - WHERE (domain_id = 0 AND entity_id = EntityID) - OR domain_id = EntityID; + WHERE (domain_id = 0 AND entity_id = InternalEntityID) + OR domain_id = InternalEntityID; INSERT INTO archive_date_data (domain_id, entity_id, property_id, value, status, pidx, _iversion) SELECT domain_id, entity_id, property_id, value, status, pidx, IVersion AS _iversion FROM date_data - WHERE (domain_id = 0 AND entity_id = EntityID) - OR domain_id = EntityID; + WHERE (domain_id = 0 AND entity_id = InternalEntityID) + OR domain_id = InternalEntityID; INSERT INTO archive_name_overrides (domain_id, entity_id, property_id, name, _iversion) SELECT domain_id, entity_id, property_id, name, IVersion AS _iversion FROM name_overrides - WHERE (domain_id = 0 AND entity_id = EntityID) - OR domain_id = EntityID; + WHERE (domain_id = 0 AND entity_id = InternalEntityID) + OR domain_id = InternalEntityID; INSERT INTO archive_desc_overrides (domain_id, entity_id, property_id, description, _iversion) SELECT domain_id, entity_id, property_id, description, IVersion AS _iversion FROM desc_overrides - WHERE (domain_id = 0 AND entity_id = EntityID) - OR domain_id = EntityID; + WHERE (domain_id = 0 AND entity_id = InternalEntityID) + OR domain_id = InternalEntityID; INSERT INTO archive_data_type (domain_id, entity_id, property_id, datatype, _iversion) SELECT domain_id, entity_id, property_id, datatype, IVersion AS _iversion FROM data_type - WHERE (domain_id = 0 AND entity_id = EntityID) - OR domain_id = EntityID; + WHERE (domain_id = 0 AND entity_id = InternalEntityID) + OR domain_id = InternalEntityID; INSERT INTO archive_collection_type (domain_id, entity_id, property_id, collection, _iversion) SELECT domain_id, entity_id, property_id, collection, IVersion AS _iversion FROM collection_type - WHERE (domain_id = 0 AND entity_id = EntityID) - OR domain_id = EntityID; + WHERE (domain_id = 0 AND entity_id = InternalEntityID) + OR domain_id = InternalEntityID; INSERT INTO archive_query_template_def (id, definition, _iversion) SELECT id, definition, IVersion AS _iversion FROM query_template_def - WHERE id = EntityID; + WHERE id = InternalEntityID; END IF; DELETE FROM reference_data - where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; + where (domain_id=0 AND entity_id=InternalEntityID) OR domain_id=InternalEntityID; DELETE FROM null_data - where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; + where (domain_id=0 AND entity_id=InternalEntityID) OR domain_id=InternalEntityID; DELETE FROM text_data - where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; + where (domain_id=0 AND entity_id=InternalEntityID) OR domain_id=InternalEntityID; DELETE FROM name_data - where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; + where (domain_id=0 AND entity_id=InternalEntityID) OR domain_id=InternalEntityID; DELETE FROM enum_data - where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; + where (domain_id=0 AND entity_id=InternalEntityID) OR domain_id=InternalEntityID; DELETE FROM integer_data - where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; + where (domain_id=0 AND entity_id=InternalEntityID) OR domain_id=InternalEntityID; DELETE FROM double_data - where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; + where (domain_id=0 AND entity_id=InternalEntityID) OR domain_id=InternalEntityID; DELETE FROM datetime_data - where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; + where (domain_id=0 AND entity_id=InternalEntityID) OR domain_id=InternalEntityID; DELETE FROM date_data - where (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; + where (domain_id=0 AND entity_id=InternalEntityID) OR domain_id=InternalEntityID; DELETE FROM name_overrides - WHERE (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; + WHERE (domain_id=0 AND entity_id=InternalEntityID) OR domain_id=InternalEntityID; DELETE FROM desc_overrides - WHERE (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; + WHERE (domain_id=0 AND entity_id=InternalEntityID) OR domain_id=InternalEntityID; DELETE FROM data_type - WHERE (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; + WHERE (domain_id=0 AND entity_id=InternalEntityID) OR domain_id=InternalEntityID; DELETE FROM collection_type - WHERE (domain_id=0 AND entity_id=EntityID) OR domain_id=EntityID; + WHERE (domain_id=0 AND entity_id=InternalEntityID) OR domain_id=InternalEntityID; - DELETE FROM query_template_def WHERE id=EntityID; + DELETE FROM query_template_def WHERE id=InternalEntityID; END; // diff --git a/procedures/deleteIsaCache.sql b/procedures/deleteIsaCache.sql index fd78d3f..92f2bf6 100644 --- a/procedures/deleteIsaCache.sql +++ b/procedures/deleteIsaCache.sql @@ -44,24 +44,27 @@ Child entity for which all parental relations should be deleted. CREATE PROCEDURE db_5_0.deleteIsa(IN EntityID 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 FROM entity_version - WHERE entity_id = EntityID; + WHERE entity_id = InternalEntityID; -- move to archive_isa before deleting INSERT IGNORE INTO archive_isa (child, child_iversion, parent, direct) - SELECT e.child, IVersion AS child_iversion, e.parent, rpath = EntityID + SELECT e.child, IVersion AS child_iversion, e.parent, rpath = InternalEntityID FROM isa_cache AS e - WHERE e.child = EntityID; + WHERE e.child = InternalEntityID; END IF; DELETE FROM isa_cache - WHERE child = EntityID - OR rpath = EntityID - OR rpath LIKE concat('%>', EntityID) - OR rpath LIKE concat('%>', EntityID, '>%'); + WHERE child = InternalEntityID + OR rpath = InternalEntityID + OR rpath LIKE concat('%>', InternalEntityID) + OR rpath LIKE concat('%>', InternalEntityID, '>%'); END; // diff --git a/procedures/entityVersioning.sql b/procedures/entityVersioning.sql index 888fc60..22ef175 100644 --- a/procedures/entityVersioning.sql +++ b/procedures/entityVersioning.sql @@ -52,12 +52,15 @@ 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 SELECT e._iversion INTO newipparent FROM entity_version AS e - WHERE e.entity_id = EntityID + WHERE e.entity_id = InternalEntityID AND e.version = Parent; IF newipparent IS NULL THEN -- throw error; @@ -70,7 +73,7 @@ BEGIN -- generate _iversion SELECT max(e._iversion)+1 INTO newiversion FROM entity_version AS e - WHERE e.entity_id=EntityID; + WHERE e.entity_id=InternalEntityID; IF newiversion IS NULL THEN SET newiversion = 1; END IF; @@ -78,7 +81,7 @@ BEGIN INSERT INTO entity_version (entity_id, hash, version, _iversion, _ipparent, srid) VALUES - (EntityID, Hash, Version, newiversion, newipparent, Transaction); + (InternalEntityID, Hash, Version, newiversion, newipparent, Transaction); @@ -98,8 +101,11 @@ DROP PROCEDURE IF EXISTS db_5_0.delete_all_entity_versions // CREATE PROCEDURE db_5_0.delete_all_entity_versions( in EntityID INT UNSIGNED) BEGIN + DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL; + + SELECT internal_id INTO InternalEntityID FROM entity_ids WHERE id = EntityID; - DELETE FROM entity_version WHERE entity_id = EntityID; + DELETE FROM entity_version WHERE entity_id = InternalEntityID; END; // @@ -126,10 +132,14 @@ CREATE FUNCTION db_5_0.get_iversion( 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 - WHERE e.entity_id = EntityID + WHERE e.entity_id = InternalEntityID AND e.version = Version ); END; @@ -158,12 +168,16 @@ CREATE FUNCTION db_5_0.get_primary_parent_version( 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 p.version FROM entity_version AS e INNER JOIN entity_version AS p ON (e._ipparent = p._iversion AND e.entity_id = p.entity_id) - WHERE e.entity_id = EntityID + WHERE e.entity_id = InternalEntityID AND e.version = Version ); END; @@ -193,11 +207,15 @@ CREATE FUNCTION db_5_0.get_version_timestamp( RETURNS VARCHAR(255) READS SQL DATA BEGIN + DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL; + + SELECT internal_id INTO InternalEntityID FROM entity_ids WHERE id = EntityID; + RETURN ( SELECT concat(t.seconds, '.', t.nanos) FROM entity_version AS e INNER JOIN transactions AS t ON ( e.srid = t.srid ) - WHERE e.entity_id = EntityID + WHERE e.entity_id = InternalEntityID AND e.version = Version ); END; @@ -245,6 +263,10 @@ CREATE FUNCTION db_5_0._get_head_iversion( 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 @@ -252,7 +274,7 @@ BEGIN RETURN ( SELECT e._iversion FROM entity_version AS e - WHERE e.entity_id = EntityID + WHERE e.entity_id = InternalEntityID ORDER BY e._iversion DESC LIMIT 1 ); @@ -284,6 +306,10 @@ CREATE FUNCTION db_5_0.get_head_relative( RETURNS VARBINARY(255) 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 distance from the head equals the -- difference between the _iversion numbers. This will not be correct anymore -- as soon as branches may split and merge. Then, a walk over the primary @@ -291,7 +317,7 @@ BEGIN RETURN ( SELECT e.version FROM entity_version AS e - WHERE e.entity_id = EntityID + WHERE e.entity_id = InternalEntityID ORDER BY e._iversion DESC LIMIT 1 OFFSET Offset ); @@ -319,9 +345,13 @@ CREATE FUNCTION db_5_0._get_version( 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 = EntityID + WHERE entity_id = InternalEntityID AND _iversion = IVersion ); END; @@ -346,6 +376,10 @@ DROP PROCEDURE IF EXISTS db_5_0.get_version_history // CREATE PROCEDURE db_5_0.get_version_history( in EntityID INT UNSIGNED) BEGIN + DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL; + + SELECT internal_id INTO InternalEntityID FROM entity_ids WHERE id = EntityID; + -- retrieve root(s) (initial versions) SELECT c.version AS child, NULL as parent, @@ -355,7 +389,7 @@ BEGIN t.realm AS child_realm FROM entity_version AS c INNER JOIN transactions as t ON ( c.srid = t.srid ) - WHERE c.entity_id = EntityID + WHERE c.entity_id = InternalEntityID AND c._ipparent is Null -- TODO This first SELECT statement is necessary because the second one @@ -375,7 +409,7 @@ BEGIN ON (c._ipparent = p._iversion AND c.entity_id = p.entity_id AND t.srid = c.srid) - WHERE p.entity_id = EntityID; + WHERE p.entity_id = InternalEntityID; END; // @@ -439,24 +473,28 @@ CREATE PROCEDURE setFileProperties ( in FileHash VARCHAR(255) ) BEGIN + DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL; DECLARE IVersion 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(e._iversion) INTO IVersion FROM entity_version AS e - WHERE e.entity_id = EntityID; + WHERE e.entity_id = InternalEntityID; INSERT INTO archive_files (file_id, path, size, hash, _iversion) SELECT file_id, path, size, hash, IVersion AS _iversion FROM files - WHERE file_id = EntityID; + WHERE file_id = InternalEntityID; END IF; - DELETE FROM files WHERE file_id = EntityID; + DELETE FROM files WHERE file_id = InternalEntityID; IF FilePath IS NOT NULL THEN INSERT INTO files (file_id, path, size, hash) - VALUES (EntityID, FilePath, FileSize, unhex(FileHash)); + VALUES (InternalEntityID, FilePath, FileSize, unhex(FileHash)); END IF; END // @@ -486,6 +524,10 @@ retrieveQueryTemplateDefBody: BEGIN DECLARE IVersion INT UNSIGNED DEFAULT NULL; DECLARE IsHead BOOLEAN DEFAULT TRUE; + 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 -- Are we at the head? @@ -497,7 +539,7 @@ retrieveQueryTemplateDefBody: BEGIN -- 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 = EntityID + WHERE e.entity_id = InternalEntityID AND e.version = Version; IF IVersion IS NULL THEN @@ -507,7 +549,7 @@ retrieveQueryTemplateDefBody: BEGIN SELECT definition FROM archive_query_template_def - WHERE id = EntityID + WHERE id = InternalEntityID AND _iversion = IVersion; LEAVE retrieveQueryTemplateDefBody; @@ -516,7 +558,7 @@ retrieveQueryTemplateDefBody: BEGIN SELECT definition FROM query_template_def - WHERE id = EntityID; + WHERE id = InternalEntityID; END // diff --git a/procedures/getDependentEntities.sql b/procedures/getDependentEntities.sql index 708503d..81c0e38 100644 --- a/procedures/getDependentEntities.sql +++ b/procedures/getDependentEntities.sql @@ -29,45 +29,49 @@ delimiter // CREATE PROCEDURE db_5_0.getDependentEntities(in EntityID INT UNSIGNED) BEGIN -DROP TEMPORARY TABLE IF EXISTS refering; -CREATE TEMPORARY TABLE refering ( -id INT UNSIGNED UNIQUE -); + DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL; -INSERT IGNORE INTO refering (id) SELECT entity_id FROM reference_data WHERE (value=EntityID OR property_id=EntityID) AND domain_id=0 AND entity_id!=EntityID; -INSERT IGNORE INTO refering (id) SELECT domain_id FROM reference_data WHERE (value=EntityID OR property_id=EntityID) AND domain_id!=EntityID AND entity_id!=EntityID AND domain_id!=0; + DROP TEMPORARY TABLE IF EXISTS refering; + CREATE TEMPORARY TABLE refering ( + id INT UNSIGNED UNIQUE + ); -INSERT IGNORE INTO refering (id) SELECT entity_id FROM text_data WHERE property_id=EntityID AND domain_id=0 AND entity_id!=EntityID; -INSERT IGNORE INTO refering (id) SELECT domain_id FROM text_data WHERE property_id=EntityID AND domain_id!=EntityID AND entity_id!=EntityID AND domain_id!=0; + SELECT internal_id INTO InternalEntityID from entity_ids WHERE id = EntityID; -INSERT IGNORE INTO refering (id) SELECT entity_id FROM enum_data WHERE property_id=EntityID AND domain_id=0 AND entity_id!=EntityID; -INSERT IGNORE INTO refering (id) SELECT domain_id FROM enum_data WHERE property_id=EntityID AND domain_id!=EntityID AND entity_id!=EntityID AND domain_id!=0; + INSERT IGNORE INTO refering (id) SELECT entity_id FROM reference_data WHERE (value=InternalEntityID OR property_id=InternalEntityID) AND domain_id=0 AND entity_id!=InternalEntityID; + INSERT IGNORE INTO refering (id) SELECT domain_id FROM reference_data WHERE (value=InternalEntityID OR property_id=InternalEntityID) AND domain_id!=InternalEntityID AND entity_id!=InternalEntityID AND domain_id!=0; -INSERT IGNORE INTO refering (id) SELECT entity_id FROM name_data WHERE property_id=EntityID AND domain_id=0 AND entity_id!=EntityID; -INSERT IGNORE INTO refering (id) SELECT domain_id FROM name_data WHERE property_id=EntityID AND domain_id!=EntityID AND entity_id!=EntityID AND domain_id!=0; + INSERT IGNORE INTO refering (id) SELECT entity_id FROM text_data WHERE property_id=InternalEntityID AND domain_id=0 AND entity_id!=InternalEntityID; + INSERT IGNORE INTO refering (id) SELECT domain_id FROM text_data WHERE property_id=InternalEntityID AND domain_id!=InternalEntityID AND entity_id!=InternalEntityID AND domain_id!=0; -INSERT IGNORE INTO refering (id) SELECT entity_id FROM integer_data WHERE property_id=EntityID AND domain_id=0 AND entity_id!=EntityID; -INSERT IGNORE INTO refering (id) SELECT domain_id FROM integer_data WHERE property_id=EntityID AND domain_id!=EntityID AND entity_id!=EntityID AND domain_id!=0; + INSERT IGNORE INTO refering (id) SELECT entity_id FROM enum_data WHERE property_id=InternalEntityID AND domain_id=0 AND entity_id!=InternalEntityID; + INSERT IGNORE INTO refering (id) SELECT domain_id FROM enum_data WHERE property_id=InternalEntityID AND domain_id!=InternalEntityID AND entity_id!=InternalEntityID AND domain_id!=0; -INSERT IGNORE INTO refering (id) SELECT entity_id FROM double_data WHERE property_id=EntityID AND domain_id=0 AND entity_id!=EntityID; -INSERT IGNORE INTO refering (id) SELECT domain_id FROM double_data WHERE property_id=EntityID AND domain_id!=EntityID AND entity_id!=EntityID AND domain_id!=0; + INSERT IGNORE INTO refering (id) SELECT entity_id FROM name_data WHERE property_id=InternalEntityID AND domain_id=0 AND entity_id!=InternalEntityID; + INSERT IGNORE INTO refering (id) SELECT domain_id FROM name_data WHERE property_id=InternalEntityID AND domain_id!=InternalEntityID AND entity_id!=InternalEntityID AND domain_id!=0; -INSERT IGNORE INTO refering (id) SELECT entity_id FROM datetime_data WHERE property_id=EntityID AND domain_id=0 AND entity_id!=EntityID; -INSERT IGNORE INTO refering (id) SELECT domain_id FROM datetime_data WHERE property_id=EntityID AND domain_id!=EntityID AND entity_id!=EntityID AND domain_id!=0; + INSERT IGNORE INTO refering (id) SELECT entity_id FROM integer_data WHERE property_id=InternalEntityID AND domain_id=0 AND entity_id!=InternalEntityID; + INSERT IGNORE INTO refering (id) SELECT domain_id FROM integer_data WHERE property_id=InternalEntityID AND domain_id!=InternalEntityID AND entity_id!=InternalEntityID AND domain_id!=0; -INSERT IGNORE INTO refering (id) SELECT entity_id FROM date_data WHERE property_id=EntityID AND domain_id=0 AND entity_id!=EntityID; -INSERT IGNORE INTO refering (id) SELECT domain_id FROM date_data WHERE property_id=EntityID AND domain_id!=EntityID AND entity_id!=EntityID AND domain_id!=0; + INSERT IGNORE INTO refering (id) SELECT entity_id FROM double_data WHERE property_id=InternalEntityID AND domain_id=0 AND entity_id!=InternalEntityID; + INSERT IGNORE INTO refering (id) SELECT domain_id FROM double_data WHERE property_id=InternalEntityID AND domain_id!=InternalEntityID AND entity_id!=InternalEntityID AND domain_id!=0; -INSERT IGNORE INTO refering (id) SELECT entity_id FROM null_data WHERE property_id=EntityID AND domain_id=0 AND entity_id!=EntityID; -INSERT IGNORE INTO refering (id) SELECT domain_id FROM null_data WHERE property_id=EntityID AND domain_id!=EntityID AND entity_id!=EntityID AND domain_id!=0; + INSERT IGNORE INTO refering (id) SELECT entity_id FROM datetime_data WHERE property_id=InternalEntityID AND domain_id=0 AND entity_id!=InternalEntityID; + INSERT IGNORE INTO refering (id) SELECT domain_id FROM datetime_data WHERE property_id=InternalEntityID AND domain_id!=InternalEntityID AND entity_id!=InternalEntityID AND domain_id!=0; -INSERT IGNORE INTO refering (id) SELECT entity_id from data_type WHERE datatype=EntityID AND domain_id=0 AND entity_id!=EntityID; -INSERT IGNORE INTO refering (id) SELECT domain_id from data_type WHERE datatype=EntityID; + INSERT IGNORE INTO refering (id) SELECT entity_id FROM date_data WHERE property_id=InternalEntityID AND domain_id=0 AND entity_id!=InternalEntityID; + INSERT IGNORE INTO refering (id) SELECT domain_id FROM date_data WHERE property_id=InternalEntityID AND domain_id!=InternalEntityID AND entity_id!=InternalEntityID AND domain_id!=0; + INSERT IGNORE INTO refering (id) SELECT entity_id FROM null_data WHERE property_id=InternalEntityID AND domain_id=0 AND entity_id!=InternalEntityID; + INSERT IGNORE INTO refering (id) SELECT domain_id FROM null_data WHERE property_id=InternalEntityID AND domain_id!=InternalEntityID AND entity_id!=InternalEntityID AND domain_id!=0; -Select id from refering WHERE id!=0 and id!=EntityID; + INSERT IGNORE INTO refering (id) SELECT entity_id from data_type WHERE datatype=InternalEntityID AND domain_id=0 AND entity_id!=InternalEntityID; + INSERT IGNORE INTO refering (id) SELECT domain_id from data_type WHERE datatype=InternalEntityID; -DROP TEMPORARY TABLE refering; + + SELECT e.id FROM refering AS r LEFT JOIN entity_ids AS e ON r.id = e.internal_id WHERE r.id!=0 AND e.internal_id!=InternalEntityID; + + DROP TEMPORARY TABLE refering; END; // diff --git a/procedures/getFileIdByPath.sql b/procedures/getFileIdByPath.sql index e565ece..97634b1 100644 --- a/procedures/getFileIdByPath.sql +++ b/procedures/getFileIdByPath.sql @@ -24,9 +24,9 @@ Drop Procedure if exists db_5_0.getFileIdByPath; Delimiter // Create Procedure db_5_0.getFileIdByPath (in FilePath VARCHAR(255)) -BEGIN +BEGIN -Select file_id as FileID from files where path=FilePath LIMIT 1; + SELECT e.id AS FileID FROM files AS f LEFT JOIN entity_ids ON e.internal_in = f.file_id WHERE f.path=FilePath LIMIT 1; END; // diff --git a/procedures/getIdByName.sql b/procedures/getIdByName.sql new file mode 100644 index 0000000..0d1208f --- /dev/null +++ b/procedures/getIdByName.sql @@ -0,0 +1,27 @@ + +DROP PROCEDURE IF EXISTS db_5_0.getIdByName; +DELIMITER // + +CREATE PROCEDURE db_5_0.getIdByName(in Name VARCHAR(255), in Role VARCHAR(255), in Lmt VARCHAR(255)) +BEGIN + + SET @stmtStr = "SELECT e.id AS id FROM name_data AS n JOIN entity_ids AS e ON (n.domain_id=0 AND n.property_id=20 AND e.internal_id = n.entity_id) JOIN entities AS i ON (i.id = e.internal_id) WHERE n.value = ?"; + + IF Role IS NULL THEN + SET @stmtStr = CONCAT(@stmtStr, " AND i.role!='ROLE'"); + ELSE + SET @stmtStr = CONCAT(@stmtStr, " AND i.role='", Role, "'"); + END IF; + + IF Lmt IS NOT NULL THEN + SET @stmtStr = CONCAT(@stmtStr, " LIMIT ", Lmt); + END IF; + + SET @vName = Name; + PREPARE stmt FROM @stmtStr; + EXECUTE stmt USING @vName; + DEALLOCATE PREPARE stmt; + +END; +// +DELIMITER ; diff --git a/procedures/getInfo.sql b/procedures/getInfo.sql deleted file mode 100644 index 03c75b4..0000000 --- a/procedures/getInfo.sql +++ /dev/null @@ -1,24 +0,0 @@ -/* - * ** header v3.0 - * This file is a part of the CaosDB Project. - * - * Copyright (C) 2018 Research Group Biomedical Physics, - * Max-Planck-Institute for Dynamics and Self-Organization Göttingen - * - * 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/>. - * - * ** end header - */ -#-- old procedure. -Drop Procedure if exists db_5_0.getInfo; diff --git a/procedures/getRole.sql b/procedures/getRole.sql deleted file mode 100644 index bea96fc..0000000 --- a/procedures/getRole.sql +++ /dev/null @@ -1,44 +0,0 @@ -/* - * ** header v3.0 - * This file is a part of the CaosDB Project. - * - * Copyright (C) 2018 Research Group Biomedical Physics, - * Max-Planck-Institute for Dynamics and Self-Organization Göttingen - * - * 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/>. - * - * ** end header - */ - - - - - - - -DROP PROCEDURE IF EXISTS db_5_0.getRole; -delimiter // -CREATE PROCEDURE db_5_0.getRole(in RoleName VARCHAR(255)) -BEGIN - -Select e.id INTO @RoleID from entities e where e.name=RoleName AND e.role=RoleName LIMIT 1; - -call retrieveEntity(@RoleID); - - - - -END; -// -delimiter ; diff --git a/procedures/insertEntity.sql b/procedures/insertEntity.sql index e73a3bd..c65ee52 100644 --- a/procedures/insertEntity.sql +++ b/procedures/insertEntity.sql @@ -4,8 +4,8 @@ * * 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 + * Copyright (C) 2020 - 2022 IndiScale GmbH <info@indiscale.com> + * Copyright (C) 2020 - 2022 Timm Fitschen <t.fitschen@indiscale * * This program is free software: you can redistribute it and/or modify * it under the terms of the GNU Affero General Public License as @@ -53,6 +53,7 @@ BEGIN DECLARE Hash VARBINARY(255) DEFAULT NULL; DECLARE Version VARBINARY(255) DEFAULT NULL; DECLARE Transaction VARBINARY(255) DEFAULT NULL; + DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL; -- insert the acl. the new acl id is being written (c-style) into the -- variable NewACLID. @@ -63,6 +64,9 @@ BEGIN VALUES (EntityDesc, EntityRole, NewACLID); -- ... and return the generated id + SET InternalEntityID = LAST_INSERT_ID(); + + INSERT INTO entity_ids (internal_id) VALUES (InternalEntityID); SET NewEntityID = LAST_INSERT_ID(); IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN @@ -77,7 +81,7 @@ BEGIN IF EntityName IS NOT NULL THEN INSERT INTO name_data (domain_id, entity_id, property_id, value, status, pidx) - VALUES (0, NewEntityID, 20, EntityName, "FIX", 0); + VALUES (0, InternalEntityID, 20, EntityName, "FIX", 0); END IF; SELECT NewEntityID as EntityID, Version as Version; diff --git a/procedures/insertEntityDataType.sql b/procedures/insertEntityDataType.sql new file mode 100644 index 0000000..9836f9f --- /dev/null +++ b/procedures/insertEntityDataType.sql @@ -0,0 +1,33 @@ + + +DROP PROCEDURE IF EXISTS db_5_0.insertEntityDataType; +DELIMITER // + +CREATE PROCEDURE db_5_0.insertEntityDataType(in PropertyID INT UNSIGNED, in DataType VARCHAR(255)) +BEGIN + DECLARE InternalPropertyID INT UNSIGNED DEFAULT NULL; + + SELECT internal_id INTO InternalPropertyID FROM entity_ids WHERE id=PropertyID; + + INSERT INTO data_type (domain_id, entity_id, property_id, datatype) SELECT 0, 0, InternalPropertyID, ( SELECT entity_id FROM name_data WHERE domain_id = 0 AND property_id = 20 AND value = DataType LIMIT 1); + + +END; +// +DELIMITER ; + + +DROP PROCEDURE IF EXISTS db_5_0.insertEntityCollection; +DELIMITER // + +CREATE PROCEDURE db_5_0.insertEntityCollection(in PropertyID INT UNSIGNED, in Collection VARCHAR(255)) +BEGIN + DECLARE InternalPropertyID INT UNSIGNED DEFAULT NULL; + + SELECT internal_id INTO InternalPropertyID FROM entity_ids WHERE id=PropertyID; + + INSERT INTO collection_type (domain_id, entity_id, property_id, collection) SELECT 0, 0, InternalPropertyID, Collection; + +END; +// +DELIMITER ; diff --git a/procedures/insertEntityProperty.sql b/procedures/insertEntityProperty.sql index 1cfd38b..02c31bc 100644 --- a/procedures/insertEntityProperty.sql +++ b/procedures/insertEntityProperty.sql @@ -42,89 +42,100 @@ BEGIN DECLARE ReferenceValueIVersion INT UNSIGNED DEFAULT NULL; DECLARE ReferenceValue INT UNSIGNED DEFAULT NULL; DECLARE AT_PRESENT INTEGER DEFAULT NULL; + DECLARE InternalDataTypeID INT UNSIGNED DEFAULT NULL; + DECLARE InternalPropertyID INT UNSIGNED DEFAULT NULL; + 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; CASE Datatable WHEN 'double_data' THEN INSERT INTO double_data (domain_id, entity_id, property_id, value, unit_sig, status, pidx) VALUES - (DomainID, EntityID, PropertyID, PropertyValue, PropertyUnitSig, PropertyStatus, PropertyIndex); + (InternalDomainID, InternalEntityID, InternalPropertyID, PropertyValue, PropertyUnitSig, PropertyStatus, PropertyIndex); WHEN 'integer_data' THEN INSERT INTO integer_data (domain_id, entity_id, property_id, value, unit_sig, status, pidx) VALUES - (DomainID, EntityID, PropertyID, PropertyValue, PropertyUnitSig, PropertyStatus, PropertyIndex); + (InternalDomainID, InternalEntityID, InternalPropertyID, PropertyValue, PropertyUnitSig, PropertyStatus, PropertyIndex); WHEN 'datetime_data' THEN INSERT INTO datetime_data (domain_id, entity_id, property_id, value, value_ns, status, pidx) VALUES - (DomainID, EntityID, PropertyID, SUBSTRING_INDEX(PropertyValue, 'UTC', 1), IF(SUBSTRING_INDEX(PropertyValue, 'UTC', -1)='',NULL,SUBSTRING_INDEX(PropertyValue, 'UTC', -1)), PropertyStatus, PropertyIndex); + (InternalDomainID, InternalEntityID, InternalPropertyID, SUBSTRING_INDEX(PropertyValue, 'UTC', 1), IF(SUBSTRING_INDEX(PropertyValue, 'UTC', -1)='',NULL,SUBSTRING_INDEX(PropertyValue, 'UTC', -1)), PropertyStatus, PropertyIndex); WHEN 'reference_data' THEN -- special handling if versioning enabled and specific version of referenced entity is given. SET AT_PRESENT=LOCATE("@", PropertyValue); IF is_feature_config("ENTITY_VERSIONING", "ENABLED") AND AT_PRESENT > 0 THEN - SET ReferenceValue = SUBSTRING_INDEX(PropertyValue, '@', 1); + SELECT internal_id INTO ReferenceValue FROM entity_ids WHERE id = SUBSTRING_INDEX(PropertyValue, '@', 1); SET ReferenceValueIVersion = get_iversion(ReferenceValue, SUBSTRING_INDEX(PropertyValue, '@', -1)); - -- TODO raise error when @ present but iversion is null IF ReferenceValueIVersion IS NULL THEN + -- Raise error when @ present but iversion is null SELECT 0 from `ReferenceValueIVersion_WAS_NULL`; END IF; ELSE - SET ReferenceValue = PropertyValue; + SELECT internal_id INTO ReferenceValue FROM entity_ids WHERE id = PropertyValue; END IF; + INSERT INTO reference_data (domain_id, entity_id, property_id, value, value_iversion, status, pidx) VALUES - (DomainID, EntityID, PropertyID, ReferenceValue, + (InternalDomainID, InternalEntityID, InternalPropertyID, ReferenceValue, ReferenceValueIVersion, PropertyStatus, PropertyIndex); WHEN 'enum_data' THEN INSERT INTO enum_data (domain_id, entity_id, property_id, value, status, pidx) VALUES - (DomainID, EntityID, PropertyID, PropertyValue, PropertyStatus, PropertyIndex); + (InternalDomainID, InternalEntityID, InternalPropertyID, PropertyValue, PropertyStatus, PropertyIndex); WHEN 'date_data' THEN INSERT INTO date_data (domain_id, entity_id, property_id, value, status, pidx) VALUES - (DomainID, EntityID, PropertyID, SUBSTRING_INDEX(PropertyValue, '.', 1), PropertyStatus, PropertyIndex); + (InternalDomainID, InternalEntityID, InternalPropertyID, SUBSTRING_INDEX(PropertyValue, '.', 1), PropertyStatus, PropertyIndex); WHEN 'text_data' THEN INSERT INTO text_data (domain_id, entity_id, property_id, value, status, pidx) VALUES - (DomainID, EntityID, PropertyID, PropertyValue, PropertyStatus, PropertyIndex); + (InternalDomainID, InternalEntityID, InternalPropertyID, PropertyValue, PropertyStatus, PropertyIndex); WHEN 'null_data' THEN INSERT INTO null_data (domain_id, entity_id, property_id, status, pidx) VALUES - (DomainID, EntityID, PropertyID, PropertyStatus, PropertyIndex); + (InternalDomainID, InternalEntityID, InternalPropertyID, PropertyStatus, PropertyIndex); WHEN 'name_data' THEN INSERT INTO name_data (domain_id, entity_id, property_id, value, status, pidx) VALUES - (DomainID, EntityID, PropertyID, PropertyValue, PropertyStatus, PropertyIndex); + (InternalDomainID, InternalEntityID, InternalPropertyID, PropertyValue, PropertyStatus, PropertyIndex); ELSE + -- raise error SELECT * FROM table_does_not_exist; END CASE; IF DatatypeOverride IS NOT NULL THEN - call overrideType(DomainID, EntityID, PropertyID, DatatypeOverride); + SELECT internal_id INTO InternalDataTypeID from entity_ids WHERE id = DatatypeOverride; + call overrideType(InternalDomainID, InternalEntityID, InternalPropertyID, InternalDataTypeID); IF Collection IS NOT NULL THEN - INSERT INTO collection_type (domain_id, entity_id, property_id, collection) VALUES (DomainID, EntityID, PropertyID, Collection); + INSERT INTO collection_type (domain_id, entity_id, property_id, collection) VALUES (InternalDomainID, InternalEntityID, InternalPropertyID, Collection); END IF; END IF; IF NameOverride IS NOT NULL THEN - call overrideName(DomainID, EntityID, PropertyID, NameOverride); + call overrideName(InternalDomainID, InternalEntityID, InternalPropertyID, NameOverride); END IF; IF DescOverride IS NOT NULL THEN - call overrideDesc(DomainID, EntityID, PropertyID, DescOverride); + call overrideDesc(InternalDomainID, InternalEntityID, InternalPropertyID, DescOverride); END IF; END; diff --git a/procedures/insertFile.sql b/procedures/insertFile.sql new file mode 100644 index 0000000..153b141 --- /dev/null +++ b/procedures/insertFile.sql @@ -0,0 +1,14 @@ + +DROP PROCEDURE IF EXISTS db_5_0.insertFile; +DELIMITER // + +CREATE PROCEDURE db_5_0.insertFile(in EntityID INT UNSIGNED, in Hash VARCHAR(255), in FileSize BIGINT UNSIGNED, in FilePath VARCHAR(255)) +BEGIN + DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL; + SELECT internal_id INTO InternalEntityID FROM entity_ids WHERE id=EntityID; + + INSERT INTO files (file_id, hash, size, path) VALUES (InternalEntityID, unhex(Hash), FileSize, FilePath); + +END; +// +DELIMITER ; diff --git a/procedures/insertIsaCache.sql b/procedures/insertIsaCache.sql index 9d1bf1c..d1d06e8 100644 --- a/procedures/insertIsaCache.sql +++ b/procedures/insertIsaCache.sql @@ -33,15 +33,21 @@ DELIMITER // * Parameters * ========== * - * c : UNSIGNED + * ChildID : UNSIGNED * The child entity * - * p : UNSIGNED + * ParentID : UNSIGNED * The parent entity */ -CREATE PROCEDURE db_5_0.insertIsa(IN c INT UNSIGNED, IN p INT UNSIGNED) +CREATE PROCEDURE db_5_0.insertIsa(IN ChildID INT UNSIGNED, IN ParentID INT UNSIGNED) insert_is_a_proc: BEGIN + DECLARE c INT UNSIGNED DEFAULT NULL; + DECLARE p INT UNSIGNED DEFAULT NULL; + + SELECT internal_id INTO c FROM entity_ids WHERE id = ChildID; + SELECT internal_id INTO p FROM entity_ids WHERE id = ParentID; + INSERT INTO isa_cache (child, parent, rpath) VALUES (c, p, c); IF p = c THEN @@ -69,17 +75,17 @@ insert_is_a_proc: BEGIN INSERT IGNORE INTO isa_cache SELECT l.child, -- Descendant as found in isa_cache r.parent, -- Ancestor as found in isa_cache - if(l.rpath=l.child and r.rpath=c, -- if distance=1 for left and right: + IF(l.rpath=l.child AND r.rpath=c, -- if distance=1 for left and right: c, -- rpath = current child - concat(if(l.rpath=l.child, -- if dist=1 for descendant: + concat(IF(l.rpath=l.child, -- if dist=1 for descendant: c, -- rpath starts with c concat(l.rpath, '>', c)), -- rpath starts with "desc.rpath > c" - if(r.rpath=c, -- if dist=1 for ancestor + IF(r.rpath=c, -- if dist=1 for ancestor '', -- rpath is finished concat('>', r.rpath)))) -- rpath continuees with " > ancest.rpath" AS rpath FROM - isa_cache as l INNER JOIN isa_cache as r + isa_cache AS l INNER JOIN isa_cache AS r ON (l.parent = c AND c = r.child AND l.child != l.parent); -- Left: descendants of c, right: ancestors END; diff --git a/procedures/isSubtype.sql b/procedures/isSubtype.sql index f97c13f..d421cfd 100644 --- a/procedures/isSubtype.sql +++ b/procedures/isSubtype.sql @@ -25,10 +25,16 @@ DROP PROCEDURE IF EXISTS db_5_0.isSubtype; delimiter // -CREATE PROCEDURE db_5_0.isSubtype(in c INT UNSIGNED, in p INT UNSIGNED) +CREATE PROCEDURE db_5_0.isSubtype(in ChildID INT UNSIGNED, in ParentID INT UNSIGNED) BEGIN - DECLARE ret BOOLEAN DEFAULT FALSE; - SELECT TRUE INTO ret FROM isa_cache AS i WHERE i.child=c AND i.parent=p LIMIT 1; + DECLARE c INT UNSIGNED DEFAULT NULL; + DECLARE p INT UNSIGNED DEFAULT NULL; + DECLARE ret BOOLEAN DEFAULT FALSE; + + SELECT internal_id INTO c from entity_ids WHERE id = ChildID; + SELECT internal_id INTO p from entity_ids WHERE id = ParentID; + + SELECT TRUE INTO ret FROM isa_cache AS i WHERE i.child=c AND i.parent=p LIMIT 1; SELECT ret as ISA; END; // diff --git a/procedures/overrideName.sql b/procedures/overrideName.sql index ace102b..c518842 100644 --- a/procedures/overrideName.sql +++ b/procedures/overrideName.sql @@ -26,21 +26,70 @@ DROP PROCEDURE IF EXISTS db_5_0.overrideDesc; DROP PROCEDURE IF EXISTS db_5_0.overrideType; DELIMITER // -CREATE PROCEDURE db_5_0.overrideName(in DomainID INT UNSIGNED, in EntityID INT UNSIGNED, in PropertyID INT UNSIGNED, in Name VARCHAR(255)) +/* Insert a name override. + +Parameters +========== + +InternalDomainID : INT UNSIGNED + The *internal* id of the domain. + +InternalEntityID : INT UNSIGNED + The *internal* id of the entity. + +InternalPropertyID : INT UNSIGNED + The *internal* id of the property. + +Name : VARCHAR(255) +*/ +CREATE PROCEDURE db_5_0.overrideName(in InternalDomainID INT UNSIGNED, in InternalEntityID INT UNSIGNED, in InternalPropertyID INT UNSIGNED, in Name VARCHAR(255)) BEGIN - INSERT INTO name_overrides (domain_id, entity_id, property_id, name) VALUES (DomainID, EntityID, PropertyID, Name); + INSERT INTO name_overrides (domain_id, entity_id, property_id, name) VALUES (InternalDomainID, InternalEntityID, InternalPropertyID, Name); END; // -CREATE PROCEDURE db_5_0.overrideDesc(in DomainID INT UNSIGNED, in EntityID INT UNSIGNED, in PropertyID INT UNSIGNED, in Description TEXT) +/* Insert a description override. + +Parameters +========== + +InternalDomainID : INT UNSIGNED + The *internal* id of the domain. + +InternalEntityID : INT UNSIGNED + The *internal* id of the entity. + +InternalPropertyID : INT UNSIGNED + The *internal* id of the property. + +Description : TEXT +*/ +CREATE PROCEDURE db_5_0.overrideDesc(in InternalDomainID INT UNSIGNED, in InternalEntityID INT UNSIGNED, in InternalPropertyID INT UNSIGNED, in Description TEXT) BEGIN - INSERT INTO desc_overrides (domain_id, entity_id, property_id, description) VALUES (DomainID, EntityID, PropertyID, Description); + INSERT INTO desc_overrides (domain_id, entity_id, property_id, description) VALUES (InternalDomainID, InternalEntityID, InternalPropertyID, Description); END; // -CREATE PROCEDURE db_5_0.overrideType(in DomainID INT UNSIGNED, in EntityID INT UNSIGNED, in PropertyID INT UNSIGNED, in Datatype INT UNSIGNED) +/* Insert a data type override. + +Parameters +========== + +InternalDomainID : INT UNSIGNED + The *internal* id of the domain. + +InternalEntityID : INT UNSIGNED + The *internal* id of the entity. + +InternalPropertyID : INT UNSIGNED + The *internal* id of the property. + +InternalDatatypeID : INT UNSIGNED + The *internal* id of the data type. +*/ +CREATE PROCEDURE db_5_0.overrideType(in InternalDomainID INT UNSIGNED, in InternalEntityID INT UNSIGNED, in InternalPropertyID INT UNSIGNED, in InternalDataTypeID INT UNSIGNED) BEGIN - INSERT INTO data_type (domain_id, entity_id, property_id, datatype) VALUES (DomainID, EntityID, PropertyID, Datatype); + INSERT INTO data_type (domain_id, entity_id, property_id, datatype) VALUES (InternalDomainID, InternalEntityID, InternalPropertyID, InternalDataTypeID); END; // diff --git a/procedures/registerSubdomain.sql b/procedures/registerSubdomain.sql index 4cb18e4..3d3f44d 100644 --- a/procedures/registerSubdomain.sql +++ b/procedures/registerSubdomain.sql @@ -34,16 +34,20 @@ 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 id as DomainID FROM entities WHERE Role='DOMAIN' and id!=0; + 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; END; // diff --git a/procedures/retrieveEntity.sql b/procedures/retrieveEntity.sql index aa8a406..be4eb71 100644 --- a/procedures/retrieveEntity.sql +++ b/procedures/retrieveEntity.sql @@ -72,10 +72,10 @@ retrieveEntityBody: BEGIN IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN -- Find out head-ness and version IF Version IS NULL OR UPPER(Version) = "HEAD" THEN - SET Version = get_head_version(InternalEntityID); + SET Version = get_head_version(EntityID); ELSEIF UPPER(LEFT(Version, 5)) = "HEAD~" THEN SET IsHead = FALSE; - SET Version = get_head_relative(InternalEntityID, SUBSTR(Version, 6)); + SET Version = get_head_relative(EntityID, SUBSTR(Version, 6)); ELSE SELECT get_head_version(InternalEntityID) = Version INTO IsHead; END IF; @@ -155,11 +155,13 @@ retrieveEntityBody: BEGIN WHERE file_id = InternalEntityID LIMIT 1; - SELECT datatype INTO DatatypeID - FROM data_type - WHERE domain_id=0 - AND entity_id=0 - AND property_id=InternalEntityID + SELECT eids.id 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 LIMIT 1; SELECT collection INTO CollectionName diff --git a/procedures/retrieveEntityParents.sql b/procedures/retrieveEntityParents.sql index 0ed5145..9965f1c 100644 --- a/procedures/retrieveEntityParents.sql +++ b/procedures/retrieveEntityParents.sql @@ -96,7 +96,6 @@ retrieveEntityParentsBody: BEGIN FROM archive_isa AS i JOIN entities AS e ON (i.parent = e.id) WHERE i.child = InternalEntityID - AND i.rpath = InternalEntityID AND i.child_iversion = IVersion AND i.direct IS TRUE ; diff --git a/procedures/retrieveEntityProperties.sql b/procedures/retrieveEntityProperties.sql index 7744ff9..775dd19 100644 --- a/procedures/retrieveEntityProperties.sql +++ b/procedures/retrieveEntityProperties.sql @@ -45,9 +45,9 @@ retrieveEntityPropertiesBody: BEGIN 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; diff --git a/procedures/setPassword.sql b/procedures/setPassword.sql deleted file mode 100644 index 33345d9..0000000 --- a/procedures/setPassword.sql +++ /dev/null @@ -1,37 +0,0 @@ -/* - * ** header v3.0 - * This file is a part of the CaosDB Project. - * - * Copyright (C) 2018 Research Group Biomedical Physics, - * Max-Planck-Institute for Dynamics and Self-Organization Göttingen - * - * 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/>. - * - * ** end header - */ - - -DROP PROCEDURE IF EXISTS db_5_0.setPassword; -delimiter // - -CREATE PROCEDURE db_5_0.setPassword(in EntityID INT UNSIGNED, in NewPassword VARCHAR(255)) -BEGIN - - - DELETE FROM passwords where entity_id=EntityID; - INSERT INTO passwords (entity_id, password) VALUES (EntityID, NewPassword); - -END; -// -delimiter ; diff --git a/procedures/updateEntity.sql b/procedures/updateEntity.sql index f98e479..07b6d75 100644 --- a/procedures/updateEntity.sql +++ b/procedures/updateEntity.sql @@ -48,20 +48,23 @@ BEGIN DECLARE ParentVersion VARBINARY(255) DEFAULT NULL; DECLARE Transaction VARBINARY(255) DEFAULT NULL; DECLARE OldIVersion INT UNSIGNED DEFAULT NULL; + DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL; + + SELECT internal_id INTO InternalEntityID from entity_ids WHERE id = EntityID; call entityACL(ACLID, ACL); IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN SELECT max(_iversion) INTO OldIVersion FROM entity_version - WHERE entity_id = EntityID; + WHERE entity_id = InternalEntityID; -- move old data to archives INSERT INTO archive_entities (id, description, role, acl, _iversion) SELECT e.id, e.description, e.role, e.acl, OldIVersion FROM entities AS e - WHERE e.id = EntityID; + WHERE e.id = InternalEntityID; INSERT INTO archive_data_type (domain_id, entity_id, property_id, datatype, _iversion) @@ -70,7 +73,7 @@ BEGIN FROM data_type AS e WHERE e.domain_id = 0 AND e.entity_id = 0 - AND e.property_id = EntityID; + AND e.property_id = InternalEntityID; INSERT INTO archive_collection_type (domain_id, entity_id, property_id, collection, _iversion) @@ -79,13 +82,13 @@ BEGIN FROM collection_type as e WHERE e.domain_id = 0 AND e.entity_id = 0 - AND e.property_id = EntityID; + AND e.property_id = InternalEntityID; SET Transaction = @SRID; SELECT e.version INTO ParentVersion FROM entity_version as e - WHERE e.entity_id = EntityID + WHERE e.entity_id = InternalEntityID AND e._iversion = OldIVersion; CALL insert_single_child_version( EntityID, Hash, Version, @@ -96,34 +99,34 @@ BEGIN SET e.description = EntityDescription, e.role=EntityRole, e.acl = ACLID - WHERE e.id = EntityID; + WHERE e.id = InternalEntityID; -- clean up primary name, because updateEntity might be called without a -- prior call to deleteEntityProperties. DELETE FROM name_data - WHERE domain_id = 0 AND entity_id = EntityID AND property_id = 20; + WHERE domain_id = 0 AND entity_id = InternalEntityID AND property_id = 20; IF EntityName IS NOT NULL THEN INSERT INTO name_data (domain_id, entity_id, property_id, value, status, pidx) - VALUES (0, EntityID, 20, EntityName, "FIX", 0); + VALUES (0, InternalEntityID, 20, EntityName, "FIX", 0); END IF; DELETE FROM data_type - WHERE domain_id=0 AND entity_id=0 AND property_id=EntityID; + WHERE domain_id=0 AND entity_id=0 AND property_id=InternalEntityID; DELETE FROM collection_type - WHERE domain_id=0 AND entity_id=0 AND property_id=EntityID; + WHERE domain_id=0 AND entity_id=0 AND property_id=InternalEntityID; IF Datatype IS NOT NULL THEN INSERT INTO data_type (domain_id, entity_id, property_id, datatype) - SELECT 0, 0, EntityID, + SELECT 0, 0, InternalEntityID, ( SELECT entity_id FROM name_data WHERE domain_id = 0 AND property_id = 20 AND value = Datatype LIMIT 1 ); IF Collection IS NOT NULL THEN INSERT INTO collection_type (domain_id, entity_id, property_id, collection) - SELECT 0, 0, EntityID, Collection; + SELECT 0, 0, InternalEntityID, Collection; END IF; END IF; diff --git a/utils/update_sql_procedures.sh b/utils/update_sql_procedures.sh index b9a9e7f..ad57f3c 100755 --- a/utils/update_sql_procedures.sh +++ b/utils/update_sql_procedures.sh @@ -37,8 +37,8 @@ fi source $UTILSPATH/load_settings.sh source $UTILSPATH/helpers.sh -echo -n "updating procedures ... " temp_proc_sql=$(mktemp --suffix=.sql) +echo -n "updating procedures (tmp file: $temp_proc_sql) ..." sed -e "s/db_5_0/$DATABASE_NAME/g" procedures/*.sql procedures/query/*.sql \ > "$temp_proc_sql" mysql_execute_file "$temp_proc_sql" -- GitLab