From 8a1b64a21bf52d0b9dc4904b20ab5de8feb24e1b Mon Sep 17 00:00:00 2001 From: Thomas Avery <43214426+Thomas-Avery@users.noreply.github.com> Date: Fri, 21 Jun 2024 17:29:36 -0500 Subject: [PATCH] [SM-1075] Fix bulk remove organization users with Secrets Manager (#4197) * Fix OrganizationUser_DeleteByIds procedure * Add db migration --- .../OrganizationUser_DeleteByIds.sql | 22 +++- ...6-20_00_FixOrganizationUserDeleteByIds.sql | 102 ++++++++++++++++++ 2 files changed, 122 insertions(+), 2 deletions(-) create mode 100644 util/Migrator/DbScripts/2024-06-20_00_FixOrganizationUserDeleteByIds.sql diff --git a/src/Sql/dbo/Stored Procedures/OrganizationUser_DeleteByIds.sql b/src/Sql/dbo/Stored Procedures/OrganizationUser_DeleteByIds.sql index 4930a8fbedb7..ac9e75dd5e73 100644 --- a/src/Sql/dbo/Stored Procedures/OrganizationUser_DeleteByIds.sql +++ b/src/Sql/dbo/Stored Procedures/OrganizationUser_DeleteByIds.sql @@ -58,11 +58,29 @@ BEGIN SET @BatchSize = @@ROWCOUNT - COMMIT TRANSACTION GoupUser_DeleteMany_GroupUsers + COMMIT TRANSACTION GroupUser_DeleteMany_GroupUsers + END + + SET @BatchSize = 100; + + -- Delete User Access Policies + WHILE @BatchSize > 0 + BEGIN + BEGIN TRANSACTION AccessPolicy_DeleteMany_Users + + DELETE TOP(@BatchSize) AP + FROM + [dbo].[AccessPolicy] AP + INNER JOIN + @Ids I ON I.Id = AP.OrganizationUserId + + SET @BatchSize = @@ROWCOUNT + + COMMIT TRANSACTION AccessPolicy_DeleteMany_Users END EXEC [dbo].[OrganizationSponsorship_OrganizationUsersDeleted] @Ids - + SET @BatchSize = 100; -- Delete OrganizationUsers diff --git a/util/Migrator/DbScripts/2024-06-20_00_FixOrganizationUserDeleteByIds.sql b/util/Migrator/DbScripts/2024-06-20_00_FixOrganizationUserDeleteByIds.sql new file mode 100644 index 000000000000..7122467be46d --- /dev/null +++ b/util/Migrator/DbScripts/2024-06-20_00_FixOrganizationUserDeleteByIds.sql @@ -0,0 +1,102 @@ +CREATE OR ALTER PROCEDURE [dbo].[OrganizationUser_DeleteByIds] + @Ids [dbo].[GuidIdArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserIds] @Ids + + DECLARE @UserAndOrganizationIds [dbo].[TwoGuidIdArray] + + INSERT INTO @UserAndOrganizationIds + (Id1, Id2) + SELECT + UserId, + OrganizationId + FROM + [dbo].[OrganizationUser] OU + INNER JOIN + @Ids OUIds ON OUIds.Id = OU.Id + WHERE + UserId IS NOT NULL AND + OrganizationId IS NOT NULL + + BEGIN + EXEC [dbo].[SsoUser_DeleteMany] @UserAndOrganizationIds + END + + DECLARE @BatchSize INT = 100 + + -- Delete CollectionUsers + WHILE @BatchSize > 0 + BEGIN + BEGIN TRANSACTION CollectionUser_DeleteMany_CUs + + DELETE TOP(@BatchSize) CU + FROM + [dbo].[CollectionUser] CU + INNER JOIN + @Ids I ON I.Id = CU.OrganizationUserId + + SET @BatchSize = @@ROWCOUNT + + COMMIT TRANSACTION CollectionUser_DeleteMany_CUs + END + + SET @BatchSize = 100; + + -- Delete GroupUsers + WHILE @BatchSize > 0 + BEGIN + BEGIN TRANSACTION GroupUser_DeleteMany_GroupUsers + + DELETE TOP(@BatchSize) GU + FROM + [dbo].[GroupUser] GU + INNER JOIN + @Ids I ON I.Id = GU.OrganizationUserId + + SET @BatchSize = @@ROWCOUNT + + COMMIT TRANSACTION GroupUser_DeleteMany_GroupUsers + END + + SET @BatchSize = 100; + + -- Delete User Access Policies + WHILE @BatchSize > 0 + BEGIN + BEGIN TRANSACTION AccessPolicy_DeleteMany_Users + + DELETE TOP(@BatchSize) AP + FROM + [dbo].[AccessPolicy] AP + INNER JOIN + @Ids I ON I.Id = AP.OrganizationUserId + + SET @BatchSize = @@ROWCOUNT + + COMMIT TRANSACTION AccessPolicy_DeleteMany_Users + END + + EXEC [dbo].[OrganizationSponsorship_OrganizationUsersDeleted] @Ids + + SET @BatchSize = 100; + + -- Delete OrganizationUsers + WHILE @BatchSize > 0 + BEGIN + BEGIN TRANSACTION OrganizationUser_DeleteMany_OUs + + DELETE TOP(@BatchSize) OU + FROM + [dbo].[OrganizationUser] OU + INNER JOIN + @Ids I ON I.Id = OU.Id + + SET @BatchSize = @@ROWCOUNT + + COMMIT TRANSACTION OrganizationUser_DeleteMany_OUs + END +END +GO