1
0
mirror of https://github.com/bitwarden/server.git synced 2025-07-03 00:52:49 -05:00

[AC-1682] Modified data migration script to have just one big transaction

This commit is contained in:
Rui Tome
2024-01-18 16:07:15 +00:00
parent 95977b1263
commit 160fc3edd0
2 changed files with 208 additions and 332 deletions

View File

@ -13,13 +13,45 @@ BEGIN
AND [OrganizationId] = @OrganizationId; AND [OrganizationId] = @OrganizationId;
-- Create a temporary table to store distinct OrganizationUserIds -- Create a temporary table to store distinct OrganizationUserIds
SELECT DISTINCT GU.[OrganizationUserId] DECLARE @Step1OrgUsersToBump [dbo].[GuidIdArray]
INTO #TempOrganizationUsers INSERT INTO @Step1OrgUsersToBump
SELECT DISTINCT GU.[OrganizationUserId] AS Id
FROM [dbo].[GroupUser] GU FROM [dbo].[GroupUser] GU
JOIN #TempGroup TG ON GU.[GroupId] = TG.[GroupId]; INNER JOIN #TempGroup TG ON GU.[GroupId] = TG.[GroupId];
-- Step 2: AccessAll migration for OrganizationUsers
-- Create a temporary table to store the OrganizationUsers with AccessAll = 1
SELECT [Id] AS [OrganizationUserId], [OrganizationId]
INTO #TempOrgUser
FROM [dbo].[OrganizationUser]
WHERE [AccessAll] = 1
AND [OrganizationId] = @OrganizationId;
-- 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
-- Create a temporary table to store the OrganizationUsers with Manager role or 'EditAssignedCollections' permission
SELECT ou.[Id] AS [OrganizationUserId],
CASE WHEN ou.[Type] = 3 THEN 1 ELSE 0 END AS [IsManager]
INTO #TempStep3
FROM [dbo].[OrganizationUser] ou
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 TRY
BEGIN TRANSACTION; BEGIN TRANSACTION;
-- Step 1
-- Update existing rows in [dbo].[CollectionGroup] -- Update existing rows in [dbo].[CollectionGroup]
UPDATE CG UPDATE CG
SET SET
@ -43,50 +75,12 @@ BEGIN
UPDATE G UPDATE G
SET [AccessAll] = 0 SET [AccessAll] = 0
FROM [dbo].[Group] G FROM [dbo].[Group] G
INNER JOIN #TempGroup TG ON G.[Id] = TG.[GroupId] INNER JOIN #TempGroup TG ON G.[Id] = TG.[GroupId];
-- Execute User_BumpAccountRevisionDateByOrganizationUserId for each unique OrganizationUserId -- Execute User_BumpAccountRevisionDateByOrganizationUserIds for the distinct OrganizationUserIds
DECLARE @Step1OrganizationUserId UNIQUEIDENTIFIER EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserIds] @Step1OrgUsersToBump;
DECLARE UniqueOrgUserIdCursor CURSOR FOR -- Step 2
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
-- Create a temporary table to store the OrganizationUsers with AccessAll = 1
SELECT [Id] AS [OrganizationUserId], [OrganizationId]
INTO #TempOrgUser
FROM [dbo].[OrganizationUser]
WHERE [AccessAll] = 1
AND [OrganizationId] = @OrganizationId;
BEGIN TRY
BEGIN TRANSACTION;
-- Update existing rows in [dbo].[CollectionUser] -- Update existing rows in [dbo].[CollectionUser]
UPDATE target UPDATE target
SET SET
@ -117,51 +111,12 @@ BEGIN
UPDATE OU UPDATE OU
SET [AccessAll] = 0 SET [AccessAll] = 0
FROM [dbo].[OrganizationUser] OU FROM [dbo].[OrganizationUser] OU
INNER JOIN #TempOrgUser T ON OU.[Id] = T.[OrganizationUserId] INNER JOIN #TempOrgUser T ON OU.[Id] = T.[OrganizationUserId];
-- Execute User_BumpAccountRevisionDateByOrganizationUserId for each unique OrganizationUserId -- Execute User_BumpAccountRevisionDateByOrganizationUserIds for the distinct OrganizationUserIds
DECLARE @Step2OrganizationUserId UNIQUEIDENTIFIER EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserIds] @Step2OrgUsersToBump;
DECLARE UniqueOrgUserIdCursor CURSOR FOR -- Step 3
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;
-- 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
-- Create a temporary table to store the OrganizationUsers with Manager role or 'EditAssignedCollections' permission
SELECT ou.[Id] AS [OrganizationUserId],
CASE WHEN ou.[Type] = 3 THEN 1 ELSE 0 END AS [IsManager]
INTO #TempStep3
FROM [dbo].[OrganizationUser] ou
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'));
BEGIN TRY
BEGIN TRANSACTION;
-- Update [dbo].[CollectionUser] with [Manage] = 1 using the temporary table -- Update [dbo].[CollectionUser] with [Manage] = 1 using the temporary table
UPDATE cu UPDATE cu
SET cu.[ReadOnly] = 0, SET cu.[ReadOnly] = 0,
@ -188,27 +143,8 @@ BEGIN
INNER JOIN #TempStep3 temp ON ou.[Id] = temp.[OrganizationUserId] INNER JOIN #TempStep3 temp ON ou.[Id] = temp.[OrganizationUserId]
WHERE temp.[IsManager] = 1; -- Filter for Managers WHERE temp.[IsManager] = 1; -- Filter for Managers
-- Execute User_BumpAccountRevisionDateByOrganizationUserId for each unique OrganizationUserId -- Execute User_BumpAccountRevisionDateByOrganizationUserIds for the distinct OrganizationUserIds
DECLARE @Step3OrganizationUserId UNIQUEIDENTIFIER EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserIds] @Step3OrgUsersToBump;
DECLARE UniqueOrgUserIdCursor CURSOR FOR
SELECT [OrganizationUserId]
FROM #TempStep3
OPEN UniqueOrgUserIdCursor
FETCH NEXT FROM UniqueOrgUserIdCursor INTO @Step3OrganizationUserId
WHILE (@@FETCH_STATUS = 0)
BEGIN
-- Execute the stored procedure for the current OrganizationUserId
EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserId] @Step3OrganizationUserId
-- Fetch the next row
FETCH NEXT FROM UniqueOrgUserIdCursor INTO @Step3OrganizationUserId
END
CLOSE UniqueOrgUserIdCursor
DEALLOCATE UniqueOrgUserIdCursor;
COMMIT TRANSACTION; COMMIT TRANSACTION;
END TRY END TRY
BEGIN CATCH BEGIN CATCH
@ -217,6 +153,8 @@ BEGIN
END CATCH; END CATCH;
-- Drop the temporary table -- Drop the temporary table
DROP TABLE #TempGroup;
DROP TABLE #TempOrgUser;
DROP TABLE #TempStep3; DROP TABLE #TempStep3;
END END
GO GO

View File

@ -13,13 +13,45 @@ BEGIN
AND [OrganizationId] = @OrganizationId; AND [OrganizationId] = @OrganizationId;
-- Create a temporary table to store distinct OrganizationUserIds -- Create a temporary table to store distinct OrganizationUserIds
SELECT DISTINCT GU.[OrganizationUserId] DECLARE @Step1OrgUsersToBump [dbo].[GuidIdArray]
INTO #TempOrganizationUsers INSERT INTO @Step1OrgUsersToBump
SELECT DISTINCT GU.[OrganizationUserId] AS Id
FROM [dbo].[GroupUser] GU FROM [dbo].[GroupUser] GU
JOIN #TempGroup TG ON GU.[GroupId] = TG.[GroupId]; INNER JOIN #TempGroup TG ON GU.[GroupId] = TG.[GroupId];
-- Step 2: AccessAll migration for OrganizationUsers
-- Create a temporary table to store the OrganizationUsers with AccessAll = 1
SELECT [Id] AS [OrganizationUserId], [OrganizationId]
INTO #TempOrgUser
FROM [dbo].[OrganizationUser]
WHERE [AccessAll] = 1
AND [OrganizationId] = @OrganizationId;
-- 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
-- Create a temporary table to store the OrganizationUsers with Manager role or 'EditAssignedCollections' permission
SELECT ou.[Id] AS [OrganizationUserId],
CASE WHEN ou.[Type] = 3 THEN 1 ELSE 0 END AS [IsManager]
INTO #TempStep3
FROM [dbo].[OrganizationUser] ou
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 TRY
BEGIN TRANSACTION; BEGIN TRANSACTION;
-- Step 1
-- Update existing rows in [dbo].[CollectionGroup] -- Update existing rows in [dbo].[CollectionGroup]
UPDATE CG UPDATE CG
SET SET
@ -43,50 +75,12 @@ BEGIN
UPDATE G UPDATE G
SET [AccessAll] = 0 SET [AccessAll] = 0
FROM [dbo].[Group] G FROM [dbo].[Group] G
INNER JOIN #TempGroup TG ON G.[Id] = TG.[GroupId] INNER JOIN #TempGroup TG ON G.[Id] = TG.[GroupId];
-- Execute User_BumpAccountRevisionDateByOrganizationUserId for each unique OrganizationUserId -- Execute User_BumpAccountRevisionDateByOrganizationUserIds for the distinct OrganizationUserIds
DECLARE @Step1OrganizationUserId UNIQUEIDENTIFIER EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserIds] @Step1OrgUsersToBump;
DECLARE UniqueOrgUserIdCursor CURSOR FOR -- Step 2
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
-- Create a temporary table to store the OrganizationUsers with AccessAll = 1
SELECT [Id] AS [OrganizationUserId], [OrganizationId]
INTO #TempOrgUser
FROM [dbo].[OrganizationUser]
WHERE [AccessAll] = 1
AND [OrganizationId] = @OrganizationId;
BEGIN TRY
BEGIN TRANSACTION;
-- Update existing rows in [dbo].[CollectionUser] -- Update existing rows in [dbo].[CollectionUser]
UPDATE target UPDATE target
SET SET
@ -117,51 +111,12 @@ BEGIN
UPDATE OU UPDATE OU
SET [AccessAll] = 0 SET [AccessAll] = 0
FROM [dbo].[OrganizationUser] OU FROM [dbo].[OrganizationUser] OU
INNER JOIN #TempOrgUser T ON OU.[Id] = T.[OrganizationUserId] INNER JOIN #TempOrgUser T ON OU.[Id] = T.[OrganizationUserId];
-- Execute User_BumpAccountRevisionDateByOrganizationUserId for each unique OrganizationUserId -- Execute User_BumpAccountRevisionDateByOrganizationUserIds for the distinct OrganizationUserIds
DECLARE @Step2OrganizationUserId UNIQUEIDENTIFIER EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserIds] @Step2OrgUsersToBump;
DECLARE UniqueOrgUserIdCursor CURSOR FOR -- Step 3
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;
-- 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
-- Create a temporary table to store the OrganizationUsers with Manager role or 'EditAssignedCollections' permission
SELECT ou.[Id] AS [OrganizationUserId],
CASE WHEN ou.[Type] = 3 THEN 1 ELSE 0 END AS [IsManager]
INTO #TempStep3
FROM [dbo].[OrganizationUser] ou
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'));
BEGIN TRY
BEGIN TRANSACTION;
-- Update [dbo].[CollectionUser] with [Manage] = 1 using the temporary table -- Update [dbo].[CollectionUser] with [Manage] = 1 using the temporary table
UPDATE cu UPDATE cu
SET cu.[ReadOnly] = 0, SET cu.[ReadOnly] = 0,
@ -188,27 +143,8 @@ BEGIN
INNER JOIN #TempStep3 temp ON ou.[Id] = temp.[OrganizationUserId] INNER JOIN #TempStep3 temp ON ou.[Id] = temp.[OrganizationUserId]
WHERE temp.[IsManager] = 1; -- Filter for Managers WHERE temp.[IsManager] = 1; -- Filter for Managers
-- Execute User_BumpAccountRevisionDateByOrganizationUserId for each unique OrganizationUserId -- Execute User_BumpAccountRevisionDateByOrganizationUserIds for the distinct OrganizationUserIds
DECLARE @Step3OrganizationUserId UNIQUEIDENTIFIER EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserIds] @Step3OrgUsersToBump;
DECLARE UniqueOrgUserIdCursor CURSOR FOR
SELECT [OrganizationUserId]
FROM #TempStep3
OPEN UniqueOrgUserIdCursor
FETCH NEXT FROM UniqueOrgUserIdCursor INTO @Step3OrganizationUserId
WHILE (@@FETCH_STATUS = 0)
BEGIN
-- Execute the stored procedure for the current OrganizationUserId
EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserId] @Step3OrganizationUserId
-- Fetch the next row
FETCH NEXT FROM UniqueOrgUserIdCursor INTO @Step3OrganizationUserId
END
CLOSE UniqueOrgUserIdCursor
DEALLOCATE UniqueOrgUserIdCursor;
COMMIT TRANSACTION; COMMIT TRANSACTION;
END TRY END TRY
BEGIN CATCH BEGIN CATCH
@ -217,6 +153,8 @@ BEGIN
END CATCH; END CATCH;
-- Drop the temporary table -- Drop the temporary table
DROP TABLE #TempGroup;
DROP TABLE #TempOrgUser;
DROP TABLE #TempStep3; DROP TABLE #TempStep3;
END END
GO GO