mirror of
https://github.com/bitwarden/server
synced 2025-12-29 06:33:43 +00:00
[PM-22108] Add PolicyDetails_ReadByOrganizationId proc (#6019)
This commit is contained in:
@@ -0,0 +1,6 @@
|
||||
namespace Bit.Core.AdminConsole.Models.Data.Organizations.Policies;
|
||||
|
||||
public class OrganizationPolicyDetails : PolicyDetails
|
||||
{
|
||||
public Guid UserId { get; set; }
|
||||
}
|
||||
@@ -31,4 +31,17 @@ public interface IPolicyRepository : IRepository<Policy, Guid>
|
||||
/// You probably do not want to call it directly.
|
||||
/// </remarks>
|
||||
Task<IEnumerable<PolicyDetails>> GetPolicyDetailsByUserId(Guid userId);
|
||||
|
||||
/// <summary>
|
||||
/// Retrieves <see cref="OrganizationPolicyDetails"/> of the specified <paramref name="policyType"/>
|
||||
/// for users in the given organization and for any other organizations those users belong to.
|
||||
/// </summary>
|
||||
/// <remarks>
|
||||
/// Each PolicyDetail represents an OrganizationUser and a Policy which *may* be enforced
|
||||
/// against them. It only returns PolicyDetails for policies that are enabled and where the organization's plan
|
||||
/// supports policies. It also excludes "revoked invited" users who are not subject to policy enforcement.
|
||||
/// This is consumed by <see cref="IPolicyRequirementQuery"/> to create requirements for specific policy types.
|
||||
/// You probably do not want to call it directly.
|
||||
/// </remarks>
|
||||
Task<IEnumerable<OrganizationPolicyDetails>> GetPolicyDetailsByOrganizationIdAsync(Guid organizationId, PolicyType policyType);
|
||||
}
|
||||
|
||||
@@ -73,4 +73,17 @@ public class PolicyRepository : Repository<Policy, Guid>, IPolicyRepository
|
||||
return results.ToList();
|
||||
}
|
||||
}
|
||||
|
||||
public async Task<IEnumerable<OrganizationPolicyDetails>> GetPolicyDetailsByOrganizationIdAsync(Guid organizationId, PolicyType policyType)
|
||||
{
|
||||
using (var connection = new SqlConnection(ConnectionString))
|
||||
{
|
||||
var results = await connection.QueryAsync<OrganizationPolicyDetails>(
|
||||
$"[{Schema}].[PolicyDetails_ReadByOrganizationId]",
|
||||
new { @OrganizationId = organizationId, @PolicyType = policyType },
|
||||
commandType: CommandType.StoredProcedure);
|
||||
|
||||
return results.ToList();
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
@@ -94,4 +94,93 @@ public class PolicyRepository : Repository<AdminConsoleEntities.Policy, Policy,
|
||||
};
|
||||
return await query.ToListAsync();
|
||||
}
|
||||
|
||||
public async Task<IEnumerable<OrganizationPolicyDetails>> GetPolicyDetailsByOrganizationIdAsync(Guid organizationId, PolicyType policyType)
|
||||
{
|
||||
using var scope = ServiceScopeFactory.CreateScope();
|
||||
var dbContext = GetDatabaseContext(scope);
|
||||
|
||||
var givenOrgUsers =
|
||||
from ou in dbContext.OrganizationUsers
|
||||
where ou.OrganizationId == organizationId
|
||||
from u in dbContext.Users
|
||||
where
|
||||
(u.Email == ou.Email && ou.Email != null)
|
||||
|| (ou.UserId == u.Id && ou.UserId != null)
|
||||
|
||||
select new
|
||||
{
|
||||
ou.Id,
|
||||
ou.OrganizationId,
|
||||
UserId = u.Id,
|
||||
u.Email
|
||||
};
|
||||
|
||||
var orgUsersLinkedByUserId =
|
||||
from ou in dbContext.OrganizationUsers
|
||||
join gou in givenOrgUsers
|
||||
on ou.UserId equals gou.UserId
|
||||
select new
|
||||
{
|
||||
ou.Id,
|
||||
ou.OrganizationId,
|
||||
gou.UserId,
|
||||
ou.Type,
|
||||
ou.Status,
|
||||
ou.Permissions
|
||||
};
|
||||
|
||||
var orgUsersLinkedByEmail =
|
||||
from ou in dbContext.OrganizationUsers
|
||||
join gou in givenOrgUsers
|
||||
on ou.Email equals gou.Email
|
||||
select new
|
||||
{
|
||||
ou.Id,
|
||||
ou.OrganizationId,
|
||||
gou.UserId,
|
||||
ou.Type,
|
||||
ou.Status,
|
||||
ou.Permissions
|
||||
};
|
||||
|
||||
var allAffectedOrgUsers = orgUsersLinkedByEmail.Union(orgUsersLinkedByUserId);
|
||||
|
||||
var providerOrganizations = from pu in dbContext.ProviderUsers
|
||||
join po in dbContext.ProviderOrganizations
|
||||
on pu.ProviderId equals po.ProviderId
|
||||
join ou in allAffectedOrgUsers
|
||||
on pu.UserId equals ou.UserId
|
||||
where pu.UserId == ou.UserId
|
||||
select new
|
||||
{
|
||||
pu.UserId,
|
||||
po.OrganizationId
|
||||
};
|
||||
|
||||
var policyWithAffectedUsers =
|
||||
from p in dbContext.Policies
|
||||
join o in dbContext.Organizations
|
||||
on p.OrganizationId equals o.Id
|
||||
join ou in allAffectedOrgUsers
|
||||
on o.Id equals ou.OrganizationId
|
||||
where p.Enabled
|
||||
&& o.Enabled
|
||||
&& o.UsePolicies
|
||||
&& p.Type == policyType
|
||||
select new OrganizationPolicyDetails
|
||||
{
|
||||
UserId = ou.UserId,
|
||||
OrganizationUserId = ou.Id,
|
||||
OrganizationId = p.OrganizationId,
|
||||
PolicyType = p.Type,
|
||||
PolicyData = p.Data,
|
||||
OrganizationUserType = ou.Type,
|
||||
OrganizationUserStatus = ou.Status,
|
||||
OrganizationUserPermissionsData = ou.Permissions,
|
||||
IsProvider = providerOrganizations.Any(po => po.OrganizationId == p.OrganizationId)
|
||||
};
|
||||
|
||||
return await policyWithAffectedUsers.ToListAsync();
|
||||
}
|
||||
}
|
||||
|
||||
@@ -0,0 +1,81 @@
|
||||
CREATE PROCEDURE [dbo].[PolicyDetails_ReadByOrganizationId]
|
||||
@OrganizationId UNIQUEIDENTIFIER,
|
||||
@PolicyType TINYINT
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
|
||||
-- Get users in the given organization (@OrganizationId) by matching either on UserId or Email.
|
||||
;WITH GivenOrgUsers AS (
|
||||
SELECT
|
||||
OU.[UserId],
|
||||
U.[Email]
|
||||
FROM [dbo].[OrganizationUserView] OU
|
||||
INNER JOIN [dbo].[UserView] U ON U.[Id] = OU.[UserId]
|
||||
WHERE OU.[OrganizationId] = @OrganizationId
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
U.[Id] AS [UserId],
|
||||
U.[Email]
|
||||
FROM [dbo].[OrganizationUserView] OU
|
||||
INNER JOIN [dbo].[UserView] U ON U.[Email] = OU.[Email]
|
||||
WHERE OU.[OrganizationId] = @OrganizationId
|
||||
),
|
||||
|
||||
-- Retrieve all organization users that match on either UserId or Email from GivenOrgUsers.
|
||||
AllOrgUsers AS (
|
||||
SELECT
|
||||
OU.[Id] AS [OrganizationUserId],
|
||||
OU.[UserId],
|
||||
OU.[OrganizationId],
|
||||
AU.[Email],
|
||||
OU.[Type] AS [OrganizationUserType],
|
||||
OU.[Status] AS [OrganizationUserStatus],
|
||||
OU.[Permissions] AS [OrganizationUserPermissionsData]
|
||||
FROM [dbo].[OrganizationUserView] OU
|
||||
INNER JOIN GivenOrgUsers AU ON AU.[UserId] = OU.[UserId]
|
||||
UNION ALL
|
||||
SELECT
|
||||
OU.[Id] AS [OrganizationUserId],
|
||||
AU.[UserId],
|
||||
OU.[OrganizationId],
|
||||
AU.[Email],
|
||||
OU.[Type] AS [OrganizationUserType],
|
||||
OU.[Status] AS [OrganizationUserStatus],
|
||||
OU.[Permissions] AS [OrganizationUserPermissionsData]
|
||||
FROM [dbo].[OrganizationUserView] OU
|
||||
INNER JOIN GivenOrgUsers AU ON AU.[Email] = OU.[Email]
|
||||
)
|
||||
|
||||
-- Return policy details for each matching organization user.
|
||||
SELECT
|
||||
OU.[OrganizationUserId],
|
||||
P.[OrganizationId],
|
||||
P.[Type] AS [PolicyType],
|
||||
P.[Data] AS [PolicyData],
|
||||
OU.[OrganizationUserType],
|
||||
OU.[OrganizationUserStatus],
|
||||
OU.[OrganizationUserPermissionsData],
|
||||
-- Check if user is a provider for the organization
|
||||
CASE
|
||||
WHEN EXISTS (
|
||||
SELECT 1
|
||||
FROM [dbo].[ProviderUserView] PU
|
||||
INNER JOIN [dbo].[ProviderOrganizationView] PO ON PO.[ProviderId] = PU.[ProviderId]
|
||||
WHERE PU.[UserId] = OU.[UserId]
|
||||
AND PO.[OrganizationId] = P.[OrganizationId]
|
||||
) THEN 1
|
||||
ELSE 0
|
||||
END AS [IsProvider]
|
||||
FROM [dbo].[PolicyView] P
|
||||
INNER JOIN [dbo].[OrganizationView] O ON P.[OrganizationId] = O.[Id]
|
||||
INNER JOIN AllOrgUsers OU ON OU.[OrganizationId] = O.[Id]
|
||||
WHERE P.[Enabled] = 1
|
||||
AND O.[Enabled] = 1
|
||||
AND O.[UsePolicies] = 1
|
||||
AND P.[Type] = @PolicyType
|
||||
|
||||
END
|
||||
GO
|
||||
@@ -17,20 +17,21 @@
|
||||
CONSTRAINT [FK_OrganizationUser_User] FOREIGN KEY ([UserId]) REFERENCES [dbo].[User] ([Id])
|
||||
);
|
||||
|
||||
|
||||
GO
|
||||
CREATE NONCLUSTERED INDEX [IX_OrganizationUser_UserIdOrganizationIdStatusV2]
|
||||
ON [dbo].[OrganizationUser]([UserId] ASC, [OrganizationId] ASC, [Status] ASC);
|
||||
|
||||
|
||||
GO
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_OrganizationUser_OrganizationId]
|
||||
ON [dbo].[OrganizationUser]([OrganizationId] ASC);
|
||||
GO
|
||||
|
||||
CREATE NONCLUSTERED INDEX IX_OrganizationUser_EmailOrganizationIdStatus
|
||||
ON OrganizationUser (Email ASC, OrganizationId ASC, [Status] ASC);
|
||||
GO
|
||||
|
||||
CREATE NONCLUSTERED INDEX [IX_OrganizationUser_OrganizationId_UserId]
|
||||
ON [dbo].[OrganizationUser] ([OrganizationId], [UserId])
|
||||
INCLUDE ([Email], [Status], [Type], [ExternalId], [CreationDate],
|
||||
INCLUDE ([Email], [Status], [Type], [ExternalId], [CreationDate],
|
||||
[RevisionDate], [Permissions], [ResetPasswordKey], [AccessSecretsManager]);
|
||||
GO
|
||||
|
||||
@@ -10,3 +10,7 @@
|
||||
CONSTRAINT [FK_ProviderOrganization_Provider] FOREIGN KEY ([ProviderId]) REFERENCES [dbo].[Provider] ([Id]) ON DELETE CASCADE,
|
||||
CONSTRAINT [FK_ProviderOrganization_Organization] FOREIGN KEY ([OrganizationId]) REFERENCES [dbo].[Organization] ([Id])
|
||||
);
|
||||
|
||||
GO
|
||||
CREATE NONCLUSTERED INDEX IX_ProviderOrganization_OrganizationIdProviderId
|
||||
ON [dbo].[ProviderOrganization] ([OrganizationId], [ProviderId]);
|
||||
|
||||
@@ -13,3 +13,8 @@
|
||||
CONSTRAINT [FK_ProviderUser_Provider] FOREIGN KEY ([ProviderId]) REFERENCES [dbo].[Provider] ([Id]) ON DELETE CASCADE,
|
||||
CONSTRAINT [FK_ProviderUser_User] FOREIGN KEY ([UserId]) REFERENCES [dbo].[User] ([Id])
|
||||
);
|
||||
|
||||
|
||||
GO
|
||||
CREATE NONCLUSTERED INDEX IX_ProviderUser_UserIdProviderId
|
||||
ON [dbo].[ProviderUser] ([UserId], [ProviderId]);
|
||||
|
||||
Reference in New Issue
Block a user