1
0
mirror of https://github.com/bitwarden/server.git synced 2025-03-12 13:29:14 +01:00
bitwarden-server/util/Migrator/DbScripts/2025-02-14_00_PolicyDetails_ReadByUserId.sql
Thomas Rittson f4341b2f3b
[PM-14439] Add PolicyRequirementQuery for enforcement logic (#5336)
* Add PolicyRequirementQuery, helpers and models in preparation for migrating domain code

Co-authored-by: Rui Tomé <108268980+r-tome@users.noreply.github.com>
2025-02-14 11:05:49 +00:00

44 lines
1.7 KiB
Transact-SQL

CREATE OR ALTER PROCEDURE [dbo].[PolicyDetails_ReadByUserId]
@UserId UNIQUEIDENTIFIER
AS
BEGIN
SET NOCOUNT ON
SELECT
OU.[Id] AS OrganizationUserId,
P.[OrganizationId],
P.[Type] AS PolicyType,
P.[Data] AS PolicyData,
OU.[Type] AS OrganizationUserType,
OU.[Status] AS OrganizationUserStatus,
OU.[Permissions] AS OrganizationUserPermissionsData,
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].[OrganizationUserView] OU
ON P.[OrganizationId] = OU.[OrganizationId]
INNER JOIN [dbo].[OrganizationView] O
ON P.[OrganizationId] = O.[Id]
WHERE
P.Enabled = 1
AND O.Enabled = 1
AND O.UsePolicies = 1
AND (
-- OrgUsers who have accepted their invite and are linked to a UserId
-- (Note: this excludes "invited but revoked" users who don't have an OU.UserId yet,
-- but those users will go through policy enforcement later as part of accepting their invite after being restored.
-- This is an intentionally unhandled edge case for now.)
(OU.[Status] != 0 AND OU.[UserId] = @UserId)
-- 'Invited' OrgUsers are not linked to a UserId yet, so we have to look up their email
OR EXISTS (
SELECT 1
FROM [dbo].[UserView] U
WHERE U.[Id] = @UserId AND OU.[Email] = U.[Email] AND OU.[Status] = 0
)
)
END