diff --git a/src/Sql/dbo/Stored Procedures/Collection_UpdateWithGroupsAndUsers.sql b/src/Sql/dbo/Stored Procedures/Collection_UpdateWithGroupsAndUsers.sql index da7e77cc14..4a66b20d86 100644 --- a/src/Sql/dbo/Stored Procedures/Collection_UpdateWithGroupsAndUsers.sql +++ b/src/Sql/dbo/Stored Procedures/Collection_UpdateWithGroupsAndUsers.sql @@ -14,98 +14,88 @@ BEGIN EXEC [dbo].[Collection_Update] @Id, @OrganizationId, @Name, @ExternalId, @CreationDate, @RevisionDate -- Groups - ;WITH [AvailableGroupsCTE] AS( - SELECT - Id - FROM - [dbo].[Group] - WHERE - OrganizationId = @OrganizationId + -- Delete groups that are no longer in source + DELETE cg + FROM [dbo].[CollectionGroup] cg + LEFT JOIN @Groups g ON cg.GroupId = g.Id + WHERE cg.CollectionId = @Id + AND g.Id IS NULL; + + -- Update existing groups + UPDATE cg + SET cg.ReadOnly = g.ReadOnly, + cg.HidePasswords = g.HidePasswords, + cg.Manage = g.Manage + FROM [dbo].[CollectionGroup] cg + INNER JOIN @Groups g ON cg.GroupId = g.Id + WHERE cg.CollectionId = @Id + AND (cg.ReadOnly != g.ReadOnly + OR cg.HidePasswords != g.HidePasswords + OR cg.Manage != g.Manage); + + -- Insert new groups + INSERT INTO [dbo].[CollectionGroup] + ( + [CollectionId], + [GroupId], + [ReadOnly], + [HidePasswords], + [Manage] ) - MERGE - [dbo].[CollectionGroup] AS [Target] - USING - @Groups AS [Source] - ON - [Target].[CollectionId] = @Id - AND [Target].[GroupId] = [Source].[Id] - WHEN NOT MATCHED BY TARGET - AND [Source].[Id] IN (SELECT [Id] FROM [AvailableGroupsCTE]) THEN - INSERT -- Add explicit column list - ( - [CollectionId], - [GroupId], - [ReadOnly], - [HidePasswords], - [Manage] - ) - VALUES - ( - @Id, - [Source].[Id], - [Source].[ReadOnly], - [Source].[HidePasswords], - [Source].[Manage] - ) - WHEN MATCHED AND ( - [Target].[ReadOnly] != [Source].[ReadOnly] - OR [Target].[HidePasswords] != [Source].[HidePasswords] - OR [Target].[Manage] != [Source].[Manage] - ) THEN - UPDATE SET [Target].[ReadOnly] = [Source].[ReadOnly], - [Target].[HidePasswords] = [Source].[HidePasswords], - [Target].[Manage] = [Source].[Manage] - WHEN NOT MATCHED BY SOURCE - AND [Target].[CollectionId] = @Id THEN - DELETE - ; + SELECT + @Id, + g.Id, + g.ReadOnly, + g.HidePasswords, + g.Manage + FROM @Groups g + INNER JOIN [dbo].[Group] grp ON grp.Id = g.Id + LEFT JOIN [dbo].[CollectionGroup] cg + ON cg.CollectionId = @Id AND cg.GroupId = g.Id + WHERE grp.OrganizationId = @OrganizationId + AND cg.CollectionId IS NULL; -- Users - ;WITH [AvailableGroupsCTE] AS( - SELECT - Id - FROM - [dbo].[OrganizationUser] - WHERE - OrganizationId = @OrganizationId + -- Delete users that are no longer in source + DELETE cu + FROM [dbo].[CollectionUser] cu + LEFT JOIN @Users u ON cu.OrganizationUserId = u.Id + WHERE cu.CollectionId = @Id + AND u.Id IS NULL; + + -- Update existing users + UPDATE cu + SET cu.ReadOnly = u.ReadOnly, + cu.HidePasswords = u.HidePasswords, + cu.Manage = u.Manage + FROM [dbo].[CollectionUser] cu + INNER JOIN @Users u ON cu.OrganizationUserId = u.Id + WHERE cu.CollectionId = @Id + AND (cu.ReadOnly != u.ReadOnly + OR cu.HidePasswords != u.HidePasswords + OR cu.Manage != u.Manage); + + -- Insert new users + INSERT INTO [dbo].[CollectionUser] + ( + [CollectionId], + [OrganizationUserId], + [ReadOnly], + [HidePasswords], + [Manage] ) - MERGE - [dbo].[CollectionUser] AS [Target] - USING - @Users AS [Source] - ON - [Target].[CollectionId] = @Id - AND [Target].[OrganizationUserId] = [Source].[Id] - WHEN NOT MATCHED BY TARGET - AND [Source].[Id] IN (SELECT [Id] FROM [AvailableGroupsCTE]) THEN - INSERT - ( - [CollectionId], - [OrganizationUserId], - [ReadOnly], - [HidePasswords], - [Manage] - ) - VALUES - ( - @Id, - [Source].[Id], - [Source].[ReadOnly], - [Source].[HidePasswords], - [Source].[Manage] - ) - WHEN MATCHED AND ( - [Target].[ReadOnly] != [Source].[ReadOnly] - OR [Target].[HidePasswords] != [Source].[HidePasswords] - OR [Target].[Manage] != [Source].[Manage] - ) THEN - UPDATE SET [Target].[ReadOnly] = [Source].[ReadOnly], - [Target].[HidePasswords] = [Source].[HidePasswords], - [Target].[Manage] = [Source].[Manage] - WHEN NOT MATCHED BY SOURCE - AND [Target].[CollectionId] = @Id THEN - DELETE - ; + SELECT + @Id, + u.Id, + u.ReadOnly, + u.HidePasswords, + u.Manage + FROM @Users u + INNER JOIN [dbo].[OrganizationUser] ou ON ou.Id = u.Id + LEFT JOIN [dbo].[CollectionUser] cu + ON cu.CollectionId = @Id AND cu.OrganizationUserId = u.Id + WHERE ou.OrganizationId = @OrganizationId + AND cu.CollectionId IS NULL; EXEC [dbo].[User_BumpAccountRevisionDateByCollectionId] @Id, @OrganizationId END diff --git a/src/Sql/dbo/Tables/CollectionGroup.sql b/src/Sql/dbo/Tables/CollectionGroup.sql index 756cd79ece..72a6710e2a 100644 --- a/src/Sql/dbo/Tables/CollectionGroup.sql +++ b/src/Sql/dbo/Tables/CollectionGroup.sql @@ -9,3 +9,9 @@ CONSTRAINT [FK_CollectionGroup_Group] FOREIGN KEY ([GroupId]) REFERENCES [dbo].[Group] ([Id]) ON DELETE CASCADE ); +GO +CREATE NONCLUSTERED INDEX IX_CollectionGroup_GroupId + ON [dbo].[CollectionGroup] (GroupId) + INCLUDE (ReadOnly, HidePasswords, Manage) + +GO diff --git a/src/Sql/dbo/Tables/CollectionUser.sql b/src/Sql/dbo/Tables/CollectionUser.sql index 8e0c0ef035..afdb0f84a0 100644 --- a/src/Sql/dbo/Tables/CollectionUser.sql +++ b/src/Sql/dbo/Tables/CollectionUser.sql @@ -9,3 +9,9 @@ CONSTRAINT [FK_CollectionUser_OrganizationUser] FOREIGN KEY ([OrganizationUserId]) REFERENCES [dbo].[OrganizationUser] ([Id]) ); +GO +CREATE NONCLUSTERED INDEX IX_CollectionUser_OrganizationUserId + ON [dbo].[CollectionUser] (OrganizationUserId) + INCLUDE (ReadOnly, HidePasswords, Manage) + +GO diff --git a/test/Infrastructure.IntegrationTest/Vault/Repositories/CollectionRepositoryTests.cs b/test/Infrastructure.IntegrationTest/Vault/Repositories/CollectionRepositoryTests.cs index fa7197ff61..268d46ef6b 100644 --- a/test/Infrastructure.IntegrationTest/Vault/Repositories/CollectionRepositoryTests.cs +++ b/test/Infrastructure.IntegrationTest/Vault/Repositories/CollectionRepositoryTests.cs @@ -599,5 +599,11 @@ public class CollectionRepositoryTests Assert.True(actualOrgUser3.Manage); Assert.False(actualOrgUser3.HidePasswords); Assert.True(actualOrgUser3.ReadOnly); + + // Clean up data + await userRepository.DeleteAsync(user); + await organizationRepository.DeleteAsync(organization); + await groupRepository.DeleteManyAsync([group1.Id, group2.Id, group3.Id]); + await organizationUserRepository.DeleteManyAsync([orgUser1.Id, orgUser2.Id, orgUser3.Id]); } } diff --git a/util/Migrator/DbScripts/2025-04-07_00_Collections_UpdateWithGroupsAndUsers_AndIndices.sql b/util/Migrator/DbScripts/2025-04-07_00_Collections_UpdateWithGroupsAndUsers_AndIndices.sql new file mode 100644 index 0000000000..5bdeb5b254 --- /dev/null +++ b/util/Migrator/DbScripts/2025-04-07_00_Collections_UpdateWithGroupsAndUsers_AndIndices.sql @@ -0,0 +1,118 @@ +CREATE OR ALTER PROCEDURE [dbo].[Collection_UpdateWithGroupsAndUsers] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Name VARCHAR(MAX), + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @Groups AS [dbo].[CollectionAccessSelectionType] READONLY, + @Users AS [dbo].[CollectionAccessSelectionType] READONLY +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[Collection_Update] @Id, @OrganizationId, @Name, @ExternalId, @CreationDate, @RevisionDate + + -- Groups + -- Delete groups that are no longer in source + DELETE cg + FROM [dbo].[CollectionGroup] cg + LEFT JOIN @Groups g ON cg.GroupId = g.Id + WHERE cg.CollectionId = @Id + AND g.Id IS NULL; + + -- Update existing groups + UPDATE cg + SET cg.ReadOnly = g.ReadOnly, + cg.HidePasswords = g.HidePasswords, + cg.Manage = g.Manage + FROM [dbo].[CollectionGroup] cg + INNER JOIN @Groups g ON cg.GroupId = g.Id + WHERE cg.CollectionId = @Id + AND (cg.ReadOnly != g.ReadOnly + OR cg.HidePasswords != g.HidePasswords + OR cg.Manage != g.Manage); + + -- Insert new groups + INSERT INTO [dbo].[CollectionGroup] + ( + [CollectionId], + [GroupId], + [ReadOnly], + [HidePasswords], + [Manage] + ) + SELECT + @Id, + g.Id, + g.ReadOnly, + g.HidePasswords, + g.Manage + FROM @Groups g + INNER JOIN [dbo].[Group] grp ON grp.Id = g.Id + LEFT JOIN [dbo].[CollectionGroup] cg + ON cg.CollectionId = @Id AND cg.GroupId = g.Id + WHERE grp.OrganizationId = @OrganizationId + AND cg.CollectionId IS NULL; + + -- Users + -- Delete users that are no longer in source + DELETE cu + FROM [dbo].[CollectionUser] cu + LEFT JOIN @Users u ON cu.OrganizationUserId = u.Id + WHERE cu.CollectionId = @Id + AND u.Id IS NULL; + + -- Update existing users + UPDATE cu + SET cu.ReadOnly = u.ReadOnly, + cu.HidePasswords = u.HidePasswords, + cu.Manage = u.Manage + FROM [dbo].[CollectionUser] cu + INNER JOIN @Users u ON cu.OrganizationUserId = u.Id + WHERE cu.CollectionId = @Id + AND (cu.ReadOnly != u.ReadOnly + OR cu.HidePasswords != u.HidePasswords + OR cu.Manage != u.Manage); + + -- Insert new users + INSERT INTO [dbo].[CollectionUser] + ( + [CollectionId], + [OrganizationUserId], + [ReadOnly], + [HidePasswords], + [Manage] + ) + SELECT + @Id, + u.Id, + u.ReadOnly, + u.HidePasswords, + u.Manage + FROM @Users u + INNER JOIN [dbo].[OrganizationUser] ou ON ou.Id = u.Id + LEFT JOIN [dbo].[CollectionUser] cu + ON cu.CollectionId = @Id AND cu.OrganizationUserId = u.Id + WHERE ou.OrganizationId = @OrganizationId + AND cu.CollectionId IS NULL; + + EXEC [dbo].[User_BumpAccountRevisionDateByCollectionId] @Id, @OrganizationId +END +GO + +IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = 'IX_CollectionGroup_GroupId') + BEGIN + CREATE NONCLUSTERED INDEX IX_CollectionGroup_GroupId + ON [dbo].[CollectionGroup] (GroupId) + INCLUDE (ReadOnly, HidePasswords, Manage) + END +GO + +IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = 'IX_CollectionUser_OrganizationUserId') + BEGIN + CREATE NONCLUSTERED INDEX IX_CollectionUser_OrganizationUserId + ON [dbo].[CollectionUser] (OrganizationUserId) + INCLUDE (ReadOnly, HidePasswords, Manage) + END +GO