1
0
mirror of https://github.com/bitwarden/server.git synced 2025-07-19 00:21:35 -05:00

[PM-18972] - Fix query for Org By User Domain (#5474)

* Changed query to avoid table scan. Added index to speed up query as well.
This commit is contained in:
Jared McCannon
2025-03-06 20:32:21 -06:00
committed by GitHub
parent bea0d0d76f
commit 6cb97d9bf9
4 changed files with 73 additions and 18 deletions

View File

@ -4,12 +4,19 @@ AS
BEGIN
SET NOCOUNT ON;
WITH CTE_User AS (
SELECT
U.*,
SUBSTRING(U.Email, CHARINDEX('@', U.Email) + 1, LEN(U.Email)) AS EmailDomain
FROM dbo.[UserView] U
WHERE U.[Id] = @UserId
)
SELECT O.*
FROM [dbo].[UserView] U
INNER JOIN [dbo].[OrganizationUserView] OU ON U.[Id] = OU.[UserId]
INNER JOIN [dbo].[OrganizationView] O ON OU.[OrganizationId] = O.[Id]
INNER JOIN [dbo].[OrganizationDomainView] OD ON OU.[OrganizationId] = OD.[OrganizationId]
WHERE U.[Id] = @UserId
AND OD.[VerifiedDate] IS NOT NULL
AND U.[Email] LIKE '%@' + OD.[DomainName];
FROM CTE_User CU
INNER JOIN dbo.[OrganizationUserView] OU ON CU.[Id] = OU.[UserId]
INNER JOIN dbo.[OrganizationView] O ON OU.[OrganizationId] = O.[Id]
INNER JOIN dbo.[OrganizationDomainView] OD ON OU.[OrganizationId] = OD.[OrganizationId]
WHERE OD.[VerifiedDate] IS NOT NULL
AND CU.EmailDomain = OD.[DomainName]
AND O.[Enabled] = 1
END

View File

@ -22,3 +22,8 @@ CREATE NONCLUSTERED INDEX [IX_OrganizationDomain_VerifiedDate]
ON [dbo].[OrganizationDomain] ([VerifiedDate])
INCLUDE ([OrganizationId],[DomainName]);
GO
CREATE NONCLUSTERED INDEX [IX_OrganizationDomain_DomainNameVerifiedDateOrganizationId]
ON [dbo].[OrganizationDomain] ([DomainName],[VerifiedDate])
INCLUDE ([OrganizationId])
GO