From 577e591068d67e9b8a6d072a97727c60fcde1829 Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Mon, 13 Nov 2023 12:18:14 +0000 Subject: [PATCH] [AC-1682] Updated sql data migration procedures with performance recommendations --- ...023-11-10_00_AccessAllCollectionGroups.sql | 56 +++++---------- ...2023-11-10_00_AccessAllCollectionUsers.sql | 70 +++++++++---------- 2 files changed, 54 insertions(+), 72 deletions(-) diff --git a/util/Migrator/DbScripts/2023-11-10_00_AccessAllCollectionGroups.sql b/util/Migrator/DbScripts/2023-11-10_00_AccessAllCollectionGroups.sql index 5ad58f2bb0..4e3a6443ad 100644 --- a/util/Migrator/DbScripts/2023-11-10_00_AccessAllCollectionGroups.sql +++ b/util/Migrator/DbScripts/2023-11-10_00_AccessAllCollectionGroups.sql @@ -1,45 +1,27 @@ --- Step 1: Retrieve Groups with [AccessAll] permission +-- 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: Declare variables for GroupId and OrganizationId -DECLARE @GroupId UNIQUEIDENTIFIER; -DECLARE @OrganizationId UNIQUEIDENTIFIER; +-- Update existing rows in [dbo].[CollectionGroup] +UPDATE CG +SET + CG.[ReadOnly] = 0, + CG.[HidePasswords] = 0, + CG.[Manage] = 1 + 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: Create a cursor to iterate through the results of the temporary table -DECLARE GroupCursor CURSOR FOR -SELECT [GroupId], [OrganizationId] -FROM #TempGroup; +-- Insert new rows into [dbo].[CollectionGroup] +INSERT INTO [dbo].[CollectionGroup] ([CollectionId], [GroupId], [ReadOnly], [HidePasswords], [Manage]) +SELECT C.[Id], TG.[GroupId], 0, 0, 1 +FROM [dbo].[Collection] C + 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; -OPEN GroupCursor; - --- Step 4: Loop through the groups -FETCH NEXT FROM GroupCursor INTO @GroupId, @OrganizationId; - -WHILE @@FETCH_STATUS = 0 -BEGIN - -- Step 5: Use MERGE to insert or update into [dbo].[CollectionGroup] for each [dbo].[Collection] entry -MERGE INTO [dbo].[CollectionGroup] AS target - USING (SELECT C.[Id] AS [CollectionId], @GroupId AS [GroupId] FROM [dbo].[Collection] C WHERE C.[OrganizationId] = @OrganizationId) AS source - ON (target.[CollectionId] = source.[CollectionId] AND target.[GroupId] = source.[GroupId]) - WHEN MATCHED THEN -UPDATE SET - target.[ReadOnly] = 0, - target.[HidePasswords] = 0, - target.[Manage] = 1 - WHEN NOT MATCHED THEN -INSERT ([CollectionId], [GroupId], [ReadOnly], [HidePasswords], [Manage]) -VALUES (source.[CollectionId], source.[GroupId], 0, 0, 1); - --- Step 6: Fetch the next GroupId and OrganizationId -FETCH NEXT FROM GroupCursor INTO @GroupId, @OrganizationId; -END; - --- Step 7: Close and deallocate the cursor -CLOSE GroupCursor; -DEALLOCATE GroupCursor; - --- Step 8: Drop the temporary table +-- Drop the temporary table DROP TABLE #TempGroup; diff --git a/util/Migrator/DbScripts/2023-11-10_00_AccessAllCollectionUsers.sql b/util/Migrator/DbScripts/2023-11-10_00_AccessAllCollectionUsers.sql index 757080136c..06fd476a58 100644 --- a/util/Migrator/DbScripts/2023-11-10_00_AccessAllCollectionUsers.sql +++ b/util/Migrator/DbScripts/2023-11-10_00_AccessAllCollectionUsers.sql @@ -1,45 +1,45 @@ --- Step 1: Retrieve OrganizationUsers with [AccessAll] permission -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: Declare variables for OrganizationUserId and OrganizationId -DECLARE @OrgUserId UNIQUEIDENTIFIER; -DECLARE @OrganizationId UNIQUEIDENTIFIER; +-- Step 2: Get the maximum batch number +DECLARE @MaxBatch INT = (SELECT MAX(Batch) FROM #TempOrgUser); +DECLARE @CurrentBatch INT = 0; --- Step 3: Create a cursor to iterate through the results of the temporary table -DECLARE OrgUserCursor CURSOR FOR -SELECT [OrganizationUserId], [OrganizationId] -FROM #TempOrgUser; - -OPEN OrgUserCursor; - --- Step 4: Loop through the organization users -FETCH NEXT FROM OrgUserCursor INTO @OrgUserId, @OrganizationId; - -WHILE @@FETCH_STATUS = 0 +-- Step 3: Process each batch +WHILE @CurrentBatch <= @MaxBatch BEGIN - -- Step 5: Use MERGE to insert or update into [dbo].[CollectionUser] for each [dbo].[Collection] entry -MERGE INTO [dbo].[CollectionUser] AS target - USING (SELECT C.[Id] AS [CollectionId], @OrgUserId AS [OrganizationUserId] FROM [dbo].[Collection] C WHERE C.[OrganizationId] = @OrganizationId) AS source - ON (target.[CollectionId] = source.[CollectionId] AND target.[OrganizationUserId] = source.[OrganizationUserId]) - WHEN MATCHED THEN -UPDATE SET - target.[ReadOnly] = 0, - target.[HidePasswords] = 0, - target.[Manage] = 1 - WHEN NOT MATCHED THEN -INSERT ([CollectionId], [OrganizationUserId], [ReadOnly], [HidePasswords], [Manage]) -VALUES (source.[CollectionId], source.[OrganizationUserId], 0, 0, 1); + -- Update existing rows in [dbo].[CollectionUser] + UPDATE target + SET + target.[ReadOnly] = 0, + target.[HidePasswords] = 0, + target.[Manage] = 1 + FROM [dbo].[CollectionUser] AS target + JOIN ( + SELECT C.[Id] AS [CollectionId], T.[OrganizationUserId] + FROM [dbo].[Collection] C + 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 6: Fetch the next OrganizationUserId and OrganizationId -FETCH NEXT FROM OrgUserCursor INTO @OrgUserId, @OrganizationId; + -- Insert new rows into [dbo].[CollectionUser] + INSERT INTO [dbo].[CollectionUser] ([CollectionId], [OrganizationUserId], [ReadOnly], [HidePasswords], [Manage]) + SELECT source.[CollectionId], source.[OrganizationUserId], 0, 0, 1 + FROM ( + SELECT C.[Id] AS [CollectionId], T.[OrganizationUserId] + FROM [dbo].[Collection] C + 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; + + -- Move to the next batch + SET @CurrentBatch = @CurrentBatch + 1; END; --- Step 7: Close and deallocate the cursor -CLOSE OrgUserCursor; -DEALLOCATE OrgUserCursor; - --- Step 8: Drop the temporary table +-- Step 4: Drop the temporary table DROP TABLE #TempOrgUser;