From 8bf17eb198399866a55ce65db87c2643202473f6 Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Wed, 10 Jan 2024 12:34:36 +0000 Subject: [PATCH] [AC-1682] Updated data migration scripts to bump the account revision date --- ...023-12-06_00_AccessAllCollectionGroups.sql | 24 +++- ...2023-12-06_01_AccessAllCollectionUsers.sql | 24 +++- ...02_ManagersEditAssignedCollectionUsers.sql | 103 +++++++++++++----- 3 files changed, 122 insertions(+), 29 deletions(-) diff --git a/util/Migrator/DbScripts_transition/2023-12-06_00_AccessAllCollectionGroups.sql b/util/Migrator/DbScripts_transition/2023-12-06_00_AccessAllCollectionGroups.sql index 3ea8ead855..fe29bfe0b5 100644 --- a/util/Migrator/DbScripts_transition/2023-12-06_00_AccessAllCollectionGroups.sql +++ b/util/Migrator/DbScripts_transition/2023-12-06_00_AccessAllCollectionGroups.sql @@ -29,5 +29,27 @@ SET [AccessAll] = 0 FROM [dbo].[Group] G INNER JOIN #TempGroup TG ON G.[Id] = TG.[GroupId] --- Step 5: Drop the temporary table +-- 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 index 1169dba524..19b97a5ac5 100644 --- a/util/Migrator/DbScripts_transition/2023-12-06_01_AccessAllCollectionUsers.sql +++ b/util/Migrator/DbScripts_transition/2023-12-06_01_AccessAllCollectionUsers.sql @@ -36,5 +36,27 @@ SET [AccessAll] = 0 FROM [dbo].[OrganizationUser] OU INNER JOIN #TempOrgUser T ON OU.[Id] = T.[OrganizationUserId] --- Step 5: Drop the temporary table +-- 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 index e5994478da..736acd0f29 100644 --- a/util/Migrator/DbScripts_transition/2023-12-06_02_ManagersEditAssignedCollectionUsers.sql +++ b/util/Migrator/DbScripts_transition/2023-12-06_02_ManagersEditAssignedCollectionUsers.sql @@ -1,33 +1,82 @@ -- Step 1: Update [dbo].[CollectionUser] with [Manage] = 1 for all users with Manager role or 'EditAssignedCollections' permission -UPDATE cu -SET cu.[ReadOnly] = 0, - cu.[HidePasswords] = 0, - cu.[Manage] = 1 -FROM [dbo].[CollectionUser] cu -INNER JOIN [dbo].[OrganizationUser] ou - ON cu.[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')) + -- 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 -INSERT INTO [dbo].[CollectionUser] ([CollectionId], [OrganizationUserId], [ReadOnly], [HidePasswords], [Manage]) -SELECT cg.[CollectionId], ou.[Id], 0, 0, 1 -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] - ) + -- 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 -UPDATE [dbo].[OrganizationUser] -SET [Type] = 2 -- User -WHERE [OrganizationId] = @OrganizationId - AND [Type] = 3; -- Manager + -- Store the results in a temporary table + SELECT [Id] AS [OrganizationUserId] + INTO #TempStep3 + FROM [dbo].[OrganizationUser] + WHERE [Type] = 3; -- Manager --- TODO: clear custom permissions JSON? Probably should, but not actually used by any code once we enable FC + -- 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;