mirror of
https://github.com/bitwarden/server.git
synced 2025-02-12 01:11:22 +01:00
a99f82dddd
* [PM-14378] Introduce GetCipherPermissionsForOrganization query for Dapper CipherRepository * [PM-14378] Introduce GetCipherPermissionsForOrganization method for Entity Framework * [PM-14378] Add integration tests for new repository method * [PM-14378] Introduce IGetCipherPermissionsForUserQuery CQRS query * [PM-14378] Introduce SecurityTaskOperationRequirement * [PM-14378] Introduce SecurityTaskAuthorizationHandler.cs * [PM-14378] Introduce SecurityTaskOrganizationAuthorizationHandler.cs * [PM-14378] Register new authorization handlers * [PM-14378] Formatting * [PM-14378] Add unit tests for GetCipherPermissionsForUserQuery * [PM-15378] Cleanup SecurityTaskAuthorizationHandler and add tests * [PM-14378] Add tests for SecurityTaskOrganizationAuthorizationHandler * [PM-14378] Formatting * [PM-14378] Update date in migration file * [PM-14378] Add missing awaits * [PM-14378] Bump migration script date * [PM-14378] Remove Unassigned property from OrganizationCipherPermission as it was making the query too complicated * [PM-14378] Update sproc to use Union All to improve query performance * [PM-14378] Bump migration script date
78 lines
2.8 KiB
Transact-SQL
78 lines
2.8 KiB
Transact-SQL
CREATE OR ALTER PROCEDURE [dbo].[CipherOrganizationPermissions_GetManyByOrganizationId]
|
|
@OrganizationId UNIQUEIDENTIFIER,
|
|
@UserId UNIQUEIDENTIFIER
|
|
AS
|
|
BEGIN
|
|
SET NOCOUNT ON
|
|
|
|
;WITH BaseCiphers AS (
|
|
SELECT C.[Id], C.[OrganizationId]
|
|
FROM [dbo].[CipherDetails](@UserId) C
|
|
INNER JOIN [OrganizationUser] OU ON
|
|
C.[UserId] IS NULL
|
|
AND C.[OrganizationId] = @OrganizationId
|
|
AND OU.[UserId] = @UserId
|
|
INNER JOIN [dbo].[Organization] O ON
|
|
O.[Id] = OU.[OrganizationId]
|
|
AND O.[Id] = C.[OrganizationId]
|
|
AND O.[Enabled] = 1
|
|
),
|
|
UserPermissions AS (
|
|
SELECT DISTINCT
|
|
CC.[CipherId],
|
|
CASE WHEN CC.[CollectionId] IS NULL THEN 0 ELSE 1 END as [Read],
|
|
CASE WHEN CU.[HidePasswords] = 0 THEN 1 ELSE 0 END as [ViewPassword],
|
|
CASE WHEN CU.[ReadOnly] = 0 THEN 1 ELSE 0 END as [Edit],
|
|
COALESCE(CU.[Manage], 0) as [Manage]
|
|
FROM [dbo].[CollectionCipher] CC
|
|
INNER JOIN [dbo].[CollectionUser] CU ON
|
|
CU.[CollectionId] = CC.[CollectionId]
|
|
AND CU.[OrganizationUserId] = (
|
|
SELECT [Id] FROM [OrganizationUser]
|
|
WHERE [UserId] = @UserId
|
|
AND [OrganizationId] = @OrganizationId
|
|
)
|
|
),
|
|
GroupPermissions AS (
|
|
SELECT DISTINCT
|
|
CC.[CipherId],
|
|
CASE WHEN CC.[CollectionId] IS NULL THEN 0 ELSE 1 END as [Read],
|
|
CASE WHEN CG.[HidePasswords] = 0 THEN 1 ELSE 0 END as [ViewPassword],
|
|
CASE WHEN CG.[ReadOnly] = 0 THEN 1 ELSE 0 END as [Edit],
|
|
COALESCE(CG.[Manage], 0) as [Manage]
|
|
FROM [dbo].[CollectionCipher] CC
|
|
INNER JOIN [dbo].[CollectionGroup] CG ON
|
|
CG.[CollectionId] = CC.[CollectionId]
|
|
INNER JOIN [dbo].[GroupUser] GU ON
|
|
GU.[GroupId] = CG.[GroupId]
|
|
AND GU.[OrganizationUserId] = (
|
|
SELECT [Id] FROM [OrganizationUser]
|
|
WHERE [UserId] = @UserId
|
|
AND [OrganizationId] = @OrganizationId
|
|
)
|
|
WHERE NOT EXISTS (
|
|
SELECT 1
|
|
FROM UserPermissions UP
|
|
WHERE UP.[CipherId] = CC.[CipherId]
|
|
)
|
|
),
|
|
CombinedPermissions AS (
|
|
SELECT CipherId, [Read], ViewPassword, Edit, Manage
|
|
FROM UserPermissions
|
|
UNION ALL
|
|
SELECT CipherId, [Read], ViewPassword, Edit, Manage
|
|
FROM GroupPermissions
|
|
)
|
|
SELECT
|
|
C.[Id],
|
|
C.[OrganizationId],
|
|
ISNULL(MAX(P.[Read]), 0) as [Read],
|
|
ISNULL(MAX(P.[ViewPassword]), 0) as [ViewPassword],
|
|
ISNULL(MAX(P.[Edit]), 0) as [Edit],
|
|
ISNULL(MAX(P.[Manage]), 0) as [Manage]
|
|
FROM BaseCiphers C
|
|
LEFT JOIN CombinedPermissions P ON P.CipherId = C.[Id]
|
|
GROUP BY C.[Id], C.[OrganizationId]
|
|
END
|
|
GO
|