From 8b6d92dd92ecb2ce1508f7c89f0b87ef8f001ee2 Mon Sep 17 00:00:00 2001 From: Timm Fitschen <t.fitschen@indiscale.com> Date: Wed, 23 Nov 2022 09:37:40 +0100 Subject: [PATCH] Revert "Revert "WIP: introduce external ids"" This reverts commit d7d9e6f6e1c8a2f28d7c6a08a2011765d06e7a80. --- .../create_entity_ids_table.sql | 19 +++ patches/patch20221122-5.0.1/patch.sh | 41 +++++ procedures/retrieveDatatype.sql | 44 ------ procedures/retrieveEntity.sql | 37 +++-- procedures/retrieveEntityOverrides.sql | 79 +++++----- procedures/retrieveEntityParents.sql | 22 +-- procedures/retrieveEntityProperties.sql | 140 ++++++++++-------- procedures/retrieveGroup.sql | 24 --- procedures/retrieveSubentity.sql | 47 ------ 9 files changed, 212 insertions(+), 241 deletions(-) create mode 100644 patches/patch20221122-5.0.1/create_entity_ids_table.sql create mode 100755 patches/patch20221122-5.0.1/patch.sh delete mode 100644 procedures/retrieveDatatype.sql delete mode 100644 procedures/retrieveGroup.sql delete mode 100644 procedures/retrieveSubentity.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 new file mode 100644 index 0000000..b34d982 --- /dev/null +++ b/patches/patch20221122-5.0.1/create_entity_ids_table.sql @@ -0,0 +1,19 @@ +-- a little bit of house keeping +DROP PROCEDURE IF EXISTS retrieveSubEntity; +DROP PROCEDURE IF EXISTS retrieveDatatype; +DROP PROCEDURE IF EXISTS retrieveGroup; + +-- new entity_ids table +DROP TABLE IF EXISTS `entity_ids`; +CREATE TABLE `entity_ids` ( + `id` int(10) unsigned NOT NULL AUTO_INCREMENT, + `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`) +) ENGINE=InnoDB; + +-- fill all existing entities into the new entity_ids table. +INSERT INTO entity_ids (id, internal_id) SELECT id, id FROM entities WHERE id>0; +INSERT INTO entity_ids (id, internal_id) SELECT id, id FROM entities WHERE id=0; +UPDATE entity_ids SET id = internal_id; +-- ALTER TABLE entity_ids CHANGE id id int(10) unsigned NOT NULL AUTO_INCREMENT COMMENT 'External ID of an entity. This is the id of an entity which is exposed via the CaosDB API.'; diff --git a/patches/patch20221122-5.0.1/patch.sh b/patches/patch20221122-5.0.1/patch.sh new file mode 100755 index 0000000..07c8872 --- /dev/null +++ b/patches/patch20221122-5.0.1/patch.sh @@ -0,0 +1,41 @@ +#!/bin/bash +# +# This file is a part of the CaosDB Project. +# +# Copyright (C) 2022 IndiScale GmbH <info@indiscale.com> +# Copyright (C) 2022 Timm Fitschen <t.fitschen@indiscale.com> +# +# This program is free software: you can redistribute it and/or modify +# it under the terms of the GNU Affero General Public License as +# published by the Free Software Foundation, either version 3 of the +# License, or (at your option) any later version. +# +# This program is distributed in the hope that it will be useful, +# but WITHOUT ANY WARRANTY; without even the implied warranty of +# MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the +# GNU Affero General Public License for more details. +# +# You should have received a copy of the GNU Affero General Public License +# along with this program. If not, see <https://www.gnu.org/licenses/>. +# + +# Update mysql schema to version v5.0.0 +# Drop the 'rules' table. + +NEW_VERSION="v5.0.1" +OLD_VERSION="v5.0.0" + +if [ -z "$UTILSPATH" ]; then + UTILSPATH="../utils" +fi + +. $UTILSPATH/patch_header.sh $* + +check_version $OLD_VERSION + +mysql_execute_file $PATCH_DIR/create_entity_ids_table.sql + +update_version $NEW_VERSION + +success + diff --git a/procedures/retrieveDatatype.sql b/procedures/retrieveDatatype.sql deleted file mode 100644 index c0ed52c..0000000 --- a/procedures/retrieveDatatype.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.retrieveDatatype; -delimiter // -CREATE PROCEDURE db_5_0.retrieveDatatype(in DatatypeName VARCHAR(255)) -BEGIN - -Select e.id INTO @DatatypeID from entities e where e.name=DatatypeName AND e.role='DATATYPE' LIMIT 1; - -call retrieveEntity(@DatatypeID); - - - - -END; -// -delimiter ; diff --git a/procedures/retrieveEntity.sql b/procedures/retrieveEntity.sql index 42b283d..aa8a406 100644 --- a/procedures/retrieveEntity.sql +++ b/procedures/retrieveEntity.sql @@ -59,21 +59,29 @@ retrieveEntityBody: BEGIN DECLARE CollectionName VARCHAR(255) DEFAULT NULL; DECLARE IsHead BOOLEAN DEFAULT TRUE; DECLARE IVersion INT UNSIGNED DEFAULT NULL; + DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL; + SELECT internal_id INTO InternalEntityID from entity_ids WHERE id = EntityID; + + IF InternalEntityID IS NULL THEN + -- RETURN EARLY - Entity does not exist. + SELECT 0 FROM entities WHERE 0 = 1; + LEAVE retrieveEntityBody; + END IF; 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(EntityID); + SET Version = get_head_version(InternalEntityID); ELSEIF UPPER(LEFT(Version, 5)) = "HEAD~" THEN SET IsHead = FALSE; - SET Version = get_head_relative(EntityID, SUBSTR(Version, 6)); + SET Version = get_head_relative(InternalEntityID, SUBSTR(Version, 6)); ELSE - SELECT get_head_version(EntityID) = Version INTO IsHead; + SELECT get_head_version(InternalEntityID) = Version INTO IsHead; END IF; IF IsHead IS FALSE THEN - SET IVersion=get_iversion(EntityID, Version); + SET IVersion=get_iversion(InternalEntityID, Version); IF IVersion IS NULL THEN -- RETURN EARLY - Version does not exist. @@ -84,7 +92,7 @@ retrieveEntityBody: BEGIN SELECT path, size, HEX(hash) INTO FilePath, FileSize, FileHash FROM archive_files - WHERE file_id = EntityID + WHERE file_id = InternalEntityID AND _iversion = IVersion LIMIT 1; @@ -93,7 +101,7 @@ retrieveEntityBody: BEGIN FROM archive_data_type WHERE domain_id = 0 AND entity_id = 0 - AND property_id = EntityID + AND property_id = InternalEntityID AND _iversion = IVersion LIMIT 1; @@ -102,7 +110,7 @@ retrieveEntityBody: BEGIN FROM archive_collection_type WHERE domain_id = 0 AND entity_id = 0 - AND property_id = EntityID + AND property_id = InternalEntityID AND _iversion = IVersion LIMIT 1; @@ -119,10 +127,9 @@ retrieveEntityBody: BEGIN EntityID AS EntityID, ( SELECT value FROM archive_name_data WHERE domain_id = 0 - AND entity_ID = EntityID + AND entity_ID = InternalEntityID AND property_id = 20 AND _iversion = IVersion - -- LIMIT 1 -- TODO Remove this line if all tests pass. ) AS EntityName, e.description AS EntityDesc, e.role AS EntityRole, @@ -132,7 +139,7 @@ retrieveEntityBody: BEGIN (SELECT acl FROM entity_acl AS a WHERE a.id = e.acl) AS ACL, Version AS Version FROM archive_entities AS e - WHERE e.id = EntityID + WHERE e.id = InternalEntityID AND e._iversion = IVersion LIMIT 1; @@ -145,21 +152,21 @@ retrieveEntityBody: BEGIN SELECT path, size, hex(hash) INTO FilePath, FileSize, FileHash FROM files - WHERE file_id = EntityID + WHERE file_id = InternalEntityID LIMIT 1; SELECT datatype INTO DatatypeID FROM data_type WHERE domain_id=0 AND entity_id=0 - AND property_id=EntityID + AND property_id=InternalEntityID LIMIT 1; SELECT collection INTO CollectionName FROM collection_type WHERE domain_id=0 AND entity_id=0 - AND property_id=EntityID + AND property_id=InternalEntityID LIMIT 1; SELECT @@ -171,7 +178,7 @@ retrieveEntityBody: BEGIN EntityID AS EntityID, ( SELECT value FROM name_data WHERE domain_id = 0 - AND entity_ID = EntityID + AND entity_ID = InternalEntityID AND property_id = 20 LIMIT 1) AS EntityName, e.description AS EntityDesc, e.role AS EntityRole, @@ -180,7 +187,7 @@ retrieveEntityBody: BEGIN FileHash AS FileHash, (SELECT acl FROM entity_acl AS a WHERE a.id = e.acl) AS ACL, Version AS Version - FROM entities e WHERE id = EntityID LIMIT 1; + FROM entities e WHERE id = InternalEntityID LIMIT 1; END; // diff --git a/procedures/retrieveEntityOverrides.sql b/procedures/retrieveEntityOverrides.sql index 6964475..182cbc4 100644 --- a/procedures/retrieveEntityOverrides.sql +++ b/procedures/retrieveEntityOverrides.sql @@ -34,21 +34,26 @@ retrieveOverridesBody: BEGIN DECLARE IVersion INT UNSIGNED DEFAULT NULL; DECLARE IsHead BOOLEAN DEFAULT TRUE; + DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL; + DECLARE InternalDomainID INT UNSIGNED DEFAULT NULL; + + SELECT internal_id INTO InternalEntityID from entity_ids WHERE id = EntityID; + SELECT internal_id INTO InternalDomainID from entity_ids WHERE id = DomainID; IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN IF Version IS NOT NULL THEN - IF DomainID = 0 THEN - SELECT get_head_version(EntityID) = Version INTO IsHead; + IF InternalDomainID = 0 THEN + SELECT get_head_version(InternalEntityID) = Version INTO IsHead; ELSE - SELECT get_head_version(DomainID) = Version INTO IsHead; + SELECT get_head_version(InternalDomainID) = Version INTO IsHead; END IF; END IF; IF IsHead IS FALSE THEN SELECT e._iversion INTO IVersion FROM entity_version as e - WHERE ((e.entity_id = EntityID AND DomainID = 0) - OR (e.entity_id = DomainID)) + WHERE ((e.entity_id = InternalEntityID AND InternalDomainID = 0) + OR (e.entity_id = InternalDomainID)) AND e.version = Version; IF IVersion IS NULL THEN @@ -62,11 +67,11 @@ retrieveOverridesBody: BEGIN name AS name_override, NULL AS desc_override, NULL AS type_override, - entity_id, - property_id + EntityID AS entity_id, + ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS property_id FROM archive_name_overrides - WHERE domain_id = DomainID - AND entity_id = EntityID + WHERE domain_id = InternalDomainID + AND entity_id = InternalEntityID AND _iversion = IVersion UNION ALL @@ -77,11 +82,11 @@ retrieveOverridesBody: BEGIN NULL AS name_override, description AS desc_override, NULL AS type_override, - entity_id, - property_id + EntityID AS entity_id, + ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS property_id FROM archive_desc_overrides - WHERE domain_id = DomainID - AND entity_id = EntityID + WHERE domain_id = InternalDomainID + AND entity_id = InternalEntityID AND _iversion = IVersion UNION ALL @@ -96,11 +101,11 @@ retrieveOverridesBody: BEGIN AND entity_id = datatype AND property_id = 20 LIMIT 1), datatype) AS type_override, - entity_id, - property_id + EntityID AS entity_id, + ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS property_id FROM archive_data_type - WHERE domain_id = DomainID - AND entity_id = EntityID + WHERE domain_id = InternalDomainID + AND entity_id = InternalEntityID AND _iversion = IVersion UNION ALL @@ -111,11 +116,11 @@ retrieveOverridesBody: BEGIN NULL AS name_override, NULL AS desc_override, NULL AS type_override, - entity_id, - property_id + EntityID AS entity_id, + ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS property_id FROM archive_collection_type - WHERE domain_id = DomainID - AND entity_id = EntityID + WHERE domain_id = InternalDomainID + AND entity_id = InternalEntityID AND _iversion = IVersion; LEAVE retrieveOverridesBody; @@ -127,11 +132,11 @@ retrieveOverridesBody: BEGIN name AS name_override, NULL AS desc_override, NULL AS type_override, - entity_id, - property_id + EntityID AS entity_id, + ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS property_id FROM name_overrides - WHERE domain_id = DomainID - AND entity_id = EntityID + WHERE domain_id = InternalDomainID + AND entity_id = InternalEntityID UNION ALL @@ -140,11 +145,11 @@ retrieveOverridesBody: BEGIN NULL AS name_override, description AS desc_override, NULL AS type_override, - entity_id, - property_id + EntityID AS entity_id, + ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS property_id FROM desc_overrides - WHERE domain_id = DomainID - AND entity_id = EntityID + WHERE domain_id = InternalDomainID + AND entity_id = InternalEntityID UNION ALL @@ -156,11 +161,11 @@ retrieveOverridesBody: BEGIN WHERE domain_id = 0 AND entity_ID = datatype AND property_id = 20 LIMIT 1), datatype) AS type_override, - entity_id, - property_id + EntityID AS entity_id, + ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS property_id FROM data_type - WHERE domain_id = DomainID - AND entity_id = EntityID + WHERE domain_id = InternalDomainID + AND entity_id = InternalEntityID UNION ALL @@ -169,11 +174,11 @@ retrieveOverridesBody: BEGIN NULL AS name_override, NULL AS desc_override, NULL AS type_override, - entity_id, - property_id + EntityID AS entity_id, + ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS property_id FROM collection_type - WHERE domain_id = DomainID - AND entity_id = EntityID; + WHERE domain_id = InternalDomainID + AND entity_id = InternalEntityID; END; diff --git a/procedures/retrieveEntityParents.sql b/procedures/retrieveEntityParents.sql index 12b5c28..0ed5145 100644 --- a/procedures/retrieveEntityParents.sql +++ b/procedures/retrieveEntityParents.sql @@ -59,16 +59,19 @@ retrieveEntityParentsBody: 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 IF Version IS NOT NULL THEN - SELECT get_head_version(EntityID) = Version INTO IsHead; + SELECT get_head_version(InternalEntityID) = Version INTO IsHead; END IF; IF IsHead IS FALSE THEN 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 @@ -77,10 +80,10 @@ retrieveEntityParentsBody: BEGIN END IF; SELECT - i.parent AS ParentID, + ( SELECT id FROM entity_ids WHERE internal_id = i.parent) AS ParentID, ( SELECT value FROM name_data WHERE domain_id = 0 - AND entity_id = ParentID + AND entity_id = i.parent 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 @@ -92,7 +95,8 @@ retrieveEntityParentsBody: BEGIN (SELECT acl FROM entity_acl AS a WHERE a.id = e.acl) AS ACL FROM archive_isa AS i JOIN entities AS e ON (i.parent = e.id) - WHERE i.child = EntityID + WHERE i.child = InternalEntityID + AND i.rpath = InternalEntityID AND i.child_iversion = IVersion AND i.direct IS TRUE ; @@ -102,18 +106,18 @@ retrieveEntityParentsBody: BEGIN END IF; SELECT - i.parent AS ParentID, + ( SELECT id FROM entity_ids WHERE internal_id = i.parent) AS ParentID, ( SELECT value FROM name_data WHERE domain_id = 0 - AND entity_id = ParentID + AND entity_id = i.parent AND property_id = 20 ) AS ParentName, e.description AS ParentDescription, e.role AS ParentRole, (SELECT acl FROM entity_acl AS a WHERE a.id = e.acl) AS ACL FROM isa_cache AS i JOIN entities AS e ON (i.parent = e.id) - WHERE i.child = EntityID - AND i.rpath = EntityID; + WHERE i.child = InternalEntityID + AND i.rpath = InternalEntityID; END // diff --git a/procedures/retrieveEntityProperties.sql b/procedures/retrieveEntityProperties.sql index b8bc565..7744ff9 100644 --- a/procedures/retrieveEntityProperties.sql +++ b/procedures/retrieveEntityProperties.sql @@ -36,22 +36,26 @@ retrieveEntityPropertiesBody: BEGIN DECLARE IVersion INT UNSIGNED DEFAULT NULL; DECLARE IsHead BOOLEAN DEFAULT TRUE; + DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL; + DECLARE InternalDomainID INT UNSIGNED DEFAULT 0; + + SELECT internal_id INTO InternalEntityID from entity_ids WHERE id = EntityID; + SELECT internal_id INTO InternalDomainID from entity_ids WHERE id = DomainID; IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN IF Version IS NOT NULL THEN - IF DomainID = 0 THEN - SELECT get_head_version(EntityID) = Version INTO IsHead; + IF InternalDomainID = 0 THEN + SELECT get_head_version(InternalEntityID) = Version INTO IsHead; ELSE - SELECT get_head_version(DomainID) = Version INTO IsHead; + SELECT get_head_version(InternalDomainID) = Version INTO IsHead; END IF; - END IF; IF IsHead IS FALSE THEN SELECT e._iversion INTO IVersion FROM entity_version as e - WHERE ((e.entity_id = EntityID AND DomainID = 0) - OR (e.entity_id = DomainID)) + WHERE ((e.entity_id = InternalEntityID AND InternalDomainID = 0) + OR (e.entity_id = InternalDomainID)) AND e.version = Version; IF IVersion IS NULL THEN @@ -61,121 +65,124 @@ retrieveEntityPropertiesBody: BEGIN #-- double properties SELECT - property_id AS PropertyID, + ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID, value AS PropertyValue, status AS PropertyStatus, pidx AS PropertyIndex FROM archive_double_data - WHERE domain_id = DomainID - AND entity_id = EntityID + WHERE domain_id = InternalDomainID + AND entity_id = InternalEntityID AND _iversion = IVersion UNION ALL #-- integer properties SELECT - property_id AS PropertyID, + ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID, value AS PropertyValue, status AS PropertyStatus, pidx AS PropertyIndex FROM archive_integer_data - WHERE domain_id = DomainID - AND entity_id = EntityID + WHERE domain_id = InternalDomainID + AND entity_id = InternalEntityID AND _iversion = IVersion UNION ALL #-- date properties SELECT - property_id AS PropertyID, + ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID, CONCAT(value, '.NULL.NULL') AS PropertyValue, status AS PropertyStatus, pidx AS PropertyIndex FROM archive_date_data - WHERE domain_id = DomainID - AND entity_id = EntityID + WHERE domain_id = InternalDomainID + AND entity_id = InternalEntityID AND _iversion = IVersion UNION ALL #-- datetime properties SELECT - property_id AS PropertyID, + ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID, CONCAT(value, 'UTC', IF(value_ns IS NULL, '', value_ns)) AS PropertyValue, status AS PropertyStatus, pidx AS PropertyIndex FROM archive_datetime_data - WHERE domain_id = DomainID - AND entity_id = EntityID + WHERE domain_id = InternalDomainID + AND entity_id = InternalEntityID AND _iversion = IVersion UNION ALL #-- text properties SELECT - property_id AS PropertyID, + ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID, value AS PropertyValue, status AS PropertyStatus, pidx AS PropertyIndex FROM archive_text_data - WHERE domain_id = DomainID - AND entity_id = EntityID + WHERE domain_id = InternalDomainID + AND entity_id = InternalEntityID AND _iversion = IVersion UNION ALL #-- enum properties SELECT - property_id AS PropertyID, + ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID, value AS PropertyValue, status AS PropertyStatus, pidx AS PropertyIndex FROM archive_enum_data - WHERE domain_id = DomainID - AND entity_id = EntityID + WHERE domain_id = InternalDomainID + AND entity_id = InternalEntityID AND _iversion = IVersion UNION ALL #-- reference properties SELECT - property_id AS PropertyID, - IF(value_iversion IS NULL, value, + ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID, + IF(value_iversion IS NULL, + ( SELECT id FROM entity_ids WHERE internal_id = value ), -- make it "value@version" if necessary - CONCAT(value, "@", _get_version(value, value_iversion))) + CONCAT( + ( SELECT id FROM entity_ids WHERE internal_id = value ), + "@", _get_version(value, value_iversion))) AS PropertyValue, status AS PropertyStatus, pidx AS PropertyIndex FROM archive_reference_data - WHERE domain_id = DomainID - AND entity_id = EntityID + WHERE domain_id = InternalDomainID + AND entity_id = InternalEntityID AND _iversion = IVersion UNION ALL #-- null properties SELECT - property_id AS PropertyID, + ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID, NULL AS PropertyValue, status AS PropertyStatus, pidx AS PropertyIndex FROM archive_null_data - WHERE domain_id = DomainID - AND entity_id = EntityID + WHERE domain_id = InternalDomainID + AND entity_id = InternalEntityID AND _iversion = IVersion UNION ALL #-- name properties SELECT - property_id AS PropertyID, + ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID, value AS PropertyValue, status AS PropertyStatus, pidx AS PropertyIndex FROM archive_name_data - WHERE domain_id = DomainID - AND entity_id = EntityID + WHERE domain_id = InternalDomainID + AND entity_id = InternalEntityID AND property_id != 20 AND _iversion = IVersion; @@ -185,115 +192,118 @@ retrieveEntityPropertiesBody: BEGIN #-- double properties SELECT - property_id AS PropertyID, + ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID, value AS PropertyValue, status AS PropertyStatus, pidx AS PropertyIndex FROM double_data - WHERE domain_id = DomainID - AND entity_id = EntityID + WHERE domain_id = InternalDomainID + AND entity_id = InternalEntityID UNION ALL #-- integer properties SELECT - property_id AS PropertyID, + ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID, value AS PropertyValue, status AS PropertyStatus, pidx AS PropertyIndex FROM integer_data - WHERE domain_id = DomainID - AND entity_id = EntityID + WHERE domain_id = InternalDomainID + AND entity_id = InternalEntityID UNION ALL #-- date properties SELECT - property_id AS PropertyID, + ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID, CONCAT(value, '.NULL.NULL') AS PropertyValue, status AS PropertyStatus, pidx AS PropertyIndex FROM date_data - WHERE domain_id = DomainID - AND entity_id = EntityID + WHERE domain_id = InternalDomainID + AND entity_id = InternalEntityID UNION ALL #-- datetime properties SELECT - property_id AS PropertyID, + ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID, CONCAT(value, 'UTC', IF(value_ns IS NULL, '', value_ns)) AS PropertyValue, status AS PropertyStatus, pidx AS PropertyIndex FROM datetime_data - WHERE domain_id = DomainID - AND entity_id = EntityID + WHERE domain_id = InternalDomainID + AND entity_id = InternalEntityID UNION ALL #-- text properties SELECT - property_id AS PropertyID, + ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID, value AS PropertyValue, status AS PropertyStatus, pidx AS PropertyIndex FROM text_data - WHERE domain_id = DomainID - AND entity_id = EntityID + WHERE domain_id = InternalDomainID + AND entity_id = InternalEntityID UNION ALL #-- enum properties SELECT - property_id AS PropertyID, + ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID, value AS PropertyValue, status AS PropertyStatus, pidx AS PropertyIndex FROM enum_data - WHERE domain_id = DomainID - AND entity_id = EntityID + WHERE domain_id = InternalDomainID + AND entity_id = InternalEntityID UNION ALL #-- reference properties SELECT - property_id AS PropertyID, - IF(value_iversion IS NULL, value, - CONCAT(value, "@", _get_version(value, value_iversion))) + ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID, + IF(value_iversion IS NULL, + ( SELECT id FROM entity_ids WHERE internal_id = value ), + -- make it "value@version" if necessary + CONCAT( + ( SELECT id FROM entity_ids WHERE internal_id = value ), + "@", _get_version(value, value_iversion))) AS PropertyValue, status AS PropertyStatus, pidx AS PropertyIndex FROM reference_data - WHERE domain_id = DomainID - AND entity_id = EntityID + WHERE domain_id = InternalDomainID + AND entity_id = InternalEntityID UNION ALL #-- null properties SELECT - property_id AS PropertyID, + ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID, NULL AS PropertyValue, status AS PropertyStatus, pidx AS PropertyIndex FROM null_data - WHERE domain_id = DomainID - AND entity_id = EntityID + WHERE domain_id = InternalDomainID + AND entity_id = InternalEntityID UNION ALL #-- name properties SELECT - property_id AS PropertyID, + ( SELECT id FROM entity_ids WHERE internal_id = property_id ) AS PropertyID, value AS PropertyValue, status AS PropertyStatus, pidx AS PropertyIndex FROM name_data - WHERE domain_id = DomainID - AND entity_id = EntityID + WHERE domain_id = InternalDomainID + AND entity_id = InternalEntityID AND property_id != 20; - END; // diff --git a/procedures/retrieveGroup.sql b/procedures/retrieveGroup.sql deleted file mode 100644 index 7db1b89..0000000 --- a/procedures/retrieveGroup.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 - */ - -Drop Procedure if exists db_5_0.retrieveGroup; diff --git a/procedures/retrieveSubentity.sql b/procedures/retrieveSubentity.sql deleted file mode 100644 index 406d668..0000000 --- a/procedures/retrieveSubentity.sql +++ /dev/null @@ -1,47 +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 - */ -DELIMITER // -DROP PROCEDURE IF EXISTS db_5_0.retrieveSubEntity // -/** -CREATE PROCEDURE db_5_0.retrieveSubEntity(in EntityID INT UNSIGNED, in DomainID INT UNSIGNED) -BEGIN - DECLARE FilePath VARCHAR(255) DEFAULT NULL; - DECLARE FileSize VARCHAR(255) DEFAULT NULL; - DECLARE FileHash VARCHAR(255) DEFAULT NULL; - - Select path, size, hex(hash) into FilePath, FileSize, FileHash from files where file_id = EntityID LIMIT 1; - Select DomainID as DomainID, - EntityID as EntityID, - e.name as EntityName, - e.description as EntityDesc, - e.role as EntityRole, - FileSize as FileSize, - FilePath as FilePath, - FileHash as FileHash - from entities e where id = EntityID LIMIT 1; - -END; -// - -**/ -DELIMITER ; -- GitLab