mirror of
https://github.com/bitwarden/server.git
synced 2025-04-24 22:32:22 -05:00
[PM-19128] - Optimize Update Collections (#5626)
* added data clean up to test * Added indices and edited sproc to avoid merge commands * Forgot GO * Adding some more GOs
This commit is contained in:
parent
9218ac0d7c
commit
dc758c5176
@ -14,98 +14,88 @@ BEGIN
|
|||||||
EXEC [dbo].[Collection_Update] @Id, @OrganizationId, @Name, @ExternalId, @CreationDate, @RevisionDate
|
EXEC [dbo].[Collection_Update] @Id, @OrganizationId, @Name, @ExternalId, @CreationDate, @RevisionDate
|
||||||
|
|
||||||
-- Groups
|
-- Groups
|
||||||
;WITH [AvailableGroupsCTE] AS(
|
-- Delete groups that are no longer in source
|
||||||
SELECT
|
DELETE cg
|
||||||
Id
|
FROM [dbo].[CollectionGroup] cg
|
||||||
FROM
|
LEFT JOIN @Groups g ON cg.GroupId = g.Id
|
||||||
[dbo].[Group]
|
WHERE cg.CollectionId = @Id
|
||||||
WHERE
|
AND g.Id IS NULL;
|
||||||
OrganizationId = @OrganizationId
|
|
||||||
|
-- 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
|
SELECT
|
||||||
[dbo].[CollectionGroup] AS [Target]
|
@Id,
|
||||||
USING
|
g.Id,
|
||||||
@Groups AS [Source]
|
g.ReadOnly,
|
||||||
ON
|
g.HidePasswords,
|
||||||
[Target].[CollectionId] = @Id
|
g.Manage
|
||||||
AND [Target].[GroupId] = [Source].[Id]
|
FROM @Groups g
|
||||||
WHEN NOT MATCHED BY TARGET
|
INNER JOIN [dbo].[Group] grp ON grp.Id = g.Id
|
||||||
AND [Source].[Id] IN (SELECT [Id] FROM [AvailableGroupsCTE]) THEN
|
LEFT JOIN [dbo].[CollectionGroup] cg
|
||||||
INSERT -- Add explicit column list
|
ON cg.CollectionId = @Id AND cg.GroupId = g.Id
|
||||||
(
|
WHERE grp.OrganizationId = @OrganizationId
|
||||||
[CollectionId],
|
AND cg.CollectionId IS NULL;
|
||||||
[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
|
|
||||||
;
|
|
||||||
|
|
||||||
-- Users
|
-- Users
|
||||||
;WITH [AvailableGroupsCTE] AS(
|
-- Delete users that are no longer in source
|
||||||
SELECT
|
DELETE cu
|
||||||
Id
|
FROM [dbo].[CollectionUser] cu
|
||||||
FROM
|
LEFT JOIN @Users u ON cu.OrganizationUserId = u.Id
|
||||||
[dbo].[OrganizationUser]
|
WHERE cu.CollectionId = @Id
|
||||||
WHERE
|
AND u.Id IS NULL;
|
||||||
OrganizationId = @OrganizationId
|
|
||||||
|
-- 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
|
SELECT
|
||||||
[dbo].[CollectionUser] AS [Target]
|
@Id,
|
||||||
USING
|
u.Id,
|
||||||
@Users AS [Source]
|
u.ReadOnly,
|
||||||
ON
|
u.HidePasswords,
|
||||||
[Target].[CollectionId] = @Id
|
u.Manage
|
||||||
AND [Target].[OrganizationUserId] = [Source].[Id]
|
FROM @Users u
|
||||||
WHEN NOT MATCHED BY TARGET
|
INNER JOIN [dbo].[OrganizationUser] ou ON ou.Id = u.Id
|
||||||
AND [Source].[Id] IN (SELECT [Id] FROM [AvailableGroupsCTE]) THEN
|
LEFT JOIN [dbo].[CollectionUser] cu
|
||||||
INSERT
|
ON cu.CollectionId = @Id AND cu.OrganizationUserId = u.Id
|
||||||
(
|
WHERE ou.OrganizationId = @OrganizationId
|
||||||
[CollectionId],
|
AND cu.CollectionId IS NULL;
|
||||||
[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
|
|
||||||
;
|
|
||||||
|
|
||||||
EXEC [dbo].[User_BumpAccountRevisionDateByCollectionId] @Id, @OrganizationId
|
EXEC [dbo].[User_BumpAccountRevisionDateByCollectionId] @Id, @OrganizationId
|
||||||
END
|
END
|
||||||
|
@ -9,3 +9,9 @@
|
|||||||
CONSTRAINT [FK_CollectionGroup_Group] FOREIGN KEY ([GroupId]) REFERENCES [dbo].[Group] ([Id]) ON DELETE CASCADE
|
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
|
||||||
|
@ -9,3 +9,9 @@
|
|||||||
CONSTRAINT [FK_CollectionUser_OrganizationUser] FOREIGN KEY ([OrganizationUserId]) REFERENCES [dbo].[OrganizationUser] ([Id])
|
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
|
||||||
|
@ -599,5 +599,11 @@ public class CollectionRepositoryTests
|
|||||||
Assert.True(actualOrgUser3.Manage);
|
Assert.True(actualOrgUser3.Manage);
|
||||||
Assert.False(actualOrgUser3.HidePasswords);
|
Assert.False(actualOrgUser3.HidePasswords);
|
||||||
Assert.True(actualOrgUser3.ReadOnly);
|
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]);
|
||||||
}
|
}
|
||||||
}
|
}
|
||||||
|
@ -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
|
Loading…
x
Reference in New Issue
Block a user