From a214c60268847ee84e21606dc1c6a8dab4062082 Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Thu, 11 Jan 2024 11:55:16 +0000 Subject: [PATCH] =?UTF-8?q?Revert=20"[AC-1682]=C2=A0Deleted=20old=20data?= =?UTF-8?q?=20migration=20scripts"?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit This reverts commit 54cc6fab8f162448446eeb06822e44e97a2b6534. --- ...023-12-06_00_AccessAllCollectionGroups.sql | 55 +++++++++++++ ...2023-12-06_01_AccessAllCollectionUsers.sql | 62 ++++++++++++++ ...02_ManagersEditAssignedCollectionUsers.sql | 82 +++++++++++++++++++ 3 files changed, 199 insertions(+) create mode 100644 util/Migrator/DbScripts_transition/2023-12-06_00_AccessAllCollectionGroups.sql create mode 100644 util/Migrator/DbScripts_transition/2023-12-06_01_AccessAllCollectionUsers.sql create mode 100644 util/Migrator/DbScripts_transition/2023-12-06_02_ManagersEditAssignedCollectionUsers.sql diff --git a/util/Migrator/DbScripts_transition/2023-12-06_00_AccessAllCollectionGroups.sql b/util/Migrator/DbScripts_transition/2023-12-06_00_AccessAllCollectionGroups.sql new file mode 100644 index 000000000..fe29bfe0b --- /dev/null +++ b/util/Migrator/DbScripts_transition/2023-12-06_00_AccessAllCollectionGroups.sql @@ -0,0 +1,55 @@ +-- Step 1: Create a temporary table to store the Groups with AccessAll = 1 +SELECT [Id] AS [GroupId], [OrganizationId] +INTO #TempGroup +FROM [dbo].[Group] +WHERE [AccessAll] = 1; + +-- Step 2: Update existing rows in [dbo].[CollectionGroup] +UPDATE CG +SET + CG.[ReadOnly] = 0, + CG.[HidePasswords] = 0, + CG.[Manage] = 0 + FROM [dbo].[CollectionGroup] CG +INNER JOIN [dbo].[Collection] C ON CG.[CollectionId] = C.[Id] +INNER JOIN #TempGroup TG ON CG.[GroupId] = TG.[GroupId] +WHERE C.[OrganizationId] = TG.[OrganizationId]; + +-- Step 3: Insert new rows into [dbo].[CollectionGroup] +INSERT INTO [dbo].[CollectionGroup] ([CollectionId], [GroupId], [ReadOnly], [HidePasswords], [Manage]) +SELECT C.[Id], TG.[GroupId], 0, 0, 0 +FROM [dbo].[Collection] C + INNER JOIN #TempGroup TG ON C.[OrganizationId] = TG.[OrganizationId] + LEFT JOIN [dbo].[CollectionGroup] CG ON CG.[CollectionId] = C.[Id] AND CG.[GroupId] = TG.[GroupId] +WHERE CG.[CollectionId] IS NULL; + +-- Step 4: Update [dbo].[Group] to clear AccessAll flag +UPDATE G +SET [AccessAll] = 0 +FROM [dbo].[Group] G +INNER JOIN #TempGroup TG ON G.[Id] = TG.[GroupId] + +-- Step 5: Bump the account revision date for each unique OrganizationId in #TempGroup +DECLARE @OrganizationId UNIQUEIDENTIFIER + +DECLARE OrgIdCursor CURSOR FOR +SELECT DISTINCT [OrganizationId] +FROM #TempGroup + +OPEN OrgIdCursor +FETCH NEXT FROM OrgIdCursor INTO @OrganizationId + +WHILE (@@FETCH_STATUS = 0) +BEGIN + -- Execute the stored procedure for the current OrganizationId + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId + + -- Fetch the next OrganizationId + FETCH NEXT FROM OrgIdCursor INTO @OrganizationId +END + +CLOSE OrgIdCursor +DEALLOCATE OrgIdCursor; + +-- Step 6: Drop the temporary table +DROP TABLE #TempGroup; diff --git a/util/Migrator/DbScripts_transition/2023-12-06_01_AccessAllCollectionUsers.sql b/util/Migrator/DbScripts_transition/2023-12-06_01_AccessAllCollectionUsers.sql new file mode 100644 index 000000000..19b97a5ac --- /dev/null +++ b/util/Migrator/DbScripts_transition/2023-12-06_01_AccessAllCollectionUsers.sql @@ -0,0 +1,62 @@ +-- Step 1: Create a temporary table to store the OrganizationUsers with AccessAll = 1 +SELECT [Id] AS [OrganizationUserId], [OrganizationId] +INTO #TempOrgUser +FROM [dbo].[OrganizationUser] +WHERE [AccessAll] = 1; + +-- Step 2: Update existing rows in [dbo].[CollectionUser] +UPDATE target +SET + target.[ReadOnly] = 0, + target.[HidePasswords] = 0, + target.[Manage] = 0 +FROM [dbo].[CollectionUser] AS target +INNER JOIN ( + SELECT C.[Id] AS [CollectionId], T.[OrganizationUserId] + FROM [dbo].[Collection] C + INNER JOIN #TempOrgUser T ON C.[OrganizationId] = T.[OrganizationId] +) AS source + ON target.[CollectionId] = source.[CollectionId] AND target.[OrganizationUserId] = source.[OrganizationUserId]; + +-- Step 3: Insert new rows into [dbo].[CollectionUser] +INSERT INTO [dbo].[CollectionUser] ([CollectionId], [OrganizationUserId], [ReadOnly], [HidePasswords], [Manage]) +SELECT source.[CollectionId], source.[OrganizationUserId], 0, 0, 0 +FROM ( + SELECT C.[Id] AS [CollectionId], T.[OrganizationUserId] + FROM [dbo].[Collection] C + INNER JOIN #TempOrgUser T ON C.[OrganizationId] = T.[OrganizationId] + ) AS source +LEFT JOIN [dbo].[CollectionUser] AS target + ON target.[CollectionId] = source.[CollectionId] AND target.[OrganizationUserId] = source.[OrganizationUserId] +WHERE target.[CollectionId] IS NULL; + +-- Step 4: Update [dbo].[OrganizationUser] to clear AccessAll flag +UPDATE OU +SET [AccessAll] = 0 +FROM [dbo].[OrganizationUser] OU +INNER JOIN #TempOrgUser T ON OU.[Id] = T.[OrganizationUserId] + +-- Step 5: Bump the account revision date for each unique OrganizationId in #TempOrgUser +DECLARE @OrganizationId UNIQUEIDENTIFIER + +DECLARE OrgIdCursor CURSOR FOR +SELECT DISTINCT [OrganizationId] +FROM #TempOrgUser + +OPEN OrgIdCursor +FETCH NEXT FROM OrgIdCursor INTO @OrganizationId + +WHILE (@@FETCH_STATUS = 0) +BEGIN + -- Execute the stored procedure for the current OrganizationId + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId + + -- Fetch the next OrganizationId + FETCH NEXT FROM OrgIdCursor INTO @OrganizationId +END + +CLOSE OrgIdCursor +DEALLOCATE OrgIdCursor; + +-- Step 6: Drop the temporary table +DROP TABLE #TempOrgUser; diff --git a/util/Migrator/DbScripts_transition/2023-12-06_02_ManagersEditAssignedCollectionUsers.sql b/util/Migrator/DbScripts_transition/2023-12-06_02_ManagersEditAssignedCollectionUsers.sql new file mode 100644 index 000000000..736acd0f2 --- /dev/null +++ b/util/Migrator/DbScripts_transition/2023-12-06_02_ManagersEditAssignedCollectionUsers.sql @@ -0,0 +1,82 @@ +-- Step 1: Update [dbo].[CollectionUser] with [Manage] = 1 for all users with Manager role or 'EditAssignedCollections' permission + -- Store the results in a temporary table + SELECT ou.[Id] AS [OrganizationUserId] + INTO #TempStep1 + FROM [dbo].[OrganizationUser] ou + WHERE (ou.[Type] = 3 OR (ou.[Permissions] IS NOT NULL AND + ISJSON(ou.[Permissions]) > 0 AND JSON_VALUE(ou.[Permissions], '$.editAssignedCollections') = 'true')); + + -- Update [dbo].[CollectionUser] with [Manage] = 1 using the temporary table + UPDATE cu + SET cu.[ReadOnly] = 0, + cu.[HidePasswords] = 0, + cu.[Manage] = 1 + FROM [dbo].[CollectionUser] cu + INNER JOIN #TempStep1 temp ON cu.[OrganizationUserId] = temp.[OrganizationUserId]; + +-- Step 2: Insert rows to [dbo].[CollectionUser] for Managers and users with 'EditAssignedCollections' permission assigned to groups with collection access + -- Store the results in a temporary table + SELECT cg.[CollectionId], ou.[Id] AS [OrganizationUserId] + INTO #TempStep2 + FROM [dbo].[CollectionGroup] cg + INNER JOIN [dbo].[GroupUser] gu ON cg.GroupId = gu.GroupId + INNER JOIN [dbo].[OrganizationUser] ou ON gu.OrganizationUserId = ou.[Id] + WHERE (ou.[Type] = 3 OR (ou.[Permissions] IS NOT NULL AND ISJSON(ou.[Permissions]) > 0 AND JSON_VALUE(ou.[Permissions], '$.editAssignedCollections') = 'true')) + AND NOT EXISTS ( + SELECT 1 FROM [dbo].[CollectionUser] cu + WHERE cu.[CollectionId] = cg.[CollectionId] AND cu.[OrganizationUserId] = ou.[Id] + ); + + -- Insert rows into [dbo].[CollectionUser] using the temporary table + INSERT INTO [dbo].[CollectionUser] ([CollectionId], [OrganizationUserId], [ReadOnly], [HidePasswords], [Manage]) + SELECT [CollectionId], [OrganizationUserId], 0, 0, 1 + FROM #TempStep2; + +-- Step 3: Set all Managers to Users + -- Store the results in a temporary table + SELECT [Id] AS [OrganizationUserId] + INTO #TempStep3 + FROM [dbo].[OrganizationUser] + WHERE [Type] = 3; -- Manager + + -- Update [dbo].[OrganizationUser] based on the temporary table + UPDATE ou + SET ou.[Type] = 2 -- User + FROM [dbo].[OrganizationUser] ou + INNER JOIN #TempStep3 temp ON ou.[Id] = temp.[OrganizationUserId]; + +-- Step 4: Bump the account revision date for each unique OrganizationUserId in #TempStep1, #TempStep2, and #TempStep3 + -- Join the three temporary tables to get unique OrganizationUserId + SELECT DISTINCT temp1.[OrganizationUserId] + INTO #TempUniqueOrganizationUser + FROM #TempStep1 temp1 + JOIN #TempStep2 temp2 ON temp1.[OrganizationUserId] = temp2.[OrganizationUserId] + JOIN #TempStep3 temp3 ON temp1.[OrganizationUserId] = temp3.[OrganizationUserId]; + + -- Execute User_BumpAccountRevisionDateByOrganizationUserId for each unique OrganizationUserId + DECLARE @OrganizationUserId UNIQUEIDENTIFIER + + DECLARE UniqueOrgUserIdCursor CURSOR FOR + SELECT [OrganizationUserId] + FROM #TempUniqueOrganizationUser + + OPEN UniqueOrgUserIdCursor + FETCH NEXT FROM UniqueOrgUserIdCursor INTO @OrganizationUserId + + WHILE (@@FETCH_STATUS = 0) + BEGIN + -- Execute the stored procedure for the current OrganizationUserId + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserId] @OrganizationUserId + + -- Fetch the next row + FETCH NEXT FROM UniqueOrgUserIdCursor INTO @OrganizationUserId + END + + CLOSE UniqueOrgUserIdCursor + DEALLOCATE UniqueOrgUserIdCursor; + +-- Step 5: Clean up temporary tables +DROP TABLE #TempStep1; +DROP TABLE #TempStep2; +DROP TABLE #TempStep3; +DROP TABLE #TempUniqueOrganizationUser;