diff --git a/util/Migrator/DbScripts_transition/2024-01-10_01_AccessAllCollectionUsers.sql b/util/Migrator/DbScripts_transition/2024-01-10_01_AccessAllCollectionUsers.sql index 7b663d1ba..ac1b81726 100644 --- a/util/Migrator/DbScripts_transition/2024-01-10_01_AccessAllCollectionUsers.sql +++ b/util/Migrator/DbScripts_transition/2024-01-10_01_AccessAllCollectionUsers.sql @@ -1,34 +1,45 @@ --- Step 1: Create a temporary table to store the OrganizationUsers with AccessAll = 1 -SELECT [Id] AS [OrganizationUserId], [OrganizationId] +-- Step 1: Insert into a temporary table with an additional column for batch processing, update 50 k at a time +SELECT [Id] AS [OrganizationUserId], [OrganizationId], CAST(ROW_NUMBER() OVER(ORDER BY [Id]) / 50000 AS INT) AS Batch 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 +-- Step 2: Get the maximum batch number +DECLARE @MaxBatch INT = (SELECT MAX(Batch) FROM #TempOrgUser); +DECLARE @CurrentBatch INT = 0; + +-- Step 3: Process each batch +WHILE @CurrentBatch <= @MaxBatch +BEGIN + -- 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] AND T.Batch = @CurrentBatch + ) 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 + -- 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] AND T.Batch = @CurrentBatch + ) AS source + LEFT JOIN [dbo].[CollectionUser] AS target ON target.[CollectionId] = source.[CollectionId] AND target.[OrganizationUserId] = source.[OrganizationUserId] -WHERE target.[CollectionId] IS NULL; + WHERE target.[CollectionId] IS NULL; + + -- Move to the next batch + SET @CurrentBatch = @CurrentBatch + 1; +END; -- Step 4: Update [dbo].[OrganizationUser] to clear AccessAll flag UPDATE OU