1
0
mirror of https://github.com/bitwarden/server.git synced 2024-11-29 13:25:17 +01:00
bitwarden-server/util/Migrator/DbScripts/2024-08-26_00_FinalFlexibleCollectionsDataMigrations.sql
Rui Tomé f5caecc6d6
[AC-1722] Deprecate "Edit/Delete Assigned Collections" custom permissions (#4604)
* Add SQL script to migrate custom users with specific permissions to User type

Remove 'editAssignedCollections' and 'deleteAssignedCollections' properties from Permissions in OrganizationUser table. Migrate custom users who only have these permissions to the User type.

* Add MySQL migration to migrate custom users with specific permissions to User type

* Add Postgres migration to migrate custom users with specific permissions to User type

* Add Sqlite migration to migrate custom users with specific permissions to User type

* Update AutoFixture usage in tests to resolve creating ILogger mock instances

* Update EF integration tests database contexts to use each respective Migrations assembly. Configure Sqlite instance

* Add RunMigration method to BaseEntityFrameworkRepository

* Add FinalFlexibleCollectionsDataMigrationsTests

* Improve data migration efficiency by using OPENJSON instead of multiple JSON_EXTRACT

* Add batching to the sql data migrations

* Update DbMigrator to run a specific script based on its name

* Update DatabaseDataAttribute to be able to test a specific migration

* Add reference to the migration projects to Infrastructure.IntegrationTest

* Add integration test to test the migration FinalFlexibleCollectionsDataMigrations

* Remove EFIntegration tests and remove RunMigration method from BaseEntityFrameworkRepository

* Add IMigrationTesterService and implementations for SQL and EF migrations

* Add FinalFlexibleCollectionsDataMigrationsTests and remove test from OrganizationUserRepositoryTests

* Update sql data migration script based on performance feedback

* Bump date on EF migration scripts

* Add xmldoc comments to IMigrationTesterService and each implementation

* Bump up the date on the EF migration scripts

* Bump up dates on EF migrations

* Added tests to assert no unwanted changes are made to the permissions json. Refactor tests.

* Revert changes made to DbMigrator and refactor SqlMigrationTesterService to not use it.

* Add method description

* Fix test to assert no changes are made to custom user

* Remove unnecessary COALESCE and SELECT CASE

* Unident lines on SQL script

* Update DatabaseDataAttribute MigrationName property to be nullable

* Fix null reference checks

* Remove unnecessary COALESCE from Postgres script

* Bump dates on migration scripts

* Bump up dates on EF migrations

* Add migration tests for handling null

* Add test for non json values

* Fix test

* Remove migrations

* Recreate EF migrations

* Update Postgres data migration script to check for valid JSON in Permissions column

---------

Co-authored-by: Thomas Rittson <31796059+eliykat@users.noreply.github.com>
Co-authored-by: Thomas Rittson <trittson@bitwarden.com>
2024-09-02 11:04:55 +01:00

119 lines
4.2 KiB
Transact-SQL

DECLARE @BatchSize INT = 2000;
DECLARE @RowsAffected INT;
-- Migrate Custom users who only have 'editAssignedCollections' and/or 'deleteAssignedCollections'
-- custom permissions to the User type.
WHILE 1 = 1
BEGIN
UPDATE TOP (@BatchSize) [dbo].[OrganizationUser]
SET
[Type] = 2,
[Permissions] = NULL
WHERE
[Type] = 4
AND ISJSON([Permissions]) = 1
AND EXISTS (
SELECT 1
FROM OPENJSON([Permissions])
WITH (
editAssignedCollections bit '$.editAssignedCollections',
deleteAssignedCollections bit '$.deleteAssignedCollections',
accessEventLogs bit '$.accessEventLogs',
accessImportExport bit '$.accessImportExport',
accessReports bit '$.accessReports',
createNewCollections bit '$.createNewCollections',
editAnyCollection bit '$.editAnyCollection',
deleteAnyCollection bit '$.deleteAnyCollection',
manageGroups bit '$.manageGroups',
managePolicies bit '$.managePolicies',
manageSso bit '$.manageSso',
manageUsers bit '$.manageUsers',
manageResetPassword bit '$.manageResetPassword',
manageScim bit '$.manageScim'
) AS PermissionsJson
WHERE
(PermissionsJson.editAssignedCollections = 1 OR PermissionsJson.deleteAssignedCollections = 1)
AND PermissionsJson.accessEventLogs = 0
AND PermissionsJson.accessImportExport = 0
AND PermissionsJson.accessReports = 0
AND PermissionsJson.createNewCollections = 0
AND PermissionsJson.editAnyCollection = 0
AND PermissionsJson.deleteAnyCollection = 0
AND PermissionsJson.manageGroups = 0
AND PermissionsJson.managePolicies = 0
AND PermissionsJson.manageSso = 0
AND PermissionsJson.manageUsers = 0
AND PermissionsJson.manageResetPassword = 0
AND PermissionsJson.manageScim = 0
);
SET @RowsAffected = @@ROWCOUNT;
IF @RowsAffected = 0
BREAK;
END
-- Remove 'editAssignedCollections' and 'deleteAssignedCollections' properties from Permissions
-- Step 1: Create a temporary table to store the IDs and parsed JSON values
CREATE TABLE #TempIds (
TempId INT IDENTITY(1,1) PRIMARY KEY,
OrganizationUserId UNIQUEIDENTIFIER,
editAssignedCollections BIT,
deleteAssignedCollections BIT
);
-- Step 2: Populate the temporary table with the IDs and parsed JSON values
INSERT INTO #TempIds (OrganizationUserId, editAssignedCollections, deleteAssignedCollections)
SELECT
Id,
CAST(JSON_VALUE([Permissions], '$.editAssignedCollections') AS BIT) AS editAssignedCollections,
CAST(JSON_VALUE([Permissions], '$.deleteAssignedCollections') AS BIT) AS deleteAssignedCollections
FROM [dbo].[OrganizationUser]
WHERE
ISJSON([Permissions]) = 1
AND (
JSON_VALUE([Permissions], '$.editAssignedCollections') IS NOT NULL
OR JSON_VALUE([Permissions], '$.deleteAssignedCollections') IS NOT NULL
);
DECLARE @MaxTempId INT;
DECLARE @CurrentBatchStart INT = 1;
-- Get the maximum TempId
SELECT @MaxTempId = MAX(TempId) FROM #TempIds;
-- Step 3: Loop through the IDs in batches
WHILE @CurrentBatchStart <= @MaxTempId
BEGIN
UPDATE tu
SET
[Permissions] =
JSON_MODIFY(
JSON_MODIFY(
[Permissions],
'$.editAssignedCollections',
NULL
),
'$.deleteAssignedCollections',
NULL
)
FROM [dbo].[OrganizationUser] tu
INNER JOIN #TempIds ti ON tu.Id = ti.OrganizationUserId
WHERE
ti.TempId BETWEEN @CurrentBatchStart AND @CurrentBatchStart + @BatchSize - 1
AND (
ti.editAssignedCollections IS NOT NULL
OR ti.deleteAssignedCollections IS NOT NULL
);
SET @RowsAffected = @@ROWCOUNT;
IF @RowsAffected = 0
BREAK;
SET @CurrentBatchStart = @CurrentBatchStart + @BatchSize;
END
-- Clean up the temporary table
DROP TABLE #TempIds;