diff --git a/src/Sql/dbo/Tables/CollectionCipher.sql b/src/Sql/dbo/Tables/CollectionCipher.sql index f661cb6fbd..0891b7bc42 100644 --- a/src/Sql/dbo/Tables/CollectionCipher.sql +++ b/src/Sql/dbo/Tables/CollectionCipher.sql @@ -11,3 +11,4 @@ GO CREATE NONCLUSTERED INDEX [IX_CollectionCipher_CipherId] ON [dbo].[CollectionCipher]([CipherId] ASC); +GO diff --git a/src/Sql/dbo/Tables/OrganizationUser.sql b/src/Sql/dbo/Tables/OrganizationUser.sql index 51ed2115bc..a9f228dc3d 100644 --- a/src/Sql/dbo/Tables/OrganizationUser.sql +++ b/src/Sql/dbo/Tables/OrganizationUser.sql @@ -35,3 +35,10 @@ CREATE NONCLUSTERED INDEX [IX_OrganizationUser_OrganizationId_UserId] INCLUDE ([Email], [Status], [Type], [ExternalId], [CreationDate], [RevisionDate], [Permissions], [ResetPasswordKey], [AccessSecretsManager]); GO + +CREATE NONCLUSTERED INDEX [IX_OrganizationUser_UserId_Status_Filtered] + ON [dbo].[OrganizationUser] ([UserId]) + INCLUDE ([Id], [OrganizationId]) + WHERE [Status] = 2; -- Confirmed + +GO diff --git a/src/Sql/dbo/Vault/Stored Procedures/SecurityTask/SecurityTask_ReadByUserIdStatus.sql b/src/Sql/dbo/Vault/Stored Procedures/SecurityTask/SecurityTask_ReadByUserIdStatus.sql index 2a4ecdb4c1..2614135c54 100644 --- a/src/Sql/dbo/Vault/Stored Procedures/SecurityTask/SecurityTask_ReadByUserIdStatus.sql +++ b/src/Sql/dbo/Vault/Stored Procedures/SecurityTask/SecurityTask_ReadByUserIdStatus.sql @@ -1,56 +1,87 @@ CREATE PROCEDURE [dbo].[SecurityTask_ReadByUserIdStatus] - @UserId UNIQUEIDENTIFIER, - @Status TINYINT = NULL + @UserId [UNIQUEIDENTIFIER], + @Status [TINYINT] = NULL AS BEGIN - SET NOCOUNT ON + 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 + [ST].[Id], + [ST].[OrganizationId], + [ST].[CipherId], + [ST].[Type], + [ST].[Status], + [ST].[CreationDate], + [ST].[RevisionDate] FROM - [dbo].[SecurityTaskView] ST - INNER JOIN - [dbo].[OrganizationUserView] OU ON OU.[OrganizationId] = ST.[OrganizationId] - INNER JOIN - [dbo].[Organization] O ON O.[Id] = ST.[OrganizationId] - LEFT JOIN - [dbo].[CipherView] C ON C.[Id] = ST.[CipherId] - LEFT JOIN - [dbo].[CollectionCipher] CC ON CC.[CipherId] = C.[Id] AND C.[Id] IS NOT NULL - LEFT JOIN - [dbo].[CollectionUser] CU ON CU.[CollectionId] = CC.[CollectionId] AND CU.[OrganizationUserId] = OU.[Id] AND C.[Id] IS NOT NULL - LEFT JOIN - [dbo].[GroupUser] GU ON GU.[OrganizationUserId] = OU.[Id] AND CU.[CollectionId] IS NULL AND C.[Id] IS NOT NULL - LEFT JOIN - [dbo].[CollectionGroup] CG ON CG.[GroupId] = GU.[GroupId] AND CG.[CollectionId] = CC.[CollectionId] + [dbo].[SecurityTaskView] [ST] + INNER JOIN [OrganizationAccess] [OA] + ON [ST].[OrganizationId] = [OA].[OrganizationId] WHERE - OU.[UserId] = @UserId - AND OU.[Status] = 2 -- Ensure user is confirmed - AND O.[Enabled] = 1 + (@Status IS NULL OR [ST].[Status] = @Status) AND ( - ST.[CipherId] IS NULL - OR ( - C.[Id] IS NOT NULL - AND ( - CU.[ReadOnly] = 0 - OR CG.[ReadOnly] = 0 - ) - ) + [ST].[CipherId] IS NULL + OR EXISTS ( + SELECT 1 + FROM [AccessibleCiphers] [AC] + WHERE [AC].[CipherId] = [ST].[CipherId] + ) ) - AND ST.[Status] = COALESCE(@Status, ST.[Status]) - GROUP BY - ST.Id, - ST.OrganizationId, - ST.CipherId, - ST.Type, - ST.Status, - ST.CreationDate, - ST.RevisionDate - ORDER BY ST.[CreationDate] DESC + ORDER BY + [ST].[CreationDate] DESC + OPTION (RECOMPILE); END diff --git a/src/Sql/dbo/Vault/Tables/SecurityTask.sql b/src/Sql/dbo/Vault/Tables/SecurityTask.sql index a00dcede9c..dbf9827a63 100644 --- a/src/Sql/dbo/Vault/Tables/SecurityTask.sql +++ b/src/Sql/dbo/Vault/Tables/SecurityTask.sql @@ -19,3 +19,6 @@ CREATE NONCLUSTERED INDEX [IX_SecurityTask_CipherId] GO CREATE NONCLUSTERED INDEX [IX_SecurityTask_OrganizationId] ON [dbo].[SecurityTask]([OrganizationId] ASC) WHERE OrganizationId IS NOT NULL; + +GO + diff --git a/util/Migrator/DbScripts/2025-09-03_00_ImproveSecurityTask.sql b/util/Migrator/DbScripts/2025-09-03_00_ImproveSecurityTask.sql new file mode 100644 index 0000000000..743caf4672 --- /dev/null +++ b/util/Migrator/DbScripts/2025-09-03_00_ImproveSecurityTask.sql @@ -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