1
0
mirror of https://github.com/bitwarden/server synced 2025-12-06 00:03:34 +00:00

[PM-21044] - optimize security task ReadByUserIdStatus (#5779)

* optimize security task ReadByUserIdStatus

* fix AccessibleCiphers query

* fix error

* add migrator file

* fix migration

* update sproc

* mirror sprocs

* revert change to sproc

* add indexes. update filename. add GO statement

* move index declarations to appropriate files

* add missing GO statement

* select view. add existance checks for index

* update indexes

* revert changes

* rename file

* update security task

* update sproc

* update script file

* bump migration date

* add filtered index. update statistics, update description with perf metics

* rename file

* reordering

* remove update statistics

* remove update statistics

* add missing index

* fix sproc

* update timestamp

* improve sproc with de-dupe and views

* fix syntax error

* add missing inner join

* sync up index

* fix indentation

* update file timestamp

* remove unnecessary indexes. update sql to match guidelines.

* add comment for status

* add comment for status
This commit is contained in:
Jordan Aasen
2025-09-12 11:49:40 -07:00
committed by GitHub
parent 854abb0993
commit 6ade09312f
5 changed files with 189 additions and 46 deletions

View File

@@ -0,0 +1,101 @@
CREATE OR ALTER PROCEDURE [dbo].[SecurityTask_ReadByUserIdStatus]
@UserId [UNIQUEIDENTIFIER],
@Status [TINYINT] = NULL
AS
BEGIN
SET NOCOUNT ON;
WITH [OrganizationAccess] AS (
SELECT
[OU].[OrganizationId]
FROM
[dbo].[OrganizationUser] [OU]
INNER JOIN [dbo].[OrganizationView] [O]
ON [O].[Id] = [OU].[OrganizationId]
WHERE
[OU].[UserId] = @UserId
AND [OU].[Status] = 2 -- Confirmed
AND [O].[Enabled] = 1
),
[UserCollectionAccess] AS (
SELECT
[CC].[CipherId]
FROM
[dbo].[OrganizationUser] [OU]
INNER JOIN [dbo].[OrganizationView] [O]
ON [O].[Id] = [OU].[OrganizationId]
INNER JOIN [dbo].[CollectionUser] [CU]
ON [CU].[OrganizationUserId] = [OU].[Id]
INNER JOIN [dbo].[CollectionCipher] [CC]
ON [CC].[CollectionId] = [CU].[CollectionId]
WHERE
[OU].[UserId] = @UserId
AND [OU].[Status] = 2 -- Confirmed
AND [O].[Enabled] = 1
AND [CU].[ReadOnly] = 0
),
[GroupCollectionAccess] AS (
SELECT
[CC].[CipherId]
FROM
[dbo].[OrganizationUser] [OU]
INNER JOIN [dbo].[OrganizationView] [O]
ON [O].[Id] = [OU].[OrganizationId]
INNER JOIN [dbo].[GroupUser] [GU]
ON [GU].[OrganizationUserId] = [OU].[Id]
INNER JOIN [dbo].[CollectionGroup] [CG]
ON [CG].[GroupId] = [GU].[GroupId]
INNER JOIN [dbo].[CollectionCipher] [CC]
ON [CC].[CollectionId] = [CG].[CollectionId]
WHERE
[OU].[UserId] = @UserId
AND [OU].[Status] = 2 -- Confirmed
AND [CG].[ReadOnly] = 0
),
[AccessibleCiphers] AS (
SELECT
[CipherId] FROM [UserCollectionAccess]
UNION
SELECT
[CipherId] FROM [GroupCollectionAccess]
)
SELECT
[ST].[Id],
[ST].[OrganizationId],
[ST].[CipherId],
[ST].[Type],
[ST].[Status],
[ST].[CreationDate],
[ST].[RevisionDate]
FROM
[dbo].[SecurityTaskView] [ST]
INNER JOIN [OrganizationAccess] [OA]
ON [ST].[OrganizationId] = [OA].[OrganizationId]
WHERE
(@Status IS NULL OR [ST].[Status] = @Status)
AND (
[ST].[CipherId] IS NULL
OR EXISTS (
SELECT 1
FROM [AccessibleCiphers] [AC]
WHERE [AC].[CipherId] = [ST].[CipherId]
)
)
ORDER BY
[ST].[CreationDate] DESC
OPTION (RECOMPILE);
END
GO
IF NOT EXISTS (
SELECT 1
FROM sys.indexes
WHERE object_id = OBJECT_ID('dbo.OrganizationUser')
AND name = 'IX_OrganizationUser_UserId_Status_Filtered'
)
BEGIN
CREATE NONCLUSTERED INDEX [IX_OrganizationUser_UserId_Status_Filtered]
ON [dbo].[OrganizationUser] ([UserId])
INCLUDE ([Id], [OrganizationId])
WHERE [Status] = 2; -- Confirmed
END