From f9ecefefab11cef66e304da308f30a11bf6e0c8b Mon Sep 17 00:00:00 2001 From: Timm Fitschen <t.fitschen@indiscale.com> Date: Mon, 2 Oct 2023 14:21:34 +0200 Subject: [PATCH] WIP: String IDs --- procedures/deleteEntity.sql | 12 +- procedures/deleteEntityProperties.sql | 12 +- procedures/deleteIsaCache.sql | 5 +- procedures/entityVersioning.sql | 125 ++++++-------------- procedures/getDependentEntities.sql | 21 +++- procedures/getFileIdByPath.sql | 20 +++- procedures/getIdByName.sql | 38 +++++- procedures/insertEntity.sql | 11 +- procedures/insertEntityDataType.sql | 44 ++++++- procedures/insertEntityProperty.sql | 45 +++++-- procedures/insertFile.sql | 36 +++++- procedures/insertIsaCache.sql | 14 +-- procedures/isSubtype.sql | 22 +++- procedures/overrideName.sql | 100 +++++++--------- procedures/query/applyIDFilter.sql | 40 +++++-- procedures/query/applyPOV.sql | 3 - procedures/query/applyTransactionFilter.sql | 79 +++++++++---- procedures/query/initBackReference.sql | 42 +++++-- procedures/query/initPOV.sql | 66 ++++++++--- procedures/query/initSubEntity.sql | 24 +++- procedures/registerSubdomain.sql | 8 -- procedures/retrieveChildren.sql | 12 +- procedures/retrieveEntity.sql | 13 +- procedures/retrieveEntityOverrides.sql | 44 +++++-- procedures/retrieveEntityParents.sql | 50 ++++---- procedures/retrieveEntityProperties.sql | 44 +++++-- procedures/setFileProperties.sql | 73 ++++++++++++ procedures/updateEntity.sql | 9 +- 28 files changed, 676 insertions(+), 336 deletions(-) create mode 100644 procedures/setFileProperties.sql diff --git a/procedures/deleteEntity.sql b/procedures/deleteEntity.sql index e3c3dab..f8b026d 100644 --- a/procedures/deleteEntity.sql +++ b/procedures/deleteEntity.sql @@ -1,10 +1,10 @@ /* - * ** 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 - * Copyright (C) 2020 IndiScale GmbH <info@indiscale.com> + * Copyright (C) 2020-2023 IndiScale GmbH <info@indiscale.com> + * Copyright (C) 2023 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 @@ -18,8 +18,6 @@ * * 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 */ /* Delete a (sparse) Entity from the database. @@ -31,14 +29,14 @@ have been deleted before. This can be done for example with the Parameters ========== -EntityID : UNSIGNED -The ID of the Entity. +EntityID : VARCHAR(255) + The ID of the Entity. */ DROP PROCEDURE IF EXISTS db_5_0.deleteEntity; delimiter // -CREATE PROCEDURE db_5_0.deleteEntity(in EntityID INT UNSIGNED) +CREATE PROCEDURE db_5_0.deleteEntity(in EntityID VARCHAR(255)) BEGIN DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL; diff --git a/procedures/deleteEntityProperties.sql b/procedures/deleteEntityProperties.sql index 2875ccb..cc9676f 100644 --- a/procedures/deleteEntityProperties.sql +++ b/procedures/deleteEntityProperties.sql @@ -26,7 +26,17 @@ DROP PROCEDURE IF EXISTS db_5_0.deleteEntityProperties; delimiter // -CREATE PROCEDURE db_5_0.deleteEntityProperties(in EntityID INT UNSIGNED) +/* + * Delete all properties of an entity (i.e. remove them from the *_data tables + * and the isa_cache table). + * + * Parameters + * ========== + * + * EntityID : VARCHAR(255) + * The entity's id. + */ +CREATE PROCEDURE db_5_0.deleteEntityProperties(in EntityID VARCHAR(255)) BEGIN DECLARE IVersion INT UNSIGNED DEFAULT NULL; DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL; diff --git a/procedures/deleteIsaCache.sql b/procedures/deleteIsaCache.sql index 7e8a1a1..a792c20 100644 --- a/procedures/deleteIsaCache.sql +++ b/procedures/deleteIsaCache.sql @@ -1,5 +1,4 @@ /* - * ** header v3.0 * This file is a part of the CaosDB Project. * * Copyright (C) 2018 Research Group Biomedical Physics, @@ -19,8 +18,6 @@ * * 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 */ SET GLOBAL log_bin_trust_function_creators = 1; @@ -39,7 +36,7 @@ Parameters ========== InternalEntityID : UNSIGNED -Child entity for which all parental relations should be deleted. + Child entity for which all parental relations should be deleted. */ CREATE PROCEDURE db_5_0.deleteIsa(IN InternalEntityID INT UNSIGNED) BEGIN diff --git a/procedures/entityVersioning.sql b/procedures/entityVersioning.sql index 22274f2..8436929 100644 --- a/procedures/entityVersioning.sql +++ b/procedures/entityVersioning.sql @@ -27,18 +27,18 @@ DROP PROCEDURE IF EXISTS db_5_0.insert_single_child_version // * * Parameters * ---------- - * InternalEntityID - * The ID of the versioned entity. - * Hash + * InternalEntityID : INT UNSIGNED + * The internal ID of the versioned entity. + * Hash : VARBINARY(255) * A hash of the entity. This is currently not implemented properly and only * there for future use. - * Version + * Version : VARBINARY(255) * The new version ID of the entity, must be produced by the caller. Must be unique for each * EntityID. - * Parent + * Parent : VARBINARY(255) * The version ID of the primary parent (i.e. predecessor). May be NULL; but if given, it must * exist. - * Transaction + * Transaction : VARBINARY(255) * The transaction ID which created this entity version (by inserting * or updating an entity). */ @@ -87,16 +87,18 @@ END; DROP PROCEDURE IF EXISTS db_5_0.delete_all_entity_versions // +/* THIS PROCEDURE HAS NEVER BEEN USED (outside of the tests). Reactivate when + * versioning's FORGET is being implemented. */ /** * Remove all records in the entity_version table for the given entity. * * Parameters * ---------- - * EntityID + * EntityID : VARCHAR(255) * The id of the versioned entity. */ -CREATE PROCEDURE db_5_0.delete_all_entity_versions( - in EntityID INT UNSIGNED) +/* CREATE PROCEDURE db_5_0.delete_all_entity_versions( + in EntityID VARCHAR(255)) BEGIN DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL; @@ -106,6 +108,7 @@ BEGIN END; // +*/ DROP FUNCTION IF EXISTS db_5_0.get_iversion // @@ -114,9 +117,9 @@ DROP FUNCTION IF EXISTS db_5_0.get_iversion // * * Parameters * ---------- - * InternalEntityID - * The entity's id. - * Version + * InternalEntityID : INT UNSIGNED + * The entity's internal id. + * Version : VARBINARY(255) * The (official, externally used) version id. * * Returns @@ -146,9 +149,9 @@ DROP FUNCTION IF EXISTS db_5_0.get_primary_parent_version // * * Parameters * ---------- - * EntityID + * EntityID : VARCHAR(255) * The entity id. - * Version + * Version : VARBINARY(255) * The version id. * * Returns @@ -156,7 +159,7 @@ DROP FUNCTION IF EXISTS db_5_0.get_primary_parent_version // * The id of the given version's primary parent version. */ CREATE FUNCTION db_5_0.get_primary_parent_version( - EntityID INT UNSIGNED, + EntityID VARCHAR(255), Version VARBINARY(255)) RETURNS VARBINARY(255) READS SQL DATA @@ -184,9 +187,9 @@ DROP FUNCTION IF EXISTS db_5_0.get_version_timestamp // * * Parameters * ---------- - * EntityID + * EntityID : VARCHAR(255) * The entity id. - * Version + * Version : VARBINARY(255) * The version id. * * Returns @@ -195,7 +198,7 @@ DROP FUNCTION IF EXISTS db_5_0.get_version_timestamp // * Note that the dot `.` here is not necessarily a decimal separator. */ CREATE FUNCTION db_5_0.get_version_timestamp( - EntityID INT UNSIGNED, + EntityID VARCHAR(255), Version VARBINARY(255)) RETURNS VARCHAR(255) READS SQL DATA @@ -221,7 +224,7 @@ DROP FUNCTION IF EXISTS db_5_0.get_head_version // * * Parameters * ---------- - * EntityID + * EntityID : VARCHAR(255) * The entity id. * * Returns @@ -229,7 +232,7 @@ DROP FUNCTION IF EXISTS db_5_0.get_head_version // * The version id of the HEAD. */ CREATE FUNCTION db_5_0.get_head_version( - EntityID INT UNSIGNED) + EntityID VARCHAR(255)) RETURNS VARBINARY(255) READS SQL DATA BEGIN @@ -244,8 +247,8 @@ DROP FUNCTION IF EXISTS db_5_0._get_head_iversion // * * Parameters * ---------- - * InternalEntityID - * The entity id. + * InternalEntityID : INT UNSIGNED + * The entity's internal id. * * Returns * ------- @@ -278,9 +281,9 @@ DROP FUNCTION IF EXISTS db_5_0.get_head_relative // * * Parameters * ---------- - * EntityID + * EntityID : VARCHAR(255) * The entity id. - * Offset + * Offset : INT UNSIGNED * Distance in the sequence of primary parents of the entity. E.g. `0` is the * HEAD itself. `1` is the primary parent of the HEAD. `2` is the primary * parent of the primary parent of the HEAD, and so on. @@ -290,14 +293,14 @@ DROP FUNCTION IF EXISTS db_5_0.get_head_relative // * The version id of the HEAD. */ CREATE FUNCTION db_5_0.get_head_relative( - EntityID INT UNSIGNED, + EntityID VARCHAR(255), Offset INT UNSIGNED) RETURNS VARBINARY(255) READS SQL DATA BEGIN DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL; - SELECT temp.internal_id INTO InternalEntityID FROM (SELECT internal_id AS internal_id FROM entity_ids WHERE id = EntityID UNION SELECT EntityID AS internal_id) AS temp LIMIT 1; + 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 @@ -319,14 +322,14 @@ DROP FUNCTION IF EXISTS db_5_0._get_version // * * Parameters * ---------- - * InternalEntityID - * The entity id. + * InternalEntityID : INT UNSIGNED + * The entity's internal id. * IVersion * Internal version id (integer). * * Returns * ------- - * The version id. + * The (external) version id. */ CREATE FUNCTION db_5_0._get_version( InternalEntityID INT UNSIGNED, @@ -350,7 +353,7 @@ DROP PROCEDURE IF EXISTS db_5_0.get_version_history // * * Parameters * ---------- - * EntityID + * EntityID : VARCHAR(255) * The entity id. * * Selects @@ -359,7 +362,7 @@ DROP PROCEDURE IF EXISTS db_5_0.get_version_history // * child_realm). `child` and `parent` are version IDs. */ CREATE PROCEDURE db_5_0.get_version_history( - in EntityID INT UNSIGNED) + in EntityID VARCHAR(255)) BEGIN DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL; @@ -431,60 +434,6 @@ BEGIN END // - -DROP PROCEDURE IF EXISTS setFileProperties // -/** - * Insert/Update file properties. - * - * If ENTITY_VERSIONING is enabled the old file properties are moved to - * `archive_files`. - * - * Parameters - * ---------- - * EntityID - * The file's id. - * FilePath - * Path of the file in the internal file system. If NULL, an existing file - * entity is simply deleted. - * FileSize - * Size of the file in bytes. - * FileHash - * A Sha512 Hash of the file. - */ -CREATE PROCEDURE setFileProperties ( - in EntityID INT UNSIGNED, - in FilePath TEXT, - in FileSize BIGINT UNSIGNED, - 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 = 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 = InternalEntityID; - END IF; - - DELETE FROM files WHERE file_id = InternalEntityID; - - IF FilePath IS NOT NULL THEN - INSERT INTO files (file_id, path, size, hash) - VALUES (InternalEntityID, FilePath, FileSize, unhex(FileHash)); - END IF; - -END // - - DROP PROCEDURE IF EXISTS retrieveQueryTemplateDef // /** @@ -492,9 +441,9 @@ DROP PROCEDURE IF EXISTS retrieveQueryTemplateDef // * * Parameters * ---------- - * EntityID + * EntityID : VARCHAR(255) * The QueryTemplate's id. - * Version + * Version : VARBINARY(255) * The QueryTemplate's version's id. * * Returns @@ -503,7 +452,7 @@ DROP PROCEDURE IF EXISTS retrieveQueryTemplateDef // * QueryTemplate. */ CREATE PROCEDURE retrieveQueryTemplateDef ( - in EntityID INT UNSIGNED, + in EntityID VARCHAR(255), in Version VARBINARY(255)) retrieveQueryTemplateDefBody: BEGIN diff --git a/procedures/getDependentEntities.sql b/procedures/getDependentEntities.sql index 81c0e38..980a0d9 100644 --- a/procedures/getDependentEntities.sql +++ b/procedures/getDependentEntities.sql @@ -26,7 +26,24 @@ DROP PROCEDURE IF EXISTS db_5_0.getDependentEntities; delimiter // -CREATE PROCEDURE db_5_0.getDependentEntities(in EntityID INT UNSIGNED) +/* + * Return all entities which either reference the given entity, use the given * + * reference as data type, or are direct children of the given entity. + * + * This function is being used to make sure that no entity can be deleted which + * is still needed by others. + * + * Parameters + * ---------- + * EntityID : VARCHAR(255) + * The entity id. + * + * Selects + * ------- + * EntityID : VARCHAR(255) + * + */ +CREATE PROCEDURE db_5_0.getDependentEntities(in EntityID VARCHAR(255)) BEGIN DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL; @@ -68,6 +85,8 @@ BEGIN 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; + -- TODO activate after `retrieveChildren` has been removed. + -- INSERT IGNORE INTO refering (id) SELECT child FROM isa_cache WHERE parent = InternalParentID AND rpath=child; 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; diff --git a/procedures/getFileIdByPath.sql b/procedures/getFileIdByPath.sql index 97634b1..07e7b8b 100644 --- a/procedures/getFileIdByPath.sql +++ b/procedures/getFileIdByPath.sql @@ -1,9 +1,10 @@ /* - * ** 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 + * Copyright (C) 2023 IndiScale GmbH <info@indiscale.com> + * Copyright (C) 2023 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 @@ -17,13 +18,24 @@ * * 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.getFileIdByPath; Delimiter // -Create Procedure db_5_0.getFileIdByPath (in FilePath VARCHAR(255)) + +/* + * Return a file's id for a given path or nothing if the path is unknown. + * + * Parameters + * ---------- + * FilePath : TEXT + * The file's path. + * + * Returns + * ------- + * EntityID : VARCHAR(255) + */ +Create Procedure db_5_0.getFileIdByPath (in FilePath TEXT) BEGIN 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; diff --git a/procedures/getIdByName.sql b/procedures/getIdByName.sql index 0d1208f..781594e 100644 --- a/procedures/getIdByName.sql +++ b/procedures/getIdByName.sql @@ -1,8 +1,44 @@ +/* + * This file is a part of the CaosDB Project. + * + * Copyright (C) 2023 IndiScale GmbH <info@indiscale.com> + * Copyright (C) 2023 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/>. + */ 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)) +/* + * Return the Entity id(s) for a given name. Optionally, filter by role and set + * a limit. + * + * Parameters + * ---------- + * Name : VARCHAR(255) + * The entity's name. + * Role : VARCHAR(255) + * E.g. RecordType, Record, Property,... + * Lmt : INT UNSIGNED + * Limit the number of returned entity ids. + * + * Returns + * ------- + * EntityID : VARCHAR(255) + */ +CREATE PROCEDURE db_5_0.getIdByName(in Name VARCHAR(255), in Role VARCHAR(255), in Lmt INT UNSIGNED) 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 = ?"; diff --git a/procedures/insertEntity.sql b/procedures/insertEntity.sql index bbd5411..54b89ba 100644 --- a/procedures/insertEntity.sql +++ b/procedures/insertEntity.sql @@ -1,11 +1,10 @@ /* - * ** 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 * Copyright (C) 2020 - 2022 IndiScale GmbH <info@indiscale.com> - * Copyright (C) 2020 - 2022 Timm Fitschen <t.fitschen@indiscale + * 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 @@ -19,8 +18,6 @@ * * 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 */ @@ -31,12 +28,14 @@ delimiter // Parameters ========== +EntityID : VARCHAR(255) + The entity id. EntityName : VARCHAR(255) EntityDesc : TEXT EntityRole : VARCHAR(255) -Currently one of 'RECORDTYPE', 'RECORD', 'FILE', 'DOMAIN', 'PROPERTY', +Currently one of 'RECORDTYPE', 'RECORD', 'FILE', 'PROPERTY', 'DATATYPE', 'ROLE', 'QUERYTEMPLATE' ACL : VARBINARY(65525) @@ -46,7 +45,7 @@ Select (Version) */ -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)) +CREATE PROCEDURE db_5_0.insertEntity(in EntityID VARCHAR(255), in EntityName VARCHAR(255), in EntityDesc TEXT, in EntityRole VARCHAR(255), in ACL VARBINARY(65525)) BEGIN DECLARE NewACLID INT UNSIGNED DEFAULT NULL; DECLARE Hash VARBINARY(255) DEFAULT NULL; diff --git a/procedures/insertEntityDataType.sql b/procedures/insertEntityDataType.sql index 9836f9f..78df168 100644 --- a/procedures/insertEntityDataType.sql +++ b/procedures/insertEntityDataType.sql @@ -1,9 +1,37 @@ - +/* + * This file is a part of the CaosDB Project. + * + * Copyright (C) 2023 IndiScale GmbH <info@indiscale.com> + * Copyright (C) 2023 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/>. + */ DROP PROCEDURE IF EXISTS db_5_0.insertEntityDataType; DELIMITER // -CREATE PROCEDURE db_5_0.insertEntityDataType(in PropertyID INT UNSIGNED, in DataType VARCHAR(255)) +/* + * Insert the (default) datatype of a property. + * + * Parameters + * ---------- + * PropertyID : VARCHAR(255) + * The property id. + * DataType : VARCHAR(255) + * The data type, e.g. "DOUBLE", "Person" + */ +CREATE PROCEDURE db_5_0.insertEntityDataType(in PropertyID VARCHAR(255), in DataType VARCHAR(255)) BEGIN DECLARE InternalPropertyID INT UNSIGNED DEFAULT NULL; @@ -20,7 +48,17 @@ DELIMITER ; DROP PROCEDURE IF EXISTS db_5_0.insertEntityCollection; DELIMITER // -CREATE PROCEDURE db_5_0.insertEntityCollection(in PropertyID INT UNSIGNED, in Collection VARCHAR(255)) +/* + * Insert the (default) collection type of a property. + * + * Parameters + * ---------- + * PropertyID : VARCHAR(255) + * The property id. + * Collection : VARCHAR(255) + * The collection, e.g. "LIST" + */ +CREATE PROCEDURE db_5_0.insertEntityCollection(in PropertyID VARCHAR(255), in Collection VARCHAR(255)) BEGIN DECLARE InternalPropertyID INT UNSIGNED DEFAULT NULL; diff --git a/procedures/insertEntityProperty.sql b/procedures/insertEntityProperty.sql index f3d56e3..e0bf40a 100644 --- a/procedures/insertEntityProperty.sql +++ b/procedures/insertEntityProperty.sql @@ -1,11 +1,10 @@ /* - * ** 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 - * Copyright (C) 2020 IndiScale GmbH <info@indiscale.com> - * Copyright (C) 2020 Timm Fitschen <t.fitschen@indiscale + * Copyright (C) 2020,2023 IndiScale GmbH <info@indiscale.com> + * Copyright (C) 2020,2023 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 @@ -19,16 +18,46 @@ * * 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.insertEntityProperty; delimiter // + + +/* + * Insert the property of an entity (level 1 and 2, only one *_data table entry at a time). + * + * Parameters + * ---------- + * DomainID : VARCHAR(255) + * The domain id (0 or the entity's id for level-2-data) + * EntityID : VARCHAR(255) + * The entity id (or the property's id for level-2-data) + * PropertyID : VARCHAR(255) + * The property id (or the sub-property's id for level-2-data) + * Datatable : VARCHAR(255) + * Name of the *_data table, e.g. 'double_data'. + * PropertyValue : TEXT + * The property's value + * PropertyUnitSig : BIGINT + * The unit signature. + * PropertyStatus : VARCHAR(255) + * E.g. OBLIGATORY, FIX,... + * NameOverride : VARCHAR(255) + * The overridden name + * DescOverride : TEXT + * The overridden description + * DatatypeOverride : INT UNSIGNED + * The overridden datatype + * Collection : VARCHAR(255) + * The overridden collection (only if DatatypeOverride is present). + * PropertyIndex : INT UNSIGNED + * The property's index (for ordering of properties and values). + */ CREATE PROCEDURE db_5_0.insertEntityProperty( - in DomainID INT UNSIGNED, - in EntityID INT UNSIGNED, - in PropertyID INT UNSIGNED, + in DomainID VARCHAR(255), + in EntityID VARCHAR(255), + in PropertyID VARCHAR(255), in Datatable VARCHAR(255), in PropertyValue TEXT, in PropertyUnitSig BIGINT, diff --git a/procedures/insertFile.sql b/procedures/insertFile.sql index 153b141..c7e66cd 100644 --- a/procedures/insertFile.sql +++ b/procedures/insertFile.sql @@ -1,8 +1,42 @@ +/* + * This file is a part of the CaosDB Project. + * + * Copyright (C) 2023 IndiScale GmbH <info@indiscale.com> + * Copyright (C) 2023 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/>. + */ 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)) +/* + * Insert the file properties of a File entity. + * + * Parameters + * ---------- + * EntityID : VARCHAR(255) + * The file's id. + * Hash : VARCHAR(255) + * A Sha512 Hash of the file. + * FilePath : TEXT + * Path of the file in the internal file system. If NULL, an existing file + * entity is simply deleted. + * FileSize : BIGINT UNSIGNED + * Size of the file in bytes. + */ +CREATE PROCEDURE db_5_0.insertFile(in EntityID VARCHAR(255), in Hash VARCHAR(255), in FileSize BIGINT UNSIGNED, in FilePath TEXT) BEGIN DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL; SELECT internal_id INTO InternalEntityID FROM entity_ids WHERE id=EntityID; diff --git a/procedures/insertIsaCache.sql b/procedures/insertIsaCache.sql index d1d06e8..f7ed7d8 100644 --- a/procedures/insertIsaCache.sql +++ b/procedures/insertIsaCache.sql @@ -32,14 +32,14 @@ DELIMITER // * * Parameters * ========== - * - * ChildID : UNSIGNED - * The child entity - * - * ParentID : UNSIGNED - * The parent entity + * + * ChildID : VARCHAR(255) + * The child entity. + * + * ParentID : VARCHAR(255) + * The parent entity. */ -CREATE PROCEDURE db_5_0.insertIsa(IN ChildID INT UNSIGNED, IN ParentID INT UNSIGNED) +CREATE PROCEDURE db_5_0.insertIsa(IN ChildID VARCHAR(255), IN ParentID VARCHAR(255)) insert_is_a_proc: BEGIN DECLARE c INT UNSIGNED DEFAULT NULL; diff --git a/procedures/isSubtype.sql b/procedures/isSubtype.sql index d421cfd..3a25612 100644 --- a/procedures/isSubtype.sql +++ b/procedures/isSubtype.sql @@ -1,9 +1,10 @@ /* - * ** 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 + * Copyright (C) 2023 IndiScale GmbH <info@indiscale.com> + * Copyright (C) 2023 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 @@ -17,15 +18,28 @@ * * 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.isSubtype; delimiter // -CREATE PROCEDURE db_5_0.isSubtype(in ChildID INT UNSIGNED, in ParentID INT UNSIGNED) +/* + * Return TRUE if the given Child is indeed a (direct or indirect) child of the + * given Parent. + * + * Parameters + * ---------- + * ChildID : VARCHAR(255) + * The entity id of the child. + * ParentID : VARCHAR(255) + * The entity id of the parent. + * + * Returns + * ------- + * ISA : BOOLEAN + */ +CREATE PROCEDURE db_5_0.isSubtype(in ChildID VARCHAR(255), in ParentID VARCHAR(255)) BEGIN DECLARE c INT UNSIGNED DEFAULT NULL; DECLARE p INT UNSIGNED DEFAULT NULL; diff --git a/procedures/overrideName.sql b/procedures/overrideName.sql index c518842..b651c49 100644 --- a/procedures/overrideName.sql +++ b/procedures/overrideName.sql @@ -1,9 +1,10 @@ /* - * ** 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 + * Copyright (C) 2023 IndiScale GmbH <info@indiscale.com> + * Copyright (C) 2023 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 @@ -17,8 +18,6 @@ * * 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.overrideName; @@ -26,70 +25,61 @@ DROP PROCEDURE IF EXISTS db_5_0.overrideDesc; DROP PROCEDURE IF EXISTS db_5_0.overrideType; DELIMITER // -/* 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) -*/ +/* + *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 (InternalDomainID, InternalEntityID, InternalPropertyID, Name); + INSERT INTO name_overrides (domain_id, entity_id, property_id, name) VALUES (InternalDomainID, InternalEntityID, InternalPropertyID, Name); END; // -/* 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 -*/ +/* + * 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 (InternalDomainID, InternalEntityID, InternalPropertyID, Description); + INSERT INTO desc_overrides (domain_id, entity_id, property_id, description) VALUES (InternalDomainID, InternalEntityID, InternalPropertyID, Description); END; // -/* 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. -*/ +/* + * 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 (InternalDomainID, InternalEntityID, InternalPropertyID, InternalDataTypeID); + INSERT INTO data_type (domain_id, entity_id, property_id, datatype) VALUES (InternalDomainID, InternalEntityID, InternalPropertyID, InternalDataTypeID); END; // diff --git a/procedures/query/applyIDFilter.sql b/procedures/query/applyIDFilter.sql index 13beb63..3b3a00a 100644 --- a/procedures/query/applyIDFilter.sql +++ b/procedures/query/applyIDFilter.sql @@ -1,9 +1,10 @@ /* - * ** 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 + * Copyright (C) 2023 IndiScale GmbH <info@indiscale.com> + * Copyright (C) 2023 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 @@ -17,8 +18,6 @@ * * 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.applyIDFilter; @@ -32,9 +31,26 @@ DELIMITER // * * The `versioned` flag currently only has the effect that an `_iversion` column is also copied to * the target. + * + * Parameters + * ---------- + * sourceSet : VARCHAR(255) + * The name of the table from where we start. + * targetSet : VARCHAR(255) + * The name of the table where we collect all the "good" ids (or NULL or same as sourceSet). + * o : CHAR(2) + * The operator used for filtering, e.g. '=', '!=', '>', ... + * EntityID : VARCHAR(255) + * An entity id, existing or non-existing, which we use to compare the + * existing entities to using the operator. + * agg : CHAR(3) + * An aggregate function, e.g. 'max' or 'min'. This only makes sense for number-based ids. + * versioned : BOOLEAN + * The filter belongs to a version-aware query (e.g. FIND ANY VERSION OF + * ...) and hence the sourceSet and targetSet have an `_iversion` column. */ CREATE PROCEDURE db_5_0.applyIDFilter(in sourceSet VARCHAR(255), in targetSet VARCHAR(255), - in o CHAR(2), in vInt BIGINT, in agg CHAR(3), in versioned BOOLEAN) + in o CHAR(2), in EntityID VARCHAR(255), in agg CHAR(3), in versioned BOOLEAN) IDFILTER_LABEL: BEGIN DECLARE data VARCHAR(20000) DEFAULT NULL; DECLARE aggVal VARCHAR(255) DEFAULT NULL; @@ -63,11 +79,11 @@ IF targetSet IS NULL OR targetSet = sourceSet THEN "DELETE FROM `", sourceSet, "` WHERE ", - IF(o IS NULL OR vInt IS NULL, + IF(o IS NULL OR EntityID IS NULL, "1=1", CONCAT("NOT EXISTS (SELECT 1 FROM entity_ids AS eids WHERE eids.id ", o, - vInt, + EntityID, " AND eids.internal_id = `", sourceSet, "`.id)" @@ -82,22 +98,22 @@ ELSEIF versioned AND sourceSet = "entities" THEN "INSERT IGNORE INTO `", targetSet, '` (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, + IF(o IS NULL OR EntityID IS NULL, "1=1", CONCAT("eids.id ", o, - vInt + EntityID )), IF(aggVal IS NULL, "", CONCAT(" AND e.id=", aggVal)), ' 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, + IF(o IS NULL OR EntityID IS NULL, "1=1", CONCAT("eids.id ", o, - vInt + EntityID )), IF(aggVal IS NULL, "", @@ -114,11 +130,11 @@ ELSE '` (id) SELECT data.id FROM `'), sourceSet, "` AS data JOIN entity_ids AS eids ON (eids.internal_id = data.id) WHERE ", - IF(o IS NULL OR vInt IS NULL, + IF(o IS NULL OR EntityID IS NULL, "1=1", CONCAT("eids.id", o, - vInt)), + EntityID)), IF(aggVal IS NULL, "", CONCAT(" AND data.id=", diff --git a/procedures/query/applyPOV.sql b/procedures/query/applyPOV.sql index 993ee96..d1d8467 100644 --- a/procedures/query/applyPOV.sql +++ b/procedures/query/applyPOV.sql @@ -1,5 +1,4 @@ /* - * ** header v3.0 * This file is a part of the CaosDB Project. * * Copyright (C) 2018 Research Group Biomedical Physics, @@ -17,8 +16,6 @@ * * 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 */ /* Documentation including (?) has to be checked by an expert. */ diff --git a/procedures/query/applyTransactionFilter.sql b/procedures/query/applyTransactionFilter.sql index 2f1669a..89b2225 100644 --- a/procedures/query/applyTransactionFilter.sql +++ b/procedures/query/applyTransactionFilter.sql @@ -1,9 +1,10 @@ /* - * ** 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 + * Copyright (C) 2023 IndiScale GmbH <info@indiscale.com> + * Copyright (C) 2023 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 @@ -17,37 +18,65 @@ * * 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.applyTransactionFilter; DELIMITER // + +/* + * Apply a transaction filter to the sourceSet and collect the remaining + * entities in the targetSet. + * + * Parameters + * ---------- + * sourceSet : VARCHAR(255) + * The name of the table from where we start. + * targetSet : VARCHAR(255) + * The name of the table where we collect all the "good" ids (or NULL or same as sourceSet). + * transaction : VARCHAR(255) + * The transaction's type (INSERT, UPDATE,...) + * operator_u : CHAR(2) + * The operator used for filtering by the user, e.g. '=', '!='. + * realm : VARCHAR(255) + * The user's realm (if filtering by the user). + * userName : VARCHAR(255) + * The user's name (if filtering by the user). + * ilb : BIGINT + * Inclusive Lower Bound of seconds for the transactions time. + * ilb_nanos : BIGINT + * Inclusive Lower Bound of nanoseconds for the transactions time. + * eub : BIGINT + * Exclusive Upper Bound of seconds for the transactions time. + * eub_nanos : BIGINT + * Exclusive Upper Bound of nanoseconds for the transactions time. + * operator_t : CHAR(2) + * The operator used for filtering by the transaction time, e.g. '=', '!=', '<', '>='. + */ 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 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, - CONCAT(' AND t.realm', operator_u, '? AND t.username', operator_u, '?'), - '' - ), - IF(ilb IS NOT NULL, - CONCAT(" AND", constructDateTimeWhereClauseForColumn("t.seconds", "t.nanos", ilb, ilb_nanos, eub, eub_nanos, operator_t)), - "" - ), - ')' - ); + 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, + CONCAT(' AND t.realm', operator_u, '? AND t.username', operator_u, '?'), + '' + ), + IF(ilb IS NOT NULL, + CONCAT(" AND", constructDateTimeWhereClauseForColumn("t.seconds", "t.nanos", ilb, ilb_nanos, eub, eub_nanos, operator_t)), + "" + ), + ')' + ); - SET @stmtTransactionStr = makeStmt(sourceSet, targetSet, data, NULL, FALSE); - PREPARE stmtTransactionFilter from @stmtTransactionStr; - IF userName IS NOT NULL THEN - SET @userName = userName; - SET @realm = realm; - EXECUTE stmtTransactionFilter USING @realm, @userName; - ELSE - EXECUTE stmtTransactionFilter; - END IF; + SET @stmtTransactionStr = makeStmt(sourceSet, targetSet, data, NULL, FALSE); + PREPARE stmtTransactionFilter from @stmtTransactionStr; + IF userName IS NOT NULL THEN + SET @userName = userName; + SET @realm = realm; + EXECUTE stmtTransactionFilter USING @realm, @userName; + ELSE + EXECUTE stmtTransactionFilter; + END IF; END; // diff --git a/procedures/query/initBackReference.sql b/procedures/query/initBackReference.sql index c425dbc..0a5be1b 100644 --- a/procedures/query/initBackReference.sql +++ b/procedures/query/initBackReference.sql @@ -1,9 +1,10 @@ /* - * ** 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 + * Copyright (C) 2023 IndiScale GmbH <info@indiscale.com> + * Copyright (C) 2023 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 @@ -17,27 +18,52 @@ * * 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.initBackReference; DELIMITER // -CREATE PROCEDURE db_5_0.initBackReference(in pid INT UNSIGNED, in pname VARCHAR(255), in entity_id INT UNSIGNED, in ename VARCHAR(255)) + +/* + * Create and initialize two new temporary tables. + * + * This is being used to initialize the filterin for backreferences to a + * particular entity (specified by EntityID or EntityName) or using a + * particular property (specified by PropertyID or PropertyName). + * + * The propertiesTable contains all properties matching the PropertyID or + * PropertyName. The entitiesTable container all entities matching EntityID or + * EntityName. + + * Parameters + * ---------- + * PropertyID : VARCHAR(255) + * The property's (external) id. + * PropertyName : VARCHAR(255) + * The property's name. + * EntityID : VARCHAR(255) + * The entity's (external) id. + * EntityName : VARCHAR(255) + * The entity's name. + * + * Select + * ------ + * Tuple (propertiesTable, entitiesTable) + */ +CREATE PROCEDURE db_5_0.initBackReference(in PropertyID VARCHAR(255), in PropertyName VARCHAR(255), in EntityID VARCHAR(255), in EntityName VARCHAR(255)) BEGIN DECLARE propertiesTable VARCHAR(255) DEFAULT NULL; DECLARE entitiesTable VARCHAR(255) DEFAULT NULL; - IF pname IS NOT NULL THEN + IF PropertyName IS NOT NULL THEN -- TODO versioning for properties call createTmpTable(propertiesTable, FALSE); - call initSubEntity(pid, pname, propertiesTable); + call initSubEntity(PropertyID, PropertyName, propertiesTable); END IF; - IF ename IS NOT NULL THEN + IF EntityName IS NOT NULL THEN -- TODO versioning for referencing entities call createTmpTable(entitiesTable, FALSE); - call initSubEntity(entity_id, ename, entitiesTable); + call initSubEntity(EntityID, EntityName, entitiesTable); END IF; SELECT propertiesTable, entitiesTable; diff --git a/procedures/query/initPOV.sql b/procedures/query/initPOV.sql index 52d6a26..6971329 100644 --- a/procedures/query/initPOV.sql +++ b/procedures/query/initPOV.sql @@ -1,9 +1,10 @@ /* - * ** 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 + * Copyright (C) 2023 IndiScale GmbH <info@indiscale.com> + * Copyright (C) 2023 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 @@ -17,15 +18,32 @@ * * 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.initPOVPropertiesTable// -CREATE PROCEDURE db_5_0.initPOVPropertiesTable(in pid INT UNSIGNED, in pname VARCHAR(255), in sourceSet VARCHAR(255)) +/* + * Create and initialize a new temporary table. + * + * This is being used to initialize the POV filtering. The resulting table + * container all properties machting the Property component of the POV filter. + * + * Parameters + * ---------- + * PropertyID : VARCHAR(255) + * The property's (external) id. + * PropertyName : VARCHAR(255) + * The property's name. + * sourceSet : VARCHAR(255) + * The name of the table which will be filtered by the POV filter. + * + * Select + * ------ + * Tuple (propertiesTable, ... and a lot of debug output) + */ +CREATE PROCEDURE db_5_0.initPOVPropertiesTable(in PropertyID VARCHAR(255), in PropertyName VARCHAR(255), in sourceSet VARCHAR(255)) BEGIN DECLARE propertiesTable VARCHAR(255) DEFAULT NULL; /*table for property ids*/ DECLARE replTbl VARCHAR(255) DEFAULT NULL; @@ -38,24 +56,24 @@ BEGIN DECLARE t6 BIGINT DEFAULT 0; - IF pname is NOT NULL THEN + IF PropertyName is NOT NULL THEN SELECT conv( concat( substring(uid,16,3), substring(uid,10,4), substring(uid,1,8)),16,10) div 10000 - (141427 * 24 * 60 * 60 * 1000) as current_mills INTO t1 from (select uuid() uid) as alias; call createTmpTable2(propertiesTable); - -- fill in all properties named "pname" + -- fill in all properties named "PropertyName" SET @initPOVPropertiesTableStmt1 = CONCAT('INSERT IGNORE INTO `', propertiesTable, '` (id, id2, domain) SELECT property_id, entity_id, domain_id from name_overrides WHERE name = ? UNION ALL SELECT entity_id, domain_id, 0 FROM name_data WHERE value = ?;'); PREPARE stmt FROM @initPOVPropertiesTableStmt1; - SET @pname = pname; - EXECUTE stmt USING @pname, @pname; + SET @PropertyName = PropertyName; + EXECUTE stmt USING @PropertyName, @PropertyName; SET ecount = ROW_COUNT(); - -- fill in all properties with id="pid" + -- fill in all properties with id="PropertyID" SELECT conv( concat( substring(uid,16,3), substring(uid,10,4), substring(uid,1,8)),16,10) div 10000 - (141427 * 24 * 60 * 60 * 1000) as current_mills INTO t2 from (select uuid() uid) as alias; - IF pid IS NOT NULL THEN + IF PropertyID IS NOT NULL THEN SET @initPOVPropertiesTableStmt2 = CONCAT('INSERT IGNORE INTO `', propertiesTable, '` (id, id2, domain) VALUES (?, 0, 0)'); PREPARE stmt FROM @initPOVPropertiesTableStmt2; - SET @pid = pid; - EXECUTE stmt USING @pid; + SET @PropertyID = PropertyID; + EXECUTE stmt USING @PropertyID; SET ecount = ecount + ROW_COUNT(); END IF; @@ -91,15 +109,33 @@ END // DROP PROCEDURE IF EXISTS db_5_0.initPOVRefidsTable // -CREATE PROCEDURE db_5_0.initPOVRefidsTable(in vInt INT UNSIGNED, in vText VARCHAR(255)) +/* + * Create and initialize a new temporary table. + * + * This is being used to initialize the POV filtering. The resulting table + * container all entities machting the Value component of the POV filter (i.e. + * the referenced entities). + * + * Parameters + * ---------- + * PropertyID : VARCHAR(255) + * The property's (external) id. + * PropertyName : VARCHAR(255) + * The property's name. + * + * Select + * ------ + * Tuple (refIdsTable) + */ +CREATE PROCEDURE db_5_0.initPOVRefidsTable(in PropertyID VARCHAR(255), in PropertyName VARCHAR(255)) BEGIN DECLARE refIdsTable VARCHAR(255) DEFAULT NULL; /*table for referenced entity ids*/ #-- for reference properties: the value is interpreted as a record type name. - IF vText IS NOT NULL THEN + IF PropertyName IS NOT NULL THEN -- TODO versioned queries call createTmpTable(refIdsTable, FALSE); - call initSubEntity(vInt, vText, refIdsTable); + call initSubEntity(PropertyID, PropertyName, refIdsTable); #-- now, all ids are in the refIdsTable END IF; SELECT refIdsTable; diff --git a/procedures/query/initSubEntity.sql b/procedures/query/initSubEntity.sql index 371934b..e548250 100644 --- a/procedures/query/initSubEntity.sql +++ b/procedures/query/initSubEntity.sql @@ -1,5 +1,4 @@ /* - * ** header v3.0 * This file is a part of the CaosDB Project. * * Copyright (C) 2018 Research Group Biomedical Physics, @@ -17,8 +16,6 @@ * * 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 */ @@ -26,7 +23,22 @@ DROP PROCEDURE IF EXISTS db_5_0.initSubEntity; DELIMITER // -CREATE PROCEDURE db_5_0.initSubEntity(in e_id INT UNSIGNED, in ename VARCHAR(255), in tableName VARCHAR(255)) +/* + * Initialize a new temporary by loading an entity and all of it's children + * into the table (i.e. their internal ids). + * + * This is used by initPOVRefidsTable and initBackReference for sub-property filtering. + * + * Parameters + * ---------- + * EntityID : VARCHAR(255) + * The entity's (external) id. + * EntityName : VARCHAR(255) + * The entity's name. + * tableName : VARCHAR(255) + * The table which is to be initialized. + */ +CREATE PROCEDURE db_5_0.initSubEntity(in EntityID VARCHAR(255), in ename VARCHAR(255), in tableName VARCHAR(255)) BEGIN DECLARE ecount INT DEFAULT 0; DECLARE op VARCHAR(255) DEFAULT '='; @@ -47,8 +59,8 @@ BEGIN SET ecount = ROW_COUNT(); DEALLOCATE PREPARE stmt; - IF e_id IS NOT NULL THEN - SET @stmtStr = CONCAT('INSERT IGNORE INTO `', tableName, '` (id) SELECT internal_id FROM entity_ids WHERE id = ', e_id, ''); + IF EntityID IS NOT NULL THEN + SET @stmtStr = CONCAT('INSERT IGNORE INTO `', tableName, '` (id) SELECT internal_id FROM entity_ids WHERE id = ', EntityID, ''); PREPARE stmt FROM @stmtStr; EXECUTE stmt; SET ecount = ecount + ROW_COUNT(); diff --git a/procedures/registerSubdomain.sql b/procedures/registerSubdomain.sql index 547d953..e914f1e 100644 --- a/procedures/registerSubdomain.sql +++ b/procedures/registerSubdomain.sql @@ -1,5 +1,4 @@ /* - * ** header v3.0 * This file is a part of the CaosDB Project. * * Copyright (C) 2018 Research Group Biomedical Physics, @@ -17,17 +16,10 @@ * * 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.registerSubdomain; delimiter // diff --git a/procedures/retrieveChildren.sql b/procedures/retrieveChildren.sql index 6721b92..20615fa 100644 --- a/procedures/retrieveChildren.sql +++ b/procedures/retrieveChildren.sql @@ -18,19 +18,11 @@ * along with this program. If not, see <https://www.gnu.org/licenses/>. */ -/* Retrieve the IDs of all direct children. - -Parameters -========== - -ParentID : INT UNSIGNED - The ID of the parent. -*/ - +-- TODO: REMOVE DROP PROCEDURE IF EXISTS db_5_0.retrieveChildren; delimiter // -CREATE PROCEDURE db_5_0.retrieveChildren(in ParentID INT UNSIGNED) +CREATE PROCEDURE db_5_0.retrieveChildren(in ParentID VARCHAR(255)) BEGIN DECLARE InternalParentID INT UNSIGNED DEFAULT NULL; diff --git a/procedures/retrieveEntity.sql b/procedures/retrieveEntity.sql index 4bfde2d..a4264e3 100644 --- a/procedures/retrieveEntity.sql +++ b/procedures/retrieveEntity.sql @@ -1,11 +1,10 @@ /* - * ** 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 - * Copyright (C) 2020 IndiScale GmbH <info@indiscale.com> - * Copyright (C) 2020 Timm Fitschen <t.fitschen@indiscale + * Copyright (C) 2020,2023 IndiScale GmbH <info@indiscale.com> + * Copyright (C) 2020,2023 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 @@ -19,8 +18,6 @@ * * 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 */ @@ -36,9 +33,9 @@ drop procedure if exists db_5_0.retrieveEntity // * * Parameters * ---------- - * EntityID + * EntityID : VARCHAR(255) * The entity's id. - * Version + * Version : VARBINARY(255) * The version id. In this procedure only, the version may also be given as * `HEAD` for the latest version or as `HEAD~n`, which retrieves the n-th * ancestor of `HEAD`. @@ -49,7 +46,7 @@ drop procedure if exists db_5_0.retrieveEntity // * EntityRole, FileSize, FilePath, FileHash, ACL, Version) */ create procedure db_5_0.retrieveEntity( - in EntityID INT UNSIGNED, + in EntityID VARCHAR(255), in Version VARBINARY(255)) retrieveEntityBody: BEGIN DECLARE FilePath VARCHAR(255) DEFAULT NULL; diff --git a/procedures/retrieveEntityOverrides.sql b/procedures/retrieveEntityOverrides.sql index cc8bfbe..61a28a0 100644 --- a/procedures/retrieveEntityOverrides.sql +++ b/procedures/retrieveEntityOverrides.sql @@ -1,11 +1,10 @@ /* - * ** 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 - * Copyright (C) 2020 Indiscale GmbH <info@indiscale.com> - * Copyright (C) 2020 Timm Fitschen <t.fitschen@indiscale.com> + * Copyright (C) 2020,2023 Indiscale GmbH <info@indiscale.com> + * Copyright (C) 2020,2023 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 @@ -19,26 +18,53 @@ * * 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.retrieveOverrides; delimiter // +/* + * Retrieve the overriden (overwriting the Abstract Property's) name, description, and datatype. + * + * Parameters + * ---------- + * + * DomainID : VARCHAR(255) + * The domain id (0 or the entity'id for level-2-data) + * EntityID : VARCHAR(255) + * The entity id (or the property'id for level-2-data) + * Version : VARBINARY(255) + * The version of the entity. Optional + * + * ResultSet + * --------- + * collection_override, # e.g. LIST + * name_override, # the name + * desc_override, # the description + * type_override, # the datatype, e.g. DOUBLE + * entity_id, # same as input EntityID + * InternalPropertyID, # internal property id, to be used when property_id + * # is NULL because a replacement is being using. + * property_id, # the property id + */ CREATE PROCEDURE db_5_0.retrieveOverrides( - in DomainID INT UNSIGNED, - in EntityID INT UNSIGNED, + in DomainID VARCHAR(255), + in EntityID VARCHAR(255), in Version VARBINARY(255)) 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; + DECLARE InternalDomainID INT UNSIGNED DEFAULT 0; - SELECT temp.internal_id INTO InternalDomainID FROM (SELECT internal_id AS internal_id FROM entity_ids WHERE id = DomainID UNION SELECT DomainID AS internal_id) AS temp LIMIT 1; + -- When DomainID != 0 the EntityID could possibly be a 'replacement id' + -- which are internal ids by definition (and do not have external + -- equivalents). That's why we do the UNION here, falling back to the + -- EntityID. SELECT temp.internal_id INTO InternalEntityID FROM (SELECT internal_id AS internal_id FROM entity_ids WHERE id = EntityID UNION SELECT EntityID AS internal_id) AS temp LIMIT 1; + -- DomainID != 0 are always normal (i.e. external) Entity ids. + 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 diff --git a/procedures/retrieveEntityParents.sql b/procedures/retrieveEntityParents.sql index 6d2c858..6fa2905 100644 --- a/procedures/retrieveEntityParents.sql +++ b/procedures/retrieveEntityParents.sql @@ -1,11 +1,10 @@ /* - * ** 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 - * Copyright (C) 2020 IndiScale GmbH <info@indiscale.com> - * Copyright (C) 2020 Timm Fitschen <t.fitschen@indiscale.com> + * Copyright (C) 2020,2023 IndiScale GmbH <info@indiscale.com> + * Copyright (C) 2020,2023 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 @@ -19,8 +18,6 @@ * * 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 */ @@ -28,32 +25,27 @@ DROP PROCEDURE IF EXISTS db_5_0.retrieveEntityParents; DELIMITER // /* Retrieve the parents of an Entity. - -Parameters -========== - -EntityID : UNSIGNED -Child entity for which all parental relations should be deleted. - -Returns -======= -ParentID : INT UNSIGNED - Each parent's ID - -ParentName : - The parent's name. - -ParentDescription : - The parent's description. - -ParentRole : - The parent's Role. - -ACL : - Access control list something + * + * Parameters + * ---------- + * EntityID : VARCHAR(255) + * Child entity for which all parental relations should be deleted. + * + * ResultSet + * --------- + * ParentID : VARCHAR(255) + * Each parent's ID + * ParentName : VARCHAR(255) + * The parent's name. + * ParentDescription : TEXT + * The parent's description. + * ParentRole : VARCHAR(255) + * The parent's Role. + * ACL : VARBINARY(65525) + * Access control list. */ CREATE PROCEDURE db_5_0.retrieveEntityParents( - in EntityID INT UNSIGNED, + in EntityID VARCHAR(255), in Version VARBINARY(255)) retrieveEntityParentsBody: BEGIN diff --git a/procedures/retrieveEntityProperties.sql b/procedures/retrieveEntityProperties.sql index 78e9cf4..a7026d9 100644 --- a/procedures/retrieveEntityProperties.sql +++ b/procedures/retrieveEntityProperties.sql @@ -1,11 +1,10 @@ /* - * ** 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 - * Copyright (C) 2020 IndiScale GmbH <info@indiscale.com> - * Copyright (C) 2020 Timm Fitschen <t.fitschen@indiscale.com> + * Copyright (C) 2020-2023 IndiScale GmbH <info@indiscale.com> + * Copyright (C) 2020,2023 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 @@ -19,8 +18,6 @@ * * 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 */ @@ -28,9 +25,37 @@ delimiter // drop procedure if exists db_5_0.retrieveEntityProperties // +/* + * Retrieve the properties of an entity (level 1 and 2). + * + * Parameters + * ---------- + * + * DomainID : VARCHAR(255) + * The domain id (0 or the entity's id for level-2-data) + * EntityID : VARCHAR(255) + * The entity id (or the property's id for level-2-data) + * Version : VARBINARY(255) + * The version of the entity. Optional + * + * ResultSet + * --------- + * InternalPropertyID + * Internal property id, to be used when PropertyID + * is NULL because a replacement is being using. + * PropertyID + * The property id + * PropertyValue + * The property value + * PropertyStatus + * E.g. OBLIGATORY, FIX, ... + * PropertyIndex + * The index of the property (for ordering). + * ) + */ create procedure db_5_0.retrieveEntityProperties( - in DomainID INT UNSIGNED, - in EntityID INT UNSIGNED, + in DomainID VARCHAR(255), + in EntityID VARCHAR(255), in Version VARBINARY(255)) retrieveEntityPropertiesBody: BEGIN @@ -39,7 +64,12 @@ retrieveEntityPropertiesBody: BEGIN DECLARE InternalEntityID INT UNSIGNED DEFAULT NULL; DECLARE InternalDomainID INT UNSIGNED DEFAULT 0; + -- When DomainID != 0 the EntityID could possibly be a 'replacement id' + -- which are internal ids by definition (and do not have external + -- equivalents). That's why we do the UNION here, falling back to the + -- EntityID. SELECT temp.internal_id INTO InternalEntityID FROM (SELECT internal_id AS internal_id FROM entity_ids WHERE id = EntityID UNION SELECT EntityID AS internal_id) AS temp LIMIT 1; + -- DomainID != 0 are always normal (i.e. external) Entity ids. SELECT internal_id INTO InternalDomainID from entity_ids WHERE id = DomainID; IF is_feature_config("ENTITY_VERSIONING", "ENABLED") THEN diff --git a/procedures/setFileProperties.sql b/procedures/setFileProperties.sql new file mode 100644 index 0000000..2c2cfc1 --- /dev/null +++ b/procedures/setFileProperties.sql @@ -0,0 +1,73 @@ +/* + * This file is a part of the CaosDB Project. + * + * Copyright (C) 2020 IndiScale GmbH <info@indiscale.com> + * Copyright (C) 2020 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/>. + */ + +DROP PROCEDURE IF EXISTS setFileProperties; +DELIMITER // +/** + * Update file properties. + * + * If ENTITY_VERSIONING is enabled the old file properties are moved to + * `archive_files`. + * + * Parameters + * ---------- + * EntityID : VARCHAR(255) + * The file's id. + * FilePath : TEXT + * Path of the file in the internal file system. If NULL, an existing file + * entity is simply deleted. + * FileSize : BIGINT UNSIGNED + * Size of the file in bytes. + * FileHash : VARCHAR(255) + * A Sha512 Hash of the file. + */ +CREATE PROCEDURE setFileProperties ( + in EntityID VARCHAR(255), + in FilePath TEXT, + in FileSize BIGINT UNSIGNED, + 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 = 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 = InternalEntityID; + END IF; + + DELETE FROM files WHERE file_id = InternalEntityID; + + IF FilePath IS NOT NULL THEN + INSERT INTO files (file_id, path, size, hash) + VALUES (InternalEntityID, FilePath, FileSize, unhex(FileHash)); + END IF; + +END // +DELIMITER ; diff --git a/procedures/updateEntity.sql b/procedures/updateEntity.sql index 52a69ea..3e0a53c 100644 --- a/procedures/updateEntity.sql +++ b/procedures/updateEntity.sql @@ -1,11 +1,10 @@ /* - * ** 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 - * Copyright (C) 2020 IndiScale GmbH <info@indiscale.com> - * Copyright (C) 2020 Timm Fitschen <t.fitschen@indiscale.com> + * Copyright (C) 2020,2023 IndiScale GmbH <info@indiscale.com> + * Copyright (C) 2020,2023 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 @@ -19,8 +18,6 @@ * * 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.updateEntity; @@ -34,7 +31,7 @@ delimiter // * Selects the new version identifier for the entity. */ CREATE PROCEDURE db_5_0.updateEntity( - in EntityID INT UNSIGNED, + in EntityID VARCHAR(255), in EntityName VARCHAR(255), in EntityDescription TEXT, in EntityRole VARCHAR(255), -- GitLab