mirror of
https://github.com/bitwarden/server
synced 2025-12-21 10:43:44 +00:00
[AC-1682] Updated sql data migration procedures with performance recommendations
This commit is contained in:
@@ -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]
|
SELECT [Id] AS [GroupId], [OrganizationId]
|
||||||
INTO #TempGroup
|
INTO #TempGroup
|
||||||
FROM [dbo].[Group]
|
FROM [dbo].[Group]
|
||||||
WHERE [AccessAll] = 1;
|
WHERE [AccessAll] = 1;
|
||||||
|
|
||||||
-- Step 2: Declare variables for GroupId and OrganizationId
|
-- Update existing rows in [dbo].[CollectionGroup]
|
||||||
DECLARE @GroupId UNIQUEIDENTIFIER;
|
UPDATE CG
|
||||||
DECLARE @OrganizationId UNIQUEIDENTIFIER;
|
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
|
-- Insert new rows into [dbo].[CollectionGroup]
|
||||||
DECLARE GroupCursor CURSOR FOR
|
INSERT INTO [dbo].[CollectionGroup] ([CollectionId], [GroupId], [ReadOnly], [HidePasswords], [Manage])
|
||||||
SELECT [GroupId], [OrganizationId]
|
SELECT C.[Id], TG.[GroupId], 0, 0, 1
|
||||||
FROM #TempGroup;
|
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;
|
-- Drop the temporary table
|
||||||
|
|
||||||
-- 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 TABLE #TempGroup;
|
DROP TABLE #TempGroup;
|
||||||
|
|||||||
@@ -1,45 +1,45 @@
|
|||||||
-- Step 1: Retrieve OrganizationUsers with [AccessAll] permission
|
-- 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]
|
SELECT [Id] AS [OrganizationUserId], [OrganizationId], CAST(ROW_NUMBER() OVER(ORDER BY [Id]) / 50000 AS INT) AS Batch
|
||||||
INTO #TempOrgUser
|
INTO #TempOrgUser
|
||||||
FROM [dbo].[OrganizationUser]
|
FROM [dbo].[OrganizationUser]
|
||||||
WHERE [AccessAll] = 1;
|
WHERE [AccessAll] = 1;
|
||||||
|
|
||||||
-- Step 2: Declare variables for OrganizationUserId and OrganizationId
|
-- Step 2: Get the maximum batch number
|
||||||
DECLARE @OrgUserId UNIQUEIDENTIFIER;
|
DECLARE @MaxBatch INT = (SELECT MAX(Batch) FROM #TempOrgUser);
|
||||||
DECLARE @OrganizationId UNIQUEIDENTIFIER;
|
DECLARE @CurrentBatch INT = 0;
|
||||||
|
|
||||||
-- Step 3: Create a cursor to iterate through the results of the temporary table
|
-- Step 3: Process each batch
|
||||||
DECLARE OrgUserCursor CURSOR FOR
|
WHILE @CurrentBatch <= @MaxBatch
|
||||||
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
|
|
||||||
BEGIN
|
BEGIN
|
||||||
-- Step 5: Use MERGE to insert or update into [dbo].[CollectionUser] for each [dbo].[Collection] entry
|
-- Update existing rows in [dbo].[CollectionUser]
|
||||||
MERGE INTO [dbo].[CollectionUser] AS target
|
UPDATE target
|
||||||
USING (SELECT C.[Id] AS [CollectionId], @OrgUserId AS [OrganizationUserId] FROM [dbo].[Collection] C WHERE C.[OrganizationId] = @OrganizationId) AS source
|
SET
|
||||||
ON (target.[CollectionId] = source.[CollectionId] AND target.[OrganizationUserId] = source.[OrganizationUserId])
|
target.[ReadOnly] = 0,
|
||||||
WHEN MATCHED THEN
|
target.[HidePasswords] = 0,
|
||||||
UPDATE SET
|
target.[Manage] = 1
|
||||||
target.[ReadOnly] = 0,
|
FROM [dbo].[CollectionUser] AS target
|
||||||
target.[HidePasswords] = 0,
|
JOIN (
|
||||||
target.[Manage] = 1
|
SELECT C.[Id] AS [CollectionId], T.[OrganizationUserId]
|
||||||
WHEN NOT MATCHED THEN
|
FROM [dbo].[Collection] C
|
||||||
INSERT ([CollectionId], [OrganizationUserId], [ReadOnly], [HidePasswords], [Manage])
|
JOIN #TempOrgUser T ON C.[OrganizationId] = T.[OrganizationId] AND T.Batch = @CurrentBatch
|
||||||
VALUES (source.[CollectionId], source.[OrganizationUserId], 0, 0, 1);
|
) AS source
|
||||||
|
ON target.[CollectionId] = source.[CollectionId] AND target.[OrganizationUserId] = source.[OrganizationUserId];
|
||||||
|
|
||||||
-- Step 6: Fetch the next OrganizationUserId and OrganizationId
|
-- Insert new rows into [dbo].[CollectionUser]
|
||||||
FETCH NEXT FROM OrgUserCursor INTO @OrgUserId, @OrganizationId;
|
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;
|
END;
|
||||||
|
|
||||||
-- Step 7: Close and deallocate the cursor
|
-- Step 4: Drop the temporary table
|
||||||
CLOSE OrgUserCursor;
|
|
||||||
DEALLOCATE OrgUserCursor;
|
|
||||||
|
|
||||||
-- Step 8: Drop the temporary table
|
|
||||||
DROP TABLE #TempOrgUser;
|
DROP TABLE #TempOrgUser;
|
||||||
|
|||||||
Reference in New Issue
Block a user