diff --git a/util/MySqlMigrations/HelperScripts/2024-01-12_00_AccessAllCollectionGroups.sql b/util/MySqlMigrations/HelperScripts/2024-01-12_00_AccessAllCollectionGroups.sql index 47fddf3f7f..49cf4922d5 100644 --- a/util/MySqlMigrations/HelperScripts/2024-01-12_00_AccessAllCollectionGroups.sql +++ b/util/MySqlMigrations/HelperScripts/2024-01-12_00_AccessAllCollectionGroups.sql @@ -36,30 +36,11 @@ INNER JOIN TempGroup TG ON G.`Id` = TG.`GroupId` SET G.`AccessAll` = 0; -- Step 6: Update User AccountRevisionDate for each unique OrganizationUserId -DECLARE Step1OrganizationUserId UUID; - -DECLARE UniqueOrgUserIdCursor CURSOR FOR -SELECT `OrganizationUserId` -FROM TempOrganizationUsers; - -OPEN UniqueOrgUserIdCursor; -FETCH NEXT FROM UniqueOrgUserIdCursor INTO Step1OrganizationUserId; - -WHILE (FETCH_STATUS = 0) DO - -- Update User AccountRevisionDate for the current OrganizationUserId - UPDATE `User` U - SET U.`AccountRevisionDate` = UTC_TIMESTAMP() - FROM `User` U - INNER JOIN `OrganizationUser` OU ON OU.`UserId` = U.`Id` - WHERE OU.`Id` = Step1OrganizationUserId - AND OU.`Status` = 2; - - -- Fetch the next row - FETCH NEXT FROM UniqueOrgUserIdCursor INTO Step1OrganizationUserId; -END WHILE; - -CLOSE UniqueOrgUserIdCursor; -DEALLOCATE UniqueOrgUserIdCursor; +UPDATE `User` U +INNER JOIN `OrganizationUser` OU ON OU.`UserId` = U.`Id` +INNER JOIN TempOrganizationUsers TOU ON TOU.`OrganizationUserId` = OU.`Id` +SET U.`AccountRevisionDate` = UTC_TIMESTAMP() +WHERE OU.`Status` = 2; -- Step 7: Drop the temporary tables DROP TEMPORARY TABLE IF EXISTS TempGroup; diff --git a/util/MySqlMigrations/HelperScripts/2024-01-12_01_AccessAllCollectionUsers.sql b/util/MySqlMigrations/HelperScripts/2024-01-12_01_AccessAllCollectionUsers.sql index 2e9de29b1e..b02b06a6b0 100644 --- a/util/MySqlMigrations/HelperScripts/2024-01-12_01_AccessAllCollectionUsers.sql +++ b/util/MySqlMigrations/HelperScripts/2024-01-12_01_AccessAllCollectionUsers.sql @@ -1,21 +1,40 @@ --- Update existing rows in CollectionUsers -UPDATE CollectionUsers AS target -INNER JOIN Collection AS C ON target.CollectionId = C.Id -INNER JOIN OrganizationUser AS OU ON C.OrganizationId = OU.OrganizationId -SET - target.ReadOnly = 0, - target.HidePasswords = 0, - target.Manage = 0 -WHERE OU.AccessAll = 1; +-- Step 1: Create a temporary table +CREATE TEMPORARY TABLE TempOrgUser AS +SELECT `Id` AS `OrganizationUserId`, `OrganizationId` +FROM `OrganizationUser` +WHERE `AccessAll` = 1; --- Insert new rows into CollectionUsers -INSERT INTO CollectionUsers (CollectionId, OrganizationUserId, ReadOnly, HidePasswords, Manage) -SELECT C.Id AS CollectionId, OU.Id AS OrganizationUserId, 0, 0, 0 -FROM Collection AS C -INNER JOIN OrganizationUser AS OU ON C.OrganizationId = OU.OrganizationId -WHERE OU.AccessAll = 1 - AND NOT EXISTS ( +-- Step 2: Update existing rows in CollectionUsers +UPDATE `CollectionUsers` AS `target` +INNER JOIN `Collection` AS `C` ON `target`.`CollectionId` = `C`.`Id` +INNER JOIN `TempOrgUser` AS `OU` ON `C`.`OrganizationId` = `OU`.`OrganizationId` +SET + `target`.`ReadOnly` = 0, + `target`.`HidePasswords` = 0, + `target`.`Manage` = 0; + +-- Step 3: Insert new rows into CollectionUsers +INSERT INTO `CollectionUsers` (`CollectionId`, `OrganizationUserId`, `ReadOnly`, `HidePasswords`, `Manage`) +SELECT `C`.`Id` AS `CollectionId`, `OU`.`OrganizationUserId`, 0, 0, 0 +FROM `Collection` AS `C` +INNER JOIN `TempOrgUser` AS `OU` ON `C`.`OrganizationId` = `OU`.`OrganizationId` +WHERE NOT EXISTS ( SELECT 1 - FROM CollectionUsers AS CU - WHERE CU.CollectionId = C.Id AND CU.OrganizationUserId = OU.Id + FROM `CollectionUsers` AS `CU` + WHERE `CU`.`CollectionId` = `C`.`Id` AND `CU`.`OrganizationUserId` = `OU`.`OrganizationUserId` ); + +-- Step 4: Update OrganizationUser to clear AccessAll flag +UPDATE `OrganizationUser` AS `OU` +INNER JOIN `TempOrgUser` AS `T` ON `OU`.`Id` = `T`.`OrganizationUserId` +SET `OU`.`AccessAll` = 0; + +-- Step 5: Update `User` AccountRevisionDate for each unique OrganizationUserId +UPDATE `User` AS `U` +INNER JOIN `OrganizationUser` AS `OU` ON `OU`.`UserId` = `U`.`Id` +INNER JOIN `TempOrgUser` AS `TOU` ON `TOU`.`OrganizationUserId` = `OU`.`Id` +SET `U`.`AccountRevisionDate` = UTC_TIMESTAMP() +WHERE `OU`.`Status` = 2; + +-- Step 6: Drop the temporary table +DROP TEMPORARY TABLE IF EXISTS TempOrgUser; diff --git a/util/MySqlMigrations/HelperScripts/2024-01-12_02_ManagersEditAssignedCollectionUsers.sql b/util/MySqlMigrations/HelperScripts/2024-01-12_02_ManagersEditAssignedCollectionUsers.sql index 83e5e98c1f..ef1ec83898 100644 --- a/util/MySqlMigrations/HelperScripts/2024-01-12_02_ManagersEditAssignedCollectionUsers.sql +++ b/util/MySqlMigrations/HelperScripts/2024-01-12_02_ManagersEditAssignedCollectionUsers.sql @@ -1,20 +1,74 @@ --- Update `CollectionUser` with `Manage` = 1 for all users with Manager role or 'EditAssignedCollections' permission -UPDATE CollectionUsers cu -INNER JOIN OrganizationUser ou ON cu.OrganizationUserId = ou.Id -SET cu.ReadOnly = 0, - cu.HidePasswords = 0, - cu.Manage = 1 -WHERE ou.Type = 3 OR (ou.Permissions IS NOT NULL AND - JSON_VALID(ou.Permissions) > 0 AND JSON_UNQUOTE(JSON_EXTRACT(ou.Permissions, '$.editAssignedCollections')) = 'true'); +-- Step 1: Update `CollectionUser` with `Manage` = 1 for all users with Manager role or 'EditAssignedCollections' permission + -- Create a temporary table + CREATE TEMPORARY TABLE TempOrgUser AS + SELECT ou.Id AS OrganizationUserId + FROM OrganizationUser ou + WHERE ou.Type = 3 OR (ou.Permissions IS NOT NULL AND + JSON_VALID(ou.Permissions) > 0 AND JSON_UNQUOTE(JSON_EXTRACT(ou.Permissions, '$.editAssignedCollections')) = 'true'); --- Insert rows to CollectionUser for Managers and users with 'EditAssignedCollections' permission assigned to groups with collection access -INSERT INTO CollectionUsers (CollectionId, OrganizationUserId, ReadOnly, HidePasswords, Manage) -SELECT cg.CollectionId, ou.Id, 0, 0, 1 -FROM CollectionGroups cg -INNER JOIN GroupUser gu ON cg.GroupId = gu.GroupId -INNER JOIN OrganizationUser ou ON gu.OrganizationUserId = ou.Id -WHERE (ou.Type = 3 OR - (ou.Permissions IS NOT NULL AND JSON_VALID(ou.Permissions) > 0 AND JSON_UNQUOTE(JSON_EXTRACT(ou.Permissions, '$.editAssignedCollections')) = 'true')) - AND NOT EXISTS ( - SELECT 1 FROM CollectionUsers cu - WHERE cu.CollectionId = cg.CollectionId AND cu.OrganizationUserId = ou.Id); + -- Update CollectionUsers with Manage = 1 using the temporary table + UPDATE CollectionUsers cu + INNER JOIN TempOrgUser temp ON cu.OrganizationUserId = temp.OrganizationUserId + SET cu.ReadOnly = 0, + cu.HidePasswords = 0, + cu.Manage = 1; + + -- Update `User` AccountRevisionDate for each unique OrganizationUserId + UPDATE `User` AS `U` + INNER JOIN `OrganizationUser` AS `OU` ON `OU`.`UserId` = `U`.`Id` + INNER JOIN `TempOrgUser` AS `TOU` ON `TOU`.`OrganizationUserId` = `OU`.`Id` + SET `U`.`AccountRevisionDate` = UTC_TIMESTAMP() + WHERE `OU`.`Status` = 2; + + -- Drop the temporary table + DROP TEMPORARY TABLE IF EXISTS TempOrgUser; + +-- Step 2: Insert rows to CollectionUser for Managers and users with 'EditAssignedCollections' permission assigned to groups with collection access + -- Store the results in a temporary table + CREATE TEMPORARY TABLE IF NOT EXISTS TempCol AS + SELECT cg.CollectionId, ou.Id AS OrganizationUserId + FROM CollectionGroups cg + INNER JOIN GroupUser gu ON cg.GroupId = gu.GroupId + INNER JOIN OrganizationUser ou ON gu.OrganizationUserId = ou.Id + WHERE (ou.Type = 3 OR (ou.Permissions IS NOT NULL AND JSON_VALID(ou.Permissions) > 0 AND JSON_UNQUOTE(JSON_EXTRACT(ou.Permissions, '$.editAssignedCollections')) = 'true')) + AND NOT EXISTS ( + SELECT 1 FROM CollectionUsers cu + WHERE cu.CollectionId = cg.CollectionId AND cu.OrganizationUserId = ou.Id + ); + + -- Insert rows into CollectionUsers using the temporary table + INSERT INTO CollectionUsers (CollectionId, OrganizationUserId, ReadOnly, HidePasswords, Manage) + SELECT CollectionId, OrganizationUserId, 0, 0, 1 + FROM TempCol; + + -- Update `User` AccountRevisionDate for each unique OrganizationUserId + UPDATE `User` AS `U` + INNER JOIN `OrganizationUser` AS `OU` ON `OU`.`UserId` = `U`.`Id` + INNER JOIN `TempCol` AS `TC` ON `TC`.`OrganizationUserId` = `OU`.`Id` + SET `U`.`AccountRevisionDate` = UTC_TIMESTAMP() + WHERE `OU`.`Status` = 2; + + -- Drop the temporary table + DROP TEMPORARY TABLE IF EXISTS TempCol; + +-- Step 3: Set all Managers to Users + -- Create a temporary table + CREATE TEMPORARY TABLE TempOrgUser AS + SELECT ou.Id AS OrganizationUserId + FROM OrganizationUser ou + WHERE ou.Type = 3; + + -- Update OrganizationUser with Type = 2 using the temporary table + UPDATE OrganizationUser ou + INNER JOIN TempOrgUser temp ON ou.Id = temp.OrganizationUserId + SET ou.Type = 2; + + -- Update `User` AccountRevisionDate for each unique OrganizationUserId + UPDATE `User` AS `U` + INNER JOIN `OrganizationUser` AS `OU` ON `OU`.`UserId` = `U`.`Id` + INNER JOIN `TempOrgUser` AS `TOU` ON `TOU`.`OrganizationUserId` = `OU`.`Id` + SET `U`.`AccountRevisionDate` = UTC_TIMESTAMP() + WHERE `OU`.`Status` = 2; + + -- Drop the temporary table + DROP TEMPORARY TABLE IF EXISTS TempOrgUser; diff --git a/util/MySqlMigrations/HelperScripts/2024-01-12_03_EnableOrgsFlexibleCollections.sql b/util/MySqlMigrations/HelperScripts/2024-01-12_03_EnableOrgsFlexibleCollections.sql index e69de29bb2..1794cdb965 100644 --- a/util/MySqlMigrations/HelperScripts/2024-01-12_03_EnableOrgsFlexibleCollections.sql +++ b/util/MySqlMigrations/HelperScripts/2024-01-12_03_EnableOrgsFlexibleCollections.sql @@ -0,0 +1,4 @@ +-- Set `FlexibleCollections` = 1 for all organizations that have not yet been migrated. +UPDATE `Organization` +SET `FlexibleCollections` = 1 +WHERE `FlexibleCollections` = 0;