From 160fc3edd07e8f188ee82b9397263ad8a9714f51 Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Thu, 18 Jan 2024 16:07:15 +0000 Subject: [PATCH] [AC-1682] Modified data migration script to have just one big transaction --- ...anization_EnableCollectionEnhancements.sql | 270 +++++++----------- ...anization_EnableCollectionEnhancements.sql | 270 +++++++----------- 2 files changed, 208 insertions(+), 332 deletions(-) diff --git a/src/Sql/dbo/Stored Procedures/Organization_EnableCollectionEnhancements.sql b/src/Sql/dbo/Stored Procedures/Organization_EnableCollectionEnhancements.sql index 1d031a1bd6..dbd2508be8 100644 --- a/src/Sql/dbo/Stored Procedures/Organization_EnableCollectionEnhancements.sql +++ b/src/Sql/dbo/Stored Procedures/Organization_EnableCollectionEnhancements.sql @@ -13,71 +13,13 @@ BEGIN AND [OrganizationId] = @OrganizationId; -- Create a temporary table to store distinct OrganizationUserIds - SELECT DISTINCT GU.[OrganizationUserId] - INTO #TempOrganizationUsers + DECLARE @Step1OrgUsersToBump [dbo].[GuidIdArray] + INSERT INTO @Step1OrgUsersToBump + SELECT DISTINCT GU.[OrganizationUserId] AS Id FROM [dbo].[GroupUser] GU - JOIN #TempGroup TG ON GU.[GroupId] = TG.[GroupId]; + INNER JOIN #TempGroup TG ON GU.[GroupId] = TG.[GroupId]; - BEGIN TRY - BEGIN TRANSACTION; - -- 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]; - - -- 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; - - -- Update Group to clear AccessAll flag - UPDATE G - SET [AccessAll] = 0 - FROM [dbo].[Group] G - INNER JOIN #TempGroup TG ON G.[Id] = TG.[GroupId] - - -- Execute User_BumpAccountRevisionDateByOrganizationUserId for each unique OrganizationUserId - DECLARE @Step1OrganizationUserId UNIQUEIDENTIFIER - - DECLARE UniqueOrgUserIdCursor CURSOR FOR - SELECT [OrganizationUserId] - FROM #TempOrganizationUsers - - OPEN UniqueOrgUserIdCursor - FETCH NEXT FROM UniqueOrgUserIdCursor INTO @Step1OrganizationUserId - - WHILE (@@FETCH_STATUS = 0) - BEGIN - -- Execute the stored procedure for the current OrganizationUserId - EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserId] @Step1OrganizationUserId - - -- Fetch the next row - FETCH NEXT FROM UniqueOrgUserIdCursor INTO @Step1OrganizationUserId - END - - CLOSE UniqueOrgUserIdCursor - DEALLOCATE UniqueOrgUserIdCursor; - COMMIT TRANSACTION; - END TRY - BEGIN CATCH - ROLLBACK TRANSACTION; - THROW; - END CATCH; - - -- Drop the temporary table - DROP TABLE #TempGroup; - DROP TABLE #TempOrganizationUsers; - - -- Step 2: AccessAll migration for users + -- Step 2: AccessAll migration for OrganizationUsers -- Create a temporary table to store the OrganizationUsers with AccessAll = 1 SELECT [Id] AS [OrganizationUserId], [OrganizationId] INTO #TempOrgUser @@ -85,70 +27,11 @@ BEGIN WHERE [AccessAll] = 1 AND [OrganizationId] = @OrganizationId; - BEGIN TRY - BEGIN TRANSACTION; - -- 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]; - - -- 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; - - -- Update OrganizationUser to clear AccessAll flag - UPDATE OU - SET [AccessAll] = 0 - FROM [dbo].[OrganizationUser] OU - INNER JOIN #TempOrgUser T ON OU.[Id] = T.[OrganizationUserId] - - -- Execute User_BumpAccountRevisionDateByOrganizationUserId for each unique OrganizationUserId - DECLARE @Step2OrganizationUserId UNIQUEIDENTIFIER - - DECLARE UniqueOrgUserIdCursor CURSOR FOR - SELECT DISTINCT [OrganizationUserId] - FROM #TempOrgUser - - OPEN UniqueOrgUserIdCursor - FETCH NEXT FROM UniqueOrgUserIdCursor INTO @Step2OrganizationUserId - - WHILE (@@FETCH_STATUS = 0) - BEGIN - -- Execute the stored procedure for the current OrganizationUserId - EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserId] @Step2OrganizationUserId - - -- Fetch the next row - FETCH NEXT FROM UniqueOrgUserIdCursor INTO @Step2OrganizationUserId - END - - CLOSE UniqueOrgUserIdCursor - DEALLOCATE UniqueOrgUserIdCursor; - COMMIT TRANSACTION; - END TRY - BEGIN CATCH - ROLLBACK TRANSACTION; - THROW; - END CATCH; - - -- Drop the temporary table - DROP TABLE #TempOrgUser; + -- Create a temporary table to store distinct OrganizationUserIds + DECLARE @Step2OrgUsersToBump [dbo].[GuidIdArray] + INSERT INTO @Step2OrgUsersToBump + SELECT DISTINCT [OrganizationUserId] AS Id + FROM #TempOrgUser; -- Step 3: For all OrganizationUsers with Manager role or 'EditAssignedCollections' permission update their existing CollectionUser rows and insert new rows with [Manage] = 1 -- and finally update all OrganizationUsers with Manager role to User role @@ -160,55 +43,108 @@ BEGIN WHERE ou.[OrganizationId] = @OrganizationId AND (ou.[Type] = 3 OR (ou.[Permissions] IS NOT NULL AND ISJSON(ou.[Permissions]) > 0 AND JSON_VALUE(ou.[Permissions], '$.editAssignedCollections') = 'true')); + -- Create a temporary table to store distinct OrganizationUserIds + DECLARE @Step3OrgUsersToBump [dbo].[GuidIdArray] + INSERT INTO @Step3OrgUsersToBump + SELECT DISTINCT [OrganizationUserId] AS Id + FROM #TempStep3; + BEGIN TRY BEGIN TRANSACTION; - -- 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 #TempStep3 temp ON cu.[OrganizationUserId] = temp.[OrganizationUserId]; + -- Step 1 + -- 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]; - -- Insert rows to [dbo].[CollectionUser] with [Manage] = 1 using the temporary table - INSERT INTO [dbo].[CollectionUser] ([CollectionId], [OrganizationUserId], [ReadOnly], [HidePasswords], [Manage]) - SELECT cg.[CollectionId], ou.[OrganizationUserId], 0, 0, 1 - FROM [dbo].[CollectionGroup] cg - INNER JOIN [dbo].[GroupUser] gu ON cg.[GroupId] = gu.[GroupId] - INNER JOIN #TempStep3 ou ON gu.[OrganizationUserId] = ou.[OrganizationUserId] - WHERE NOT EXISTS ( - SELECT 1 FROM [dbo].[CollectionUser] cu - WHERE cu.[CollectionId] = cg.[CollectionId] AND cu.[OrganizationUserId] = ou.[OrganizationUserId] - ); + -- 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; - -- Update [dbo].[OrganizationUser] to migrate all OrganizationUsers with Manager role to User role - UPDATE ou - SET ou.[Type] = 2 -- User - FROM [dbo].[OrganizationUser] ou - INNER JOIN #TempStep3 temp ON ou.[Id] = temp.[OrganizationUserId] - WHERE temp.[IsManager] = 1; -- Filter for Managers + -- Update Group to clear AccessAll flag + UPDATE G + SET [AccessAll] = 0 + FROM [dbo].[Group] G + INNER JOIN #TempGroup TG ON G.[Id] = TG.[GroupId]; - -- Execute User_BumpAccountRevisionDateByOrganizationUserId for each unique OrganizationUserId - DECLARE @Step3OrganizationUserId UNIQUEIDENTIFIER + -- Execute User_BumpAccountRevisionDateByOrganizationUserIds for the distinct OrganizationUserIds + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserIds] @Step1OrgUsersToBump; - DECLARE UniqueOrgUserIdCursor CURSOR FOR - SELECT [OrganizationUserId] - FROM #TempStep3 + -- 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]; - OPEN UniqueOrgUserIdCursor - FETCH NEXT FROM UniqueOrgUserIdCursor INTO @Step3OrganizationUserId + -- 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; - WHILE (@@FETCH_STATUS = 0) - BEGIN - -- Execute the stored procedure for the current OrganizationUserId - EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserId] @Step3OrganizationUserId + -- Update OrganizationUser to clear AccessAll flag + UPDATE OU + SET [AccessAll] = 0 + FROM [dbo].[OrganizationUser] OU + INNER JOIN #TempOrgUser T ON OU.[Id] = T.[OrganizationUserId]; - -- Fetch the next row - FETCH NEXT FROM UniqueOrgUserIdCursor INTO @Step3OrganizationUserId - END + -- Execute User_BumpAccountRevisionDateByOrganizationUserIds for the distinct OrganizationUserIds + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserIds] @Step2OrgUsersToBump; - CLOSE UniqueOrgUserIdCursor - DEALLOCATE UniqueOrgUserIdCursor; + -- Step 3 + -- 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 #TempStep3 temp ON cu.[OrganizationUserId] = temp.[OrganizationUserId]; + + -- Insert rows to [dbo].[CollectionUser] with [Manage] = 1 using the temporary table + INSERT INTO [dbo].[CollectionUser] ([CollectionId], [OrganizationUserId], [ReadOnly], [HidePasswords], [Manage]) + SELECT cg.[CollectionId], ou.[OrganizationUserId], 0, 0, 1 + FROM [dbo].[CollectionGroup] cg + INNER JOIN [dbo].[GroupUser] gu ON cg.[GroupId] = gu.[GroupId] + INNER JOIN #TempStep3 ou ON gu.[OrganizationUserId] = ou.[OrganizationUserId] + WHERE NOT EXISTS ( + SELECT 1 FROM [dbo].[CollectionUser] cu + WHERE cu.[CollectionId] = cg.[CollectionId] AND cu.[OrganizationUserId] = ou.[OrganizationUserId] + ); + + -- Update [dbo].[OrganizationUser] to migrate all OrganizationUsers with Manager role to User role + UPDATE ou + SET ou.[Type] = 2 -- User + FROM [dbo].[OrganizationUser] ou + INNER JOIN #TempStep3 temp ON ou.[Id] = temp.[OrganizationUserId] + WHERE temp.[IsManager] = 1; -- Filter for Managers + + -- Execute User_BumpAccountRevisionDateByOrganizationUserIds for the distinct OrganizationUserIds + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserIds] @Step3OrgUsersToBump; COMMIT TRANSACTION; END TRY BEGIN CATCH @@ -217,6 +153,8 @@ BEGIN END CATCH; -- Drop the temporary table + DROP TABLE #TempGroup; + DROP TABLE #TempOrgUser; DROP TABLE #TempStep3; END GO diff --git a/util/Migrator/DbScripts/2024-01-11_00_Organization_EnableCollectionEnhancements.sql b/util/Migrator/DbScripts/2024-01-11_00_Organization_EnableCollectionEnhancements.sql index ad08c79985..fdee59f381 100644 --- a/util/Migrator/DbScripts/2024-01-11_00_Organization_EnableCollectionEnhancements.sql +++ b/util/Migrator/DbScripts/2024-01-11_00_Organization_EnableCollectionEnhancements.sql @@ -13,71 +13,13 @@ BEGIN AND [OrganizationId] = @OrganizationId; -- Create a temporary table to store distinct OrganizationUserIds - SELECT DISTINCT GU.[OrganizationUserId] - INTO #TempOrganizationUsers + DECLARE @Step1OrgUsersToBump [dbo].[GuidIdArray] + INSERT INTO @Step1OrgUsersToBump + SELECT DISTINCT GU.[OrganizationUserId] AS Id FROM [dbo].[GroupUser] GU - JOIN #TempGroup TG ON GU.[GroupId] = TG.[GroupId]; + INNER JOIN #TempGroup TG ON GU.[GroupId] = TG.[GroupId]; - BEGIN TRY - BEGIN TRANSACTION; - -- 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]; - - -- 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; - - -- Update Group to clear AccessAll flag - UPDATE G - SET [AccessAll] = 0 - FROM [dbo].[Group] G - INNER JOIN #TempGroup TG ON G.[Id] = TG.[GroupId] - - -- Execute User_BumpAccountRevisionDateByOrganizationUserId for each unique OrganizationUserId - DECLARE @Step1OrganizationUserId UNIQUEIDENTIFIER - - DECLARE UniqueOrgUserIdCursor CURSOR FOR - SELECT [OrganizationUserId] - FROM #TempOrganizationUsers - - OPEN UniqueOrgUserIdCursor - FETCH NEXT FROM UniqueOrgUserIdCursor INTO @Step1OrganizationUserId - - WHILE (@@FETCH_STATUS = 0) - BEGIN - -- Execute the stored procedure for the current OrganizationUserId - EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserId] @Step1OrganizationUserId - - -- Fetch the next row - FETCH NEXT FROM UniqueOrgUserIdCursor INTO @Step1OrganizationUserId - END - - CLOSE UniqueOrgUserIdCursor - DEALLOCATE UniqueOrgUserIdCursor; - COMMIT TRANSACTION; - END TRY - BEGIN CATCH - ROLLBACK TRANSACTION; - THROW; - END CATCH; - - -- Drop the temporary table - DROP TABLE #TempGroup; - DROP TABLE #TempOrganizationUsers; - - -- Step 2: AccessAll migration for users + -- Step 2: AccessAll migration for OrganizationUsers -- Create a temporary table to store the OrganizationUsers with AccessAll = 1 SELECT [Id] AS [OrganizationUserId], [OrganizationId] INTO #TempOrgUser @@ -85,70 +27,11 @@ BEGIN WHERE [AccessAll] = 1 AND [OrganizationId] = @OrganizationId; - BEGIN TRY - BEGIN TRANSACTION; - -- 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]; - - -- 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; - - -- Update OrganizationUser to clear AccessAll flag - UPDATE OU - SET [AccessAll] = 0 - FROM [dbo].[OrganizationUser] OU - INNER JOIN #TempOrgUser T ON OU.[Id] = T.[OrganizationUserId] - - -- Execute User_BumpAccountRevisionDateByOrganizationUserId for each unique OrganizationUserId - DECLARE @Step2OrganizationUserId UNIQUEIDENTIFIER - - DECLARE UniqueOrgUserIdCursor CURSOR FOR - SELECT DISTINCT [OrganizationUserId] - FROM #TempOrgUser - - OPEN UniqueOrgUserIdCursor - FETCH NEXT FROM UniqueOrgUserIdCursor INTO @Step2OrganizationUserId - - WHILE (@@FETCH_STATUS = 0) - BEGIN - -- Execute the stored procedure for the current OrganizationUserId - EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserId] @Step2OrganizationUserId - - -- Fetch the next row - FETCH NEXT FROM UniqueOrgUserIdCursor INTO @Step2OrganizationUserId - END - - CLOSE UniqueOrgUserIdCursor - DEALLOCATE UniqueOrgUserIdCursor; - COMMIT TRANSACTION; - END TRY - BEGIN CATCH - ROLLBACK TRANSACTION; - THROW; - END CATCH; - - -- Drop the temporary table - DROP TABLE #TempOrgUser; + -- Create a temporary table to store distinct OrganizationUserIds + DECLARE @Step2OrgUsersToBump [dbo].[GuidIdArray] + INSERT INTO @Step2OrgUsersToBump + SELECT DISTINCT [OrganizationUserId] AS Id + FROM #TempOrgUser; -- Step 3: For all OrganizationUsers with Manager role or 'EditAssignedCollections' permission update their existing CollectionUser rows and insert new rows with [Manage] = 1 -- and finally update all OrganizationUsers with Manager role to User role @@ -160,55 +43,108 @@ BEGIN WHERE ou.[OrganizationId] = @OrganizationId AND (ou.[Type] = 3 OR (ou.[Permissions] IS NOT NULL AND ISJSON(ou.[Permissions]) > 0 AND JSON_VALUE(ou.[Permissions], '$.editAssignedCollections') = 'true')); + -- Create a temporary table to store distinct OrganizationUserIds + DECLARE @Step3OrgUsersToBump [dbo].[GuidIdArray] + INSERT INTO @Step3OrgUsersToBump + SELECT DISTINCT [OrganizationUserId] AS Id + FROM #TempStep3; + BEGIN TRY BEGIN TRANSACTION; - -- 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 #TempStep3 temp ON cu.[OrganizationUserId] = temp.[OrganizationUserId]; + -- Step 1 + -- 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]; - -- Insert rows to [dbo].[CollectionUser] with [Manage] = 1 using the temporary table - INSERT INTO [dbo].[CollectionUser] ([CollectionId], [OrganizationUserId], [ReadOnly], [HidePasswords], [Manage]) - SELECT cg.[CollectionId], ou.[OrganizationUserId], 0, 0, 1 - FROM [dbo].[CollectionGroup] cg - INNER JOIN [dbo].[GroupUser] gu ON cg.[GroupId] = gu.[GroupId] - INNER JOIN #TempStep3 ou ON gu.[OrganizationUserId] = ou.[OrganizationUserId] - WHERE NOT EXISTS ( - SELECT 1 FROM [dbo].[CollectionUser] cu - WHERE cu.[CollectionId] = cg.[CollectionId] AND cu.[OrganizationUserId] = ou.[OrganizationUserId] - ); + -- 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; - -- Update [dbo].[OrganizationUser] to migrate all OrganizationUsers with Manager role to User role - UPDATE ou - SET ou.[Type] = 2 -- User - FROM [dbo].[OrganizationUser] ou - INNER JOIN #TempStep3 temp ON ou.[Id] = temp.[OrganizationUserId] - WHERE temp.[IsManager] = 1; -- Filter for Managers + -- Update Group to clear AccessAll flag + UPDATE G + SET [AccessAll] = 0 + FROM [dbo].[Group] G + INNER JOIN #TempGroup TG ON G.[Id] = TG.[GroupId]; - -- Execute User_BumpAccountRevisionDateByOrganizationUserId for each unique OrganizationUserId - DECLARE @Step3OrganizationUserId UNIQUEIDENTIFIER + -- Execute User_BumpAccountRevisionDateByOrganizationUserIds for the distinct OrganizationUserIds + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserIds] @Step1OrgUsersToBump; - DECLARE UniqueOrgUserIdCursor CURSOR FOR - SELECT [OrganizationUserId] - FROM #TempStep3 + -- 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]; - OPEN UniqueOrgUserIdCursor - FETCH NEXT FROM UniqueOrgUserIdCursor INTO @Step3OrganizationUserId + -- 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; - WHILE (@@FETCH_STATUS = 0) - BEGIN - -- Execute the stored procedure for the current OrganizationUserId - EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserId] @Step3OrganizationUserId + -- Update OrganizationUser to clear AccessAll flag + UPDATE OU + SET [AccessAll] = 0 + FROM [dbo].[OrganizationUser] OU + INNER JOIN #TempOrgUser T ON OU.[Id] = T.[OrganizationUserId]; - -- Fetch the next row - FETCH NEXT FROM UniqueOrgUserIdCursor INTO @Step3OrganizationUserId - END + -- Execute User_BumpAccountRevisionDateByOrganizationUserIds for the distinct OrganizationUserIds + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserIds] @Step2OrgUsersToBump; - CLOSE UniqueOrgUserIdCursor - DEALLOCATE UniqueOrgUserIdCursor; + -- Step 3 + -- 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 #TempStep3 temp ON cu.[OrganizationUserId] = temp.[OrganizationUserId]; + + -- Insert rows to [dbo].[CollectionUser] with [Manage] = 1 using the temporary table + INSERT INTO [dbo].[CollectionUser] ([CollectionId], [OrganizationUserId], [ReadOnly], [HidePasswords], [Manage]) + SELECT cg.[CollectionId], ou.[OrganizationUserId], 0, 0, 1 + FROM [dbo].[CollectionGroup] cg + INNER JOIN [dbo].[GroupUser] gu ON cg.[GroupId] = gu.[GroupId] + INNER JOIN #TempStep3 ou ON gu.[OrganizationUserId] = ou.[OrganizationUserId] + WHERE NOT EXISTS ( + SELECT 1 FROM [dbo].[CollectionUser] cu + WHERE cu.[CollectionId] = cg.[CollectionId] AND cu.[OrganizationUserId] = ou.[OrganizationUserId] + ); + + -- Update [dbo].[OrganizationUser] to migrate all OrganizationUsers with Manager role to User role + UPDATE ou + SET ou.[Type] = 2 -- User + FROM [dbo].[OrganizationUser] ou + INNER JOIN #TempStep3 temp ON ou.[Id] = temp.[OrganizationUserId] + WHERE temp.[IsManager] = 1; -- Filter for Managers + + -- Execute User_BumpAccountRevisionDateByOrganizationUserIds for the distinct OrganizationUserIds + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserIds] @Step3OrgUsersToBump; COMMIT TRANSACTION; END TRY BEGIN CATCH @@ -217,6 +153,8 @@ BEGIN END CATCH; -- Drop the temporary table + DROP TABLE #TempGroup; + DROP TABLE #TempOrgUser; DROP TABLE #TempStep3; END GO