Files
server/util/Migrator/DbScripts/2025-09-23_00_MigrateDefaultCollectionsOnUserDelete.sql

Ignoring revisions in .git-blame-ignore-revs. Click here to bypass and see the normal blame view.

326 lines
6.6 KiB
MySQL
Raw Normal View History

[PM-26050] Migrate all DefaultUserCollection when claimed user is deleted (#6366) * feat: migrate DefaultUserCollection to SharedCollection during user deletion - Implemented migration of DefaultUserCollection to SharedCollection in EF UserRepository before deleting organization users. - Updated stored procedures User_DeleteById and User_DeleteByIds to include migration logic. - Added new migration script for updating stored procedures. * Add unit test for user deletion and DefaultUserCollection migration - Implemented a new test to verify the migration of DefaultUserCollection to SharedCollection during user deletion in UserRepository. - The test ensures that the user is deleted and the associated collection is updated correctly. * Refactor user deletion process in UserRepository - Moved migrating DefaultUserCollection to SharedCollection to happen before the deletion of user-related entities. - Updated the deletion logic to use ExecuteDeleteAsync for improved performance and clarity. - Ensured that all related entities are removed in a single transaction to maintain data integrity. * Add unit test for DeleteManyAsync in UserRepository - Implemented a new test to verify the deletion of multiple users and the migration of their DefaultUserCollections to SharedCollections. - Ensured that both users are deleted and their associated collections are updated correctly in a single transaction. * Refactor UserRepositoryTests to use test user creation methods and streamline collection creation * Ensure changes are saved after deleting users in bulk * Refactor UserRepository to simplify migration queries and remove unnecessary loops for better performance * Refactor UserRepository to encapsulate DefaultUserCollection migration logic in a separate method * Refactor UserRepository to optimize deletion queries by using joins instead of subqueries for improved performance * Refactor UserRepositoryTest DeleteManyAsync_Works to ensure GroupUser and CollectionUser deletion --------- Co-authored-by: Thomas Rittson <31796059+eliykat@users.noreply.github.com>
2025-10-01 14:28:19 +01:00
CREATE OR ALTER PROCEDURE [dbo].[User_DeleteById]
@Id UNIQUEIDENTIFIER
WITH RECOMPILE
AS
BEGIN
SET NOCOUNT ON
DECLARE @BatchSize INT = 100
-- Delete ciphers
WHILE @BatchSize > 0
BEGIN
BEGIN TRANSACTION User_DeleteById_Ciphers
DELETE TOP(@BatchSize)
FROM
[dbo].[Cipher]
WHERE
[UserId] = @Id
SET @BatchSize = @@ROWCOUNT
COMMIT TRANSACTION User_DeleteById_Ciphers
END
BEGIN TRANSACTION User_DeleteById
-- Delete WebAuthnCredentials
DELETE
FROM
[dbo].[WebAuthnCredential]
WHERE
[UserId] = @Id
-- Delete folders
DELETE
FROM
[dbo].[Folder]
WHERE
[UserId] = @Id
-- Delete AuthRequest, must be before Device
DELETE
FROM
[dbo].[AuthRequest]
WHERE
[UserId] = @Id
-- Delete devices
DELETE
FROM
[dbo].[Device]
WHERE
[UserId] = @Id
-- Migrate DefaultUserCollection to SharedCollection before deleting CollectionUser records
DECLARE @OrgUserIds [dbo].[GuidIdArray]
INSERT INTO @OrgUserIds (Id)
SELECT [Id] FROM [dbo].[OrganizationUser] WHERE [UserId] = @Id
IF EXISTS (SELECT 1 FROM @OrgUserIds)
BEGIN
EXEC [dbo].[OrganizationUser_MigrateDefaultCollection] @OrgUserIds
END
-- Delete collection users
DELETE
CU
FROM
[dbo].[CollectionUser] CU
INNER JOIN
[dbo].[OrganizationUser] OU ON OU.[Id] = CU.[OrganizationUserId]
WHERE
OU.[UserId] = @Id
-- Delete group users
DELETE
GU
FROM
[dbo].[GroupUser] GU
INNER JOIN
[dbo].[OrganizationUser] OU ON OU.[Id] = GU.[OrganizationUserId]
WHERE
OU.[UserId] = @Id
-- Delete AccessPolicy
DELETE
AP
FROM
[dbo].[AccessPolicy] AP
INNER JOIN
[dbo].[OrganizationUser] OU ON OU.[Id] = AP.[OrganizationUserId]
WHERE
[UserId] = @Id
-- Delete organization users
DELETE
FROM
[dbo].[OrganizationUser]
WHERE
[UserId] = @Id
-- Delete provider users
DELETE
FROM
[dbo].[ProviderUser]
WHERE
[UserId] = @Id
-- Delete SSO Users
DELETE
FROM
[dbo].[SsoUser]
WHERE
[UserId] = @Id
-- Delete Emergency Accesses
DELETE
FROM
[dbo].[EmergencyAccess]
WHERE
[GrantorId] = @Id
OR
[GranteeId] = @Id
-- Delete Sends
DELETE
FROM
[dbo].[Send]
WHERE
[UserId] = @Id
-- Delete Notification Status
DELETE
FROM
[dbo].[NotificationStatus]
WHERE
[UserId] = @Id
-- Delete Notification
DELETE
FROM
[dbo].[Notification]
WHERE
[UserId] = @Id
-- Finally, delete the user
DELETE
FROM
[dbo].[User]
WHERE
[Id] = @Id
COMMIT TRANSACTION User_DeleteById
END
GO
CREATE OR ALTER PROCEDURE [dbo].[User_DeleteByIds]
@Ids NVARCHAR(MAX)
WITH RECOMPILE
AS
BEGIN
SET NOCOUNT ON
-- Declare a table variable to hold the parsed JSON data
DECLARE @ParsedIds TABLE (Id UNIQUEIDENTIFIER);
-- Parse the JSON input into the table variable
INSERT INTO @ParsedIds (Id)
SELECT value
FROM OPENJSON(@Ids);
-- Check if the input table is empty
IF (SELECT COUNT(1) FROM @ParsedIds) < 1
BEGIN
RETURN(-1);
END
DECLARE @BatchSize INT = 100
-- Delete ciphers
WHILE @BatchSize > 0
BEGIN
BEGIN TRANSACTION User_DeleteById_Ciphers
DELETE TOP(@BatchSize)
FROM
[dbo].[Cipher]
WHERE
[UserId] IN (SELECT * FROM @ParsedIds)
SET @BatchSize = @@ROWCOUNT
COMMIT TRANSACTION User_DeleteById_Ciphers
END
BEGIN TRANSACTION User_DeleteById
-- Delete WebAuthnCredentials
DELETE
FROM
[dbo].[WebAuthnCredential]
WHERE
[UserId] IN (SELECT * FROM @ParsedIds)
-- Delete folders
DELETE
FROM
[dbo].[Folder]
WHERE
[UserId] IN (SELECT * FROM @ParsedIds)
-- Delete AuthRequest, must be before Device
DELETE
FROM
[dbo].[AuthRequest]
WHERE
[UserId] IN (SELECT * FROM @ParsedIds)
-- Delete devices
DELETE
FROM
[dbo].[Device]
WHERE
[UserId] IN (SELECT * FROM @ParsedIds)
-- Migrate DefaultUserCollection to SharedCollection before deleting CollectionUser records
DECLARE @OrgUserIds [dbo].[GuidIdArray]
INSERT INTO @OrgUserIds (Id)
SELECT [Id] FROM [dbo].[OrganizationUser] WHERE [UserId] IN (SELECT * FROM @ParsedIds)
IF EXISTS (SELECT 1 FROM @OrgUserIds)
BEGIN
EXEC [dbo].[OrganizationUser_MigrateDefaultCollection] @OrgUserIds
END
-- Delete collection users
DELETE
CU
FROM
[dbo].[CollectionUser] CU
INNER JOIN
[dbo].[OrganizationUser] OU ON OU.[Id] = CU.[OrganizationUserId]
WHERE
OU.[UserId] IN (SELECT * FROM @ParsedIds)
-- Delete group users
DELETE
GU
FROM
[dbo].[GroupUser] GU
INNER JOIN
[dbo].[OrganizationUser] OU ON OU.[Id] = GU.[OrganizationUserId]
WHERE
OU.[UserId] IN (SELECT * FROM @ParsedIds)
-- Delete AccessPolicy
DELETE
AP
FROM
[dbo].[AccessPolicy] AP
INNER JOIN
[dbo].[OrganizationUser] OU ON OU.[Id] = AP.[OrganizationUserId]
WHERE
[UserId] IN (SELECT * FROM @ParsedIds)
-- Delete organization users
DELETE
FROM
[dbo].[OrganizationUser]
WHERE
[UserId] IN (SELECT * FROM @ParsedIds)
-- Delete provider users
DELETE
FROM
[dbo].[ProviderUser]
WHERE
[UserId] IN (SELECT * FROM @ParsedIds)
-- Delete SSO Users
DELETE
FROM
[dbo].[SsoUser]
WHERE
[UserId] IN (SELECT * FROM @ParsedIds)
-- Delete Emergency Accesses
DELETE
FROM
[dbo].[EmergencyAccess]
WHERE
[GrantorId] IN (SELECT * FROM @ParsedIds)
OR
[GranteeId] IN (SELECT * FROM @ParsedIds)
-- Delete Sends
DELETE
FROM
[dbo].[Send]
WHERE
[UserId] IN (SELECT * FROM @ParsedIds)
-- Delete Notification Status
DELETE
FROM
[dbo].[NotificationStatus]
WHERE
[UserId] IN (SELECT * FROM @ParsedIds)
-- Delete Notification
DELETE
FROM
[dbo].[Notification]
WHERE
[UserId] IN (SELECT * FROM @ParsedIds)
-- Finally, delete the user
DELETE
FROM
[dbo].[User]
WHERE
[Id] IN (SELECT * FROM @ParsedIds)
COMMIT TRANSACTION User_DeleteById
END
GO