From 2d4552728d63b232d9ab41ca05686d69110ce865 Mon Sep 17 00:00:00 2001 From: Timm Fitschen <t.fitschen@indiscale.com> Date: Fri, 28 May 2021 22:40:29 +0200 Subject: [PATCH] add parent_directory column to files table --- patches/patch20210219-5.0.0-rc1/patch.sql | 14 ++++++++++---- procedures/retrieveEntity.sql | 19 +++++++++++-------- 2 files changed, 21 insertions(+), 12 deletions(-) diff --git a/patches/patch20210219-5.0.0-rc1/patch.sql b/patches/patch20210219-5.0.0-rc1/patch.sql index f362619..a087aef 100644 --- a/patches/patch20210219-5.0.0-rc1/patch.sql +++ b/patches/patch20210219-5.0.0-rc1/patch.sql @@ -9,6 +9,7 @@ ALTER TABLE files ADD UNIQUE (`path`); ALTER TABLE files ADD COLUMN IF NOT EXISTS ( + parent_directory INT UNSIGNED DEFAULT NULL, mimetype VARBINARY(255) DEFAULT NULL, file_storage_id VARBINARY(255) NOT NULL DEFAULT "DEFAULT", file_key VARBINARY(255) DEFAULT NULL, @@ -16,6 +17,7 @@ ALTER TABLE files ADD COLUMN IF NOT EXISTS ( ); ALTER TABLE archive_files ADD COLUMN IF NOT EXISTS ( + parent_directory INT UNSIGNED DEFAULT NULL, mimetype VARBINARY(255) DEFAULT NULL, file_storage_id VARBINARY(255) NOT NULL DEFAULT "DEFAULT", file_key VARBINARY(255) DEFAULT NULL, @@ -44,6 +46,7 @@ BEGIN DECLARE _path VARCHAR(255) DEFAULT NULL; DECLARE dir_id INT UNSIGNED DEFAULT NULL; DECLARE dir_path VARCHAR(255) DEFAULT ""; + DECLARE dir_path_no_trailing_slash VARCHAR(255) DEFAULT ""; DECLARE dir_exists BOOLEAN DEFAULT FALSE; DECLARE cur CURSOR FOR SELECT file_id, path FROM files; DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE; @@ -63,7 +66,8 @@ BEGIN SET done = FALSE; LEAVE loop2; END IF; - SELECT TRUE INTO dir_exists FROM files WHERE path = LEFT(dir_path, CHAR_LENGTH(dir_path)-1); + SET dir_path_no_trailing_slash = LEFT(dir_path, CHAR_LENGTH(dir_path)-1); + SELECT TRUE INTO dir_exists FROM files WHERE path = dir_path_no_trailing_slash; IF dir_exists IS TRUE THEN SET dir_exists = FALSE; ITERATE loop2; @@ -72,9 +76,11 @@ BEGIN SET dir_id = LAST_INSERT_ID(); INSERT INTO files (file_id, path, size, hash, checked_timestamp, mimetype, file_storage_id, file_key) - VALUES (dir_id, LEFT(dir_path, CHAR_LENGTH(dir_path)-1), 0, - NULL, 0, "inode/directory", "DEFAULT", LEFT(dir_path, - CHAR_LENGTH(dir_path)-1)); + VALUES (dir_id, dir_path_no_trailing_slash, 0, NULL, 0, + "inode/directory", "DEFAULT", dir_path_no_trailing_slash + ); + UPDATE files SET parent_directory = dir_id WHERE path LIKE CONCAT(dir_path, "%"); + UPDATE files SET parent_directory = 0 WHERE path LIKE CONCAT(dir_path, "%"); END LOOP; END LOOP; diff --git a/procedures/retrieveEntity.sql b/procedures/retrieveEntity.sql index 4e89b1b..826f568 100644 --- a/procedures/retrieveEntity.sql +++ b/procedures/retrieveEntity.sql @@ -45,19 +45,21 @@ drop procedure if exists db_2_0.retrieveEntity // * * ResultSet * --------- - * Tuple of (Datatype, Collection, EntityID, EntityName, EntityDesc, - * EntityRole, FileSize, FilePath, FileHash, ACL, Version) + * Tuple of (DatatypeID, Collection, EntityID, EntityName, EntityDesc, + * EntityRole, FileSize, FilePath, FileHash, FileHashChecked, + * FileMimetype, FileStorageID, FileKey, FileParentID, ACL, Version) */ create procedure db_2_0.retrieveEntity( in EntityID INT UNSIGNED, in Version VARBINARY(255)) retrieveEntityBody: BEGIN DECLARE FilePath VARCHAR(255) DEFAULT NULL; + DECLARE FileParentID INT UNSIGNED DEFAULT NULL; DECLARE FileSize VARCHAR(255) DEFAULT NULL; DECLARE FileHash VARCHAR(255) DEFAULT NULL; DECLARE FileHashChecked BIGINT DEFAULT NULL; DECLARE FileMimetype VARBINARY(255) DEFAULT NULL; - DECLARE FileStorageId VARBINARY(255) DEFAULT NULL; + DECLARE FileStorageID VARBINARY(255) DEFAULT NULL; DECLARE FileKey VARBINARY(65525) DEFAULT NULL; DECLARE DatatypeID INT UNSIGNED DEFAULT NULL; DECLARE CollectionName VARCHAR(255) DEFAULT NULL; @@ -86,7 +88,7 @@ retrieveEntityBody: BEGIN END IF; SELECT path, size, hex(hash), checked_timestamp, mimetype, file_storage_id, file_key - INTO FilePath, FileSize, FileHash, FileHashChecked, FileMimetype, FileStorageId, FileKey + INTO FilePath, FileSize, FileHash, FileHashChecked, FileMimetype, FileStorageID, FileKey FROM archive_files WHERE file_id = EntityID AND _iversion = IVersion @@ -135,7 +137,7 @@ retrieveEntityBody: BEGIN FileHash AS FileHash, FileHashChecked AS FileHashChecked, FileMimetype as FileMimetype, - FileStorageId as FileStorageId, + FileStorageID as FileStorageID, FileKey as FileKey, (SELECT acl FROM entity_acl AS a WHERE a.id = e.acl) AS ACL, Version AS Version @@ -150,8 +152,8 @@ retrieveEntityBody: BEGIN END IF; END IF; - SELECT path, size, hex(hash), checked_timestamp, mimetype, file_storage_id, file_key - INTO FilePath, FileSize, FileHash, FileHashChecked, FileMimetype, FileStorageId, FileKey + SELECT path, parent_directory, size, hex(hash), checked_timestamp, mimetype, file_storage_id, file_key + INTO FilePath, FileParentID, FileSize, FileHash, FileHashChecked, FileMimetype, FileStorageID, FileKey FROM files WHERE file_id = EntityID LIMIT 1; @@ -188,8 +190,9 @@ retrieveEntityBody: BEGIN FileHash AS FileHash, FileHashChecked AS FileHashChecked, FileMimetype as FileMimetype, - FileStorageId as FileStorageId, + FileStorageID as FileStorageID, FileKey as FileKey, + FileParentID as FileParentID, (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; -- GitLab