From 92f7a7794b5f6635e2972703d1c7cba3eeeb7c6b Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Mon, 2 Jun 2025 14:04:41 +0100 Subject: [PATCH 01/25] Add new feature flag for Members Get Endpoint Optimization --- src/Core/Constants.cs | 1 + 1 file changed, 1 insertion(+) diff --git a/src/Core/Constants.cs b/src/Core/Constants.cs index 3769cafc5c0c..1cf930e5c46b 100644 --- a/src/Core/Constants.cs +++ b/src/Core/Constants.cs @@ -111,6 +111,7 @@ public static class FeatureFlagKeys public const string EventBasedOrganizationIntegrations = "event-based-organization-integrations"; public const string OptimizeNestedTraverseTypescript = "pm-21695-optimize-nested-traverse-typescript"; public const string SeparateCustomRolePermissions = "pm-19917-separate-custom-role-permissions"; + public const string MembersGetEndpointOptimization = "pm-21031-members-get-endpoint-optimization"; /* Auth Team */ public const string PM9112DeviceApprovalPersistence = "pm-9112-device-approval-persistence"; From 08688d6540c2641e4a971698279e78e208429408 Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Mon, 2 Jun 2025 14:21:33 +0100 Subject: [PATCH 02/25] Add a new version of OrganizationUser_ReadByOrganizationIdWithClaimedDomains that uses CTE for better performance --- ...dByOrganizationIdWithClaimedDomains_V2.sql | 20 +++++++++++++++++++ 1 file changed, 20 insertions(+) create mode 100644 src/Sql/dbo/Stored Procedures/OrganizationUser_ReadByOrganizationIdWithClaimedDomains_V2.sql diff --git a/src/Sql/dbo/Stored Procedures/OrganizationUser_ReadByOrganizationIdWithClaimedDomains_V2.sql b/src/Sql/dbo/Stored Procedures/OrganizationUser_ReadByOrganizationIdWithClaimedDomains_V2.sql new file mode 100644 index 000000000000..0655eecdbdc5 --- /dev/null +++ b/src/Sql/dbo/Stored Procedures/OrganizationUser_ReadByOrganizationIdWithClaimedDomains_V2.sql @@ -0,0 +1,20 @@ +CREATE PROCEDURE [dbo].[OrganizationUser_ReadByOrganizationIdWithClaimedDomains_V2] + @OrganizationId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON; + + WITH CTE_UserWithDomain AS ( + SELECT + OU.*, + SUBSTRING(U.Email, CHARINDEX('@', U.Email) + 1, LEN(U.Email)) AS EmailDomain + FROM [dbo].[OrganizationUserView] OU + INNER JOIN [dbo].[UserView] U ON OU.[UserId] = U.[Id] + WHERE OU.[OrganizationId] = @OrganizationId + ) + SELECT OU.* + FROM CTE_UserWithDomain OU + INNER JOIN [dbo].[OrganizationDomainView] OD ON OU.[OrganizationId] = OD.[OrganizationId] + WHERE OD.[VerifiedDate] IS NOT NULL + AND OU.EmailDomain = OD.[DomainName] +END From 3fa2797a4dbf10d3f3301ae215265d3aaee6ecd7 Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Mon, 2 Jun 2025 14:22:19 +0100 Subject: [PATCH 03/25] Add stored procedure OrganizationUserUserDetails_ReadByOrganizationId_V2 for retrieving user details, group associations, and collection associations by organization ID. --- ...serUserDetails_ReadByOrganizationId_V2.sql | 31 +++++++++++++++++++ 1 file changed, 31 insertions(+) create mode 100644 src/Sql/dbo/Stored Procedures/OrganizationUserUserDetails_ReadByOrganizationId_V2.sql diff --git a/src/Sql/dbo/Stored Procedures/OrganizationUserUserDetails_ReadByOrganizationId_V2.sql b/src/Sql/dbo/Stored Procedures/OrganizationUserUserDetails_ReadByOrganizationId_V2.sql new file mode 100644 index 000000000000..6bf32089c257 --- /dev/null +++ b/src/Sql/dbo/Stored Procedures/OrganizationUserUserDetails_ReadByOrganizationId_V2.sql @@ -0,0 +1,31 @@ +CREATE PROCEDURE [dbo].[OrganizationUserUserDetails_ReadByOrganizationId_V2] + @OrganizationId UNIQUEIDENTIFIER, + @IncludeGroups BIT = 0, + @IncludeCollections BIT = 0 +AS +BEGIN + SET NOCOUNT ON + + -- Result Set 1: User Details (always returned) + SELECT * + FROM [dbo].[OrganizationUserUserDetailsView] + WHERE OrganizationId = @OrganizationId + + -- Result Set 2: Group associations (if requested) + IF @IncludeGroups = 1 + BEGIN + SELECT gu.* + FROM [dbo].[GroupUser] gu + INNER JOIN [dbo].[OrganizationUser] ou ON gu.OrganizationUserId = ou.Id + WHERE ou.OrganizationId = @OrganizationId + END + + -- Result Set 3: Collection associations (if requested) + IF @IncludeCollections = 1 + BEGIN + SELECT cu.* + FROM [dbo].[CollectionUser] cu + INNER JOIN [dbo].[OrganizationUser] ou ON cu.OrganizationUserId = ou.Id + WHERE ou.OrganizationId = @OrganizationId + END +END From 5fdad604379fea6c58d3edb40b0295c6f7ae11a3 Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Mon, 2 Jun 2025 14:22:41 +0100 Subject: [PATCH 04/25] Add the sql migration script to add the new stored procedures --- ...25-06-02_00_OrgUsersQueryOptimizations.sql | 54 +++++++++++++++++++ 1 file changed, 54 insertions(+) create mode 100644 util/Migrator/DbScripts/2025-06-02_00_OrgUsersQueryOptimizations.sql diff --git a/util/Migrator/DbScripts/2025-06-02_00_OrgUsersQueryOptimizations.sql b/util/Migrator/DbScripts/2025-06-02_00_OrgUsersQueryOptimizations.sql new file mode 100644 index 000000000000..3aadff70da66 --- /dev/null +++ b/util/Migrator/DbScripts/2025-06-02_00_OrgUsersQueryOptimizations.sql @@ -0,0 +1,54 @@ +CREATE OR ALTER PROCEDURE [dbo].[OrganizationUserUserDetails_ReadByOrganizationId_V2] + @OrganizationId UNIQUEIDENTIFIER, + @IncludeGroups BIT = 0, + @IncludeCollections BIT = 0 +AS +BEGIN + SET NOCOUNT ON + + -- Result Set 1: User Details (always returned) + SELECT * + FROM [dbo].[OrganizationUserUserDetailsView] + WHERE OrganizationId = @OrganizationId + + -- Result Set 2: Group associations (if requested) + IF @IncludeGroups = 1 + BEGIN + SELECT gu.* + FROM [dbo].[GroupUser] gu + INNER JOIN [dbo].[OrganizationUser] ou ON gu.OrganizationUserId = ou.Id + WHERE ou.OrganizationId = @OrganizationId + END + + -- Result Set 3: Collection associations (if requested) + IF @IncludeCollections = 1 + BEGIN + SELECT cu.* + FROM [dbo].[CollectionUser] cu + INNER JOIN [dbo].[OrganizationUser] ou ON cu.OrganizationUserId = ou.Id + WHERE ou.OrganizationId = @OrganizationId + END +END +GO + +CREATE OR ALTER PROCEDURE [dbo].[OrganizationUser_ReadByOrganizationIdWithClaimedDomains_V2] + @OrganizationId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON; + + WITH CTE_UserWithDomain AS ( + SELECT + OU.*, + SUBSTRING(U.Email, CHARINDEX('@', U.Email) + 1, LEN(U.Email)) AS EmailDomain + FROM [dbo].[OrganizationUserView] OU + INNER JOIN [dbo].[UserView] U ON OU.[UserId] = U.[Id] + WHERE OU.[OrganizationId] = @OrganizationId + ) + SELECT OU.* + FROM CTE_UserWithDomain OU + INNER JOIN [dbo].[OrganizationDomainView] OD ON OU.[OrganizationId] = OD.[OrganizationId] + WHERE OD.[VerifiedDate] IS NOT NULL + AND OU.EmailDomain = OD.[DomainName] +END +GO From b40e8131c769e00da57d9a799db80410deefecd2 Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Mon, 2 Jun 2025 14:23:35 +0100 Subject: [PATCH 05/25] Introduce GetManyDetailsByOrganizationAsync_vNext and GetManyByOrganizationWithClaimedDomainsAsync_vNext in IOrganizationUserRepository to enhance performance by reducing database round trips. --- .../IOrganizationUserRepository.cs | 10 ++- .../OrganizationUserRepository.cs | 75 +++++++++++++++++++ .../OrganizationUserRepository.cs | 56 ++++++++++++++ 3 files changed, 140 insertions(+), 1 deletion(-) diff --git a/src/Core/AdminConsole/Repositories/IOrganizationUserRepository.cs b/src/Core/AdminConsole/Repositories/IOrganizationUserRepository.cs index 9692de897cad..68f2fdda2a1e 100644 --- a/src/Core/AdminConsole/Repositories/IOrganizationUserRepository.cs +++ b/src/Core/AdminConsole/Repositories/IOrganizationUserRepository.cs @@ -34,6 +34,11 @@ public interface IOrganizationUserRepository : IRepository GetDetailsByIdAsync(Guid id); Task<(OrganizationUserUserDetails? OrganizationUser, ICollection Collections)> GetDetailsByIdWithCollectionsAsync(Guid id); Task> GetManyDetailsByOrganizationAsync(Guid organizationId, bool includeGroups = false, bool includeCollections = false); + /// + /// Optimized version of with better performance. + /// Reduces database round trips by fetching all data in fewer queries. + /// + Task> GetManyDetailsByOrganizationAsync_vNext(Guid organizationId, bool includeGroups = false, bool includeCollections = false); Task> GetManyDetailsByUserAsync(Guid userId, OrganizationUserStatusType? status = null); Task GetDetailsByUserAsync(Guid userId, Guid organizationId, @@ -68,7 +73,10 @@ UpdateEncryptedDataForKeyRotation UpdateForKeyRotation(Guid userId, /// Returns a list of OrganizationUsers with email domains that match one of the Organization's claimed domains. /// Task> GetManyByOrganizationWithClaimedDomainsAsync(Guid organizationId); - + /// + /// Optimized version of with better performance. + /// + Task> GetManyByOrganizationWithClaimedDomainsAsync_vNext(Guid organizationId); Task RevokeManyByIdAsync(IEnumerable organizationUserIds); /// diff --git a/src/Infrastructure.Dapper/AdminConsole/Repositories/OrganizationUserRepository.cs b/src/Infrastructure.Dapper/AdminConsole/Repositories/OrganizationUserRepository.cs index 8968d1d2436a..3694bfad4ed5 100644 --- a/src/Infrastructure.Dapper/AdminConsole/Repositories/OrganizationUserRepository.cs +++ b/src/Infrastructure.Dapper/AdminConsole/Repositories/OrganizationUserRepository.cs @@ -277,6 +277,68 @@ public async Task> GetManyDetailsByOrga } } + public async Task> GetManyDetailsByOrganizationAsync_vNext(Guid organizationId, bool includeGroups, bool includeCollections) + { + using (var connection = new SqlConnection(ConnectionString)) + { + // Use a single call that returns multiple result sets + var results = await connection.QueryMultipleAsync( + "[dbo].[OrganizationUserUserDetails_ReadByOrganizationId_V2]", + new + { + OrganizationId = organizationId, + IncludeGroups = includeGroups, + IncludeCollections = includeCollections + }, + commandType: CommandType.StoredProcedure); + + // Read the user details (first result set) + var users = (await results.ReadAsync()).ToList(); + + // Read group associations (second result set, if requested) + Dictionary>? userGroupMap = null; + if (includeGroups) + { + var groupUsers = await results.ReadAsync(); + userGroupMap = groupUsers + .GroupBy(gu => gu.OrganizationUserId) + .ToDictionary(g => g.Key, g => g.Select(gu => gu.GroupId).ToList()); + } + + // Read collection associations (third result set, if requested) + Dictionary>? userCollectionMap = null; + if (includeCollections) + { + var collectionUsers = await results.ReadAsync(); + userCollectionMap = collectionUsers + .GroupBy(cu => cu.OrganizationUserId) + .ToDictionary(g => g.Key, g => g.Select(cu => new CollectionAccessSelection + { + Id = cu.CollectionId, + ReadOnly = cu.ReadOnly, + HidePasswords = cu.HidePasswords, + Manage = cu.Manage + }).ToList()); + } + + // Map the associations to users + foreach (var user in users) + { + if (userGroupMap != null) + { + user.Groups = userGroupMap.GetValueOrDefault(user.Id, new List()); + } + + if (userCollectionMap != null) + { + user.Collections = userCollectionMap.GetValueOrDefault(user.Id, new List()); + } + } + + return users; + } + } + public async Task> GetManyDetailsByUserAsync(Guid userId, OrganizationUserStatusType? status = null) { @@ -559,6 +621,19 @@ public async Task> GetManyByOrganizationWithClaime } } + public async Task> GetManyByOrganizationWithClaimedDomainsAsync_vNext(Guid organizationId) + { + using (var connection = new SqlConnection(ConnectionString)) + { + var results = await connection.QueryAsync( + $"[{Schema}].[OrganizationUser_ReadByOrganizationIdWithClaimedDomains_V2]", + new { OrganizationId = organizationId }, + commandType: CommandType.StoredProcedure); + + return results.ToList(); + } + } + public async Task RevokeManyByIdAsync(IEnumerable organizationUserIds) { await using var connection = new SqlConnection(ConnectionString); diff --git a/src/Infrastructure.EntityFramework/AdminConsole/Repositories/OrganizationUserRepository.cs b/src/Infrastructure.EntityFramework/AdminConsole/Repositories/OrganizationUserRepository.cs index fc5626631aa7..aab11ada707b 100644 --- a/src/Infrastructure.EntityFramework/AdminConsole/Repositories/OrganizationUserRepository.cs +++ b/src/Infrastructure.EntityFramework/AdminConsole/Repositories/OrganizationUserRepository.cs @@ -404,6 +404,56 @@ join ou in userIdEntities on cu.OrganizationUserId equals ou.Id } } + public async Task> GetManyDetailsByOrganizationAsync_vNext( + Guid organizationId, bool includeGroups, bool includeCollections) + { + using var scope = ServiceScopeFactory.CreateScope(); + var dbContext = GetDatabaseContext(scope); + + var query = from ou in dbContext.OrganizationUsers + where ou.OrganizationId == organizationId + select new OrganizationUserUserDetails + { + Id = ou.Id, + UserId = ou.UserId, + OrganizationId = ou.OrganizationId, + Name = ou.User.Name, + Email = ou.User.Email ?? ou.Email, + AvatarColor = ou.User.AvatarColor, + TwoFactorProviders = ou.User.TwoFactorProviders, + Premium = ou.User.Premium, + Status = ou.Status, + Type = ou.Type, + ExternalId = ou.ExternalId, + SsoExternalId = ou.User.SsoUsers + .Where(su => su.OrganizationId == ou.OrganizationId) + .Select(su => su.ExternalId) + .FirstOrDefault(), + Permissions = ou.Permissions, + ResetPasswordKey = ou.ResetPasswordKey, + UsesKeyConnector = ou.User != null && ou.User.UsesKeyConnector, + AccessSecretsManager = ou.AccessSecretsManager, + HasMasterPassword = ou.User != null && !string.IsNullOrWhiteSpace(ou.User.MasterPassword), + + // Project directly from navigation properties with conditional loading + Groups = includeGroups + ? ou.GroupUsers.Select(gu => gu.GroupId).ToList() + : new List(), + + Collections = includeCollections + ? ou.CollectionUsers.Select(cu => new CollectionAccessSelection + { + Id = cu.CollectionId, + ReadOnly = cu.ReadOnly, + HidePasswords = cu.HidePasswords, + Manage = cu.Manage + }).ToList() + : new List() + }; + + return await query.ToListAsync(); + } + public async Task> GetManyDetailsByUserAsync(Guid userId, OrganizationUserStatusType? status = null) { @@ -732,6 +782,12 @@ public UpdateEncryptedDataForKeyRotation UpdateForKeyRotation( } } + public async Task> GetManyByOrganizationWithClaimedDomainsAsync_vNext(Guid organizationId) + { + // No EF optimization is required for this query + return await GetManyByOrganizationWithClaimedDomainsAsync(organizationId); + } + public async Task RevokeManyByIdAsync(IEnumerable organizationUserIds) { using var scope = ServiceScopeFactory.CreateScope(); From 0579ec4160e1bea90de9229071717f4b19a4ab05 Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Mon, 2 Jun 2025 14:25:27 +0100 Subject: [PATCH 06/25] Updated GetOrganizationUsersClaimedStatusQuery to use an optimized query when the feature flag is enabled --- .../GetOrganizationUsersClaimedStatusQuery.cs | 9 +++++++-- 1 file changed, 7 insertions(+), 2 deletions(-) diff --git a/src/Core/AdminConsole/OrganizationFeatures/OrganizationUsers/GetOrganizationUsersClaimedStatusQuery.cs b/src/Core/AdminConsole/OrganizationFeatures/OrganizationUsers/GetOrganizationUsersClaimedStatusQuery.cs index d8c510119ae6..b27da2a22efa 100644 --- a/src/Core/AdminConsole/OrganizationFeatures/OrganizationUsers/GetOrganizationUsersClaimedStatusQuery.cs +++ b/src/Core/AdminConsole/OrganizationFeatures/OrganizationUsers/GetOrganizationUsersClaimedStatusQuery.cs @@ -8,13 +8,16 @@ public class GetOrganizationUsersClaimedStatusQuery : IGetOrganizationUsersClaim { private readonly IApplicationCacheService _applicationCacheService; private readonly IOrganizationUserRepository _organizationUserRepository; + private readonly IFeatureService _featureService; public GetOrganizationUsersClaimedStatusQuery( IApplicationCacheService applicationCacheService, - IOrganizationUserRepository organizationUserRepository) + IOrganizationUserRepository organizationUserRepository, + IFeatureService featureService) { _applicationCacheService = applicationCacheService; _organizationUserRepository = organizationUserRepository; + _featureService = featureService; } public async Task> GetUsersOrganizationClaimedStatusAsync(Guid organizationId, IEnumerable organizationUserIds) @@ -27,7 +30,9 @@ public async Task> GetUsersOrganizationClaimedStatusAsyn if (organizationAbility is { Enabled: true, UseOrganizationDomains: true }) { // Get all organization users with claimed domains by the organization - var organizationUsersWithClaimedDomain = await _organizationUserRepository.GetManyByOrganizationWithClaimedDomainsAsync(organizationId); + var organizationUsersWithClaimedDomain = _featureService.IsEnabled(FeatureFlagKeys.MembersGetEndpointOptimization) + ? await _organizationUserRepository.GetManyByOrganizationWithClaimedDomainsAsync_vNext(organizationId) + : await _organizationUserRepository.GetManyByOrganizationWithClaimedDomainsAsync(organizationId); // Create a dictionary with the OrganizationUserId and a boolean indicating if the user is claimed by the organization return organizationUserIds.ToDictionary(ouId => ouId, ouId => organizationUsersWithClaimedDomain.Any(ou => ou.Id == ouId)); From 516509abc9ab3e0b2f00facf79cc1b74657bc8aa Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Mon, 2 Jun 2025 14:27:59 +0100 Subject: [PATCH 07/25] Updated OrganizationUserUserDetailsQuery to use optimized queries when the feature flag is enabled --- .../OrganizationUserUserDetailsQuery.cs | 66 ++++++++++++++++++- 1 file changed, 65 insertions(+), 1 deletion(-) diff --git a/src/Core/AdminConsole/OrganizationFeatures/OrganizationUsers/OrganizationUserUserDetailsQuery.cs b/src/Core/AdminConsole/OrganizationFeatures/OrganizationUsers/OrganizationUserUserDetailsQuery.cs index 587e04826b6a..498ec2a94ad6 100644 --- a/src/Core/AdminConsole/OrganizationFeatures/OrganizationUsers/OrganizationUserUserDetailsQuery.cs +++ b/src/Core/AdminConsole/OrganizationFeatures/OrganizationUsers/OrganizationUserUserDetailsQuery.cs @@ -1,4 +1,5 @@ -using Bit.Core.AdminConsole.OrganizationFeatures.OrganizationUsers.Interfaces; +using Bit.Core; +using Bit.Core.AdminConsole.OrganizationFeatures.OrganizationUsers.Interfaces; using Bit.Core.Auth.UserFeatures.TwoFactorAuth.Interfaces; using Bit.Core.Enums; using Bit.Core.Models.Data.Organizations.OrganizationUsers; @@ -59,6 +60,11 @@ public async Task> GetOrganizationUserU /// List of OrganizationUserUserDetails public async Task> Get(OrganizationUserUserDetailsQueryRequest request) { + if (_featureService.IsEnabled(FeatureFlagKeys.MembersGetEndpointOptimization)) + { + return await Get_vNext(request); + } + var organizationUsers = await GetOrganizationUserUserDetails(request); var organizationUsersTwoFactorEnabled = (await _twoFactorIsEnabledQuery.TwoFactorIsEnabledAsync(organizationUsers)).ToDictionary(u => u.user.Id); @@ -77,6 +83,11 @@ public async Task> GetOrganizationUserU /// List of OrganizationUserUserDetails public async Task> GetAccountRecoveryEnrolledUsers(OrganizationUserUserDetailsQueryRequest request) { + if (_featureService.IsEnabled(FeatureFlagKeys.MembersGetEndpointOptimization)) + { + return await GetAccountRecoveryEnrolledUsers_vNext(request); + } + var organizationUsers = (await GetOrganizationUserUserDetails(request)) .Where(o => o.Status.Equals(OrganizationUserStatusType.Confirmed) && o.UsesKeyConnector == false && !String.IsNullOrEmpty(o.ResetPasswordKey)); @@ -88,4 +99,57 @@ public async Task> GetOrganizationUserU return responses; } + private async Task> Get_vNext(OrganizationUserUserDetailsQueryRequest request) + { + var organizationUsers = await _organizationUserRepository + .GetManyDetailsByOrganizationAsync_vNext(request.OrganizationId, request.IncludeGroups, request.IncludeCollections); + + var twoFactorTask = _twoFactorIsEnabledQuery.TwoFactorIsEnabledAsync(organizationUsers); + var claimedStatusTask = _getOrganizationUsersClaimedStatusQuery.GetUsersOrganizationClaimedStatusAsync(request.OrganizationId, organizationUsers.Select(o => o.Id)); + + await Task.WhenAll(twoFactorTask, claimedStatusTask); + + var organizationUsersTwoFactorEnabled = twoFactorTask.Result.ToDictionary(u => u.user.Id, u => u.twoFactorIsEnabled); + var organizationUsersClaimedStatus = claimedStatusTask.Result; + var responses = organizationUsers.Select(organizationUserDetails => + { + var organizationUserPermissions = organizationUserDetails.GetPermissions(); + organizationUserDetails.Permissions = CoreHelpers.ClassToJsonData(organizationUserPermissions); + + var userHasTwoFactorEnabled = organizationUsersTwoFactorEnabled[organizationUserDetails.Id]; + var userIsClaimedByOrganization = organizationUsersClaimedStatus[organizationUserDetails.Id]; + + return (organizationUserDetails, userHasTwoFactorEnabled, userIsClaimedByOrganization); + }); + + return responses; + } + + private async Task> GetAccountRecoveryEnrolledUsers_vNext(OrganizationUserUserDetailsQueryRequest request) + { + var organizationUsers = (await _organizationUserRepository + .GetManyDetailsByOrganizationAsync_vNext(request.OrganizationId, request.IncludeGroups, request.IncludeCollections)) + .Where(o => o.Status.Equals(OrganizationUserStatusType.Confirmed) && o.UsesKeyConnector == false && !String.IsNullOrEmpty(o.ResetPasswordKey)) + .ToArray(); + + var twoFactorTask = _twoFactorIsEnabledQuery.TwoFactorIsEnabledAsync(organizationUsers); + var claimedStatusTask = _getOrganizationUsersClaimedStatusQuery.GetUsersOrganizationClaimedStatusAsync(request.OrganizationId, organizationUsers.Select(o => o.Id)); + + await Task.WhenAll(twoFactorTask, claimedStatusTask); + + var organizationUsersTwoFactorEnabled = twoFactorTask.Result.ToDictionary(u => u.user.Id, u => u.twoFactorIsEnabled); + var organizationUsersClaimedStatus = claimedStatusTask.Result; + var responses = organizationUsers.Select(organizationUserDetails => + { + var organizationUserPermissions = organizationUserDetails.GetPermissions(); + organizationUserDetails.Permissions = CoreHelpers.ClassToJsonData(organizationUserPermissions); + + var userHasTwoFactorEnabled = organizationUsersTwoFactorEnabled[organizationUserDetails.Id]; + var userIsClaimedByOrganization = organizationUsersClaimedStatus[organizationUserDetails.Id]; + + return (organizationUserDetails, userHasTwoFactorEnabled, userIsClaimedByOrganization); + }); + + return responses; + } } From b9e2f5f0a3e418ab411966bdfdb3613fd045a9ff Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Mon, 2 Jun 2025 15:12:32 +0100 Subject: [PATCH 08/25] Add integration tests for GetManyDetailsByOrganizationAsync_vNext --- .../OrganizationUserRepositoryTests.cs | 248 +++++++++++++++++- 1 file changed, 247 insertions(+), 1 deletion(-) diff --git a/test/Infrastructure.IntegrationTest/AdminConsole/Repositories/OrganizationUserRepository/OrganizationUserRepositoryTests.cs b/test/Infrastructure.IntegrationTest/AdminConsole/Repositories/OrganizationUserRepository/OrganizationUserRepositoryTests.cs index 0df5dcfb503c..0fa8e6e897e8 100644 --- a/test/Infrastructure.IntegrationTest/AdminConsole/Repositories/OrganizationUserRepository/OrganizationUserRepositoryTests.cs +++ b/test/Infrastructure.IntegrationTest/AdminConsole/Repositories/OrganizationUserRepository/OrganizationUserRepositoryTests.cs @@ -142,18 +142,24 @@ public async Task GetManyAccountRecoveryDetailsByOrganizationUserAsync_Works(IUs var orgUser1 = await organizationUserRepository.CreateAsync(new OrganizationUser { + Id = CoreHelpers.GenerateComb(), OrganizationId = organization.Id, UserId = user1.Id, Status = OrganizationUserStatusType.Confirmed, + Type = OrganizationUserType.Owner, ResetPasswordKey = "resetpasswordkey1", + AccessSecretsManager = false }); var orgUser2 = await organizationUserRepository.CreateAsync(new OrganizationUser { + Id = CoreHelpers.GenerateComb(), OrganizationId = organization.Id, UserId = user2.Id, - Status = OrganizationUserStatusType.Confirmed, + Status = OrganizationUserStatusType.Invited, + Type = OrganizationUserType.User, ResetPasswordKey = "resetpasswordkey2", + AccessSecretsManager = true }); var recoveryDetails = await organizationUserRepository.GetManyAccountRecoveryDetailsByOrganizationUserAsync( @@ -211,10 +217,13 @@ public async Task GetManyDetailsByUserAsync_Works(IUserRepository userRepository var orgUser1 = await organizationUserRepository.CreateAsync(new OrganizationUser { + Id = CoreHelpers.GenerateComb(), OrganizationId = organization.Id, UserId = user1.Id, Status = OrganizationUserStatusType.Confirmed, + Type = OrganizationUserType.Owner, ResetPasswordKey = "resetpasswordkey1", + AccessSecretsManager = false }); var responseModel = await organizationUserRepository.GetManyDetailsByUserAsync(user1.Id); @@ -354,27 +363,35 @@ public async Task GetManyByOrganizationWithClaimedDomainsAsync_WithVerifiedDomai var orgUser1 = await organizationUserRepository.CreateAsync(new OrganizationUser { + Id = CoreHelpers.GenerateComb(), OrganizationId = organization.Id, UserId = user1.Id, Status = OrganizationUserStatusType.Confirmed, + Type = OrganizationUserType.Owner, ResetPasswordKey = "resetpasswordkey1", AccessSecretsManager = false }); await organizationUserRepository.CreateAsync(new OrganizationUser { + Id = CoreHelpers.GenerateComb(), OrganizationId = organization.Id, UserId = user2.Id, Status = OrganizationUserStatusType.Confirmed, + Type = OrganizationUserType.User, ResetPasswordKey = "resetpasswordkey1", + AccessSecretsManager = false }); await organizationUserRepository.CreateAsync(new OrganizationUser { + Id = CoreHelpers.GenerateComb(), OrganizationId = organization.Id, UserId = user3.Id, Status = OrganizationUserStatusType.Confirmed, + Type = OrganizationUserType.User, ResetPasswordKey = "resetpasswordkey1", + AccessSecretsManager = false }); var responseModel = await organizationUserRepository.GetManyByOrganizationWithClaimedDomainsAsync(organization.Id); @@ -621,4 +638,233 @@ public async Task CreateManyAsync_WithCollectionAndGroup_SaveSuccessfully( Assert.Equal(collection3.Id, orgUser3.Collections.First().Id); Assert.Equal(group3.Id, group3Database.First()); } + + [DatabaseTheory, DatabaseData] + public async Task GetManyDetailsByOrganizationAsync_vNext_WithoutGroupsAndCollections_ReturnsBasicUserDetails( + IUserRepository userRepository, + IOrganizationRepository organizationRepository, + IOrganizationUserRepository organizationUserRepository) + { + var id = Guid.NewGuid(); + + var user1 = await userRepository.CreateAsync(new User + { + Id = CoreHelpers.GenerateComb(), + Name = "Test User 1", + Email = $"test1+{id}@example.com", + ApiKey = "TEST", + SecurityStamp = "stamp", + Kdf = KdfType.PBKDF2_SHA256, + KdfIterations = 1, + KdfMemory = 2, + KdfParallelism = 3 + }); + + var user2 = await userRepository.CreateAsync(new User + { + Id = CoreHelpers.GenerateComb(), + Name = "Test User 2", + Email = $"test2+{id}@example.com", + ApiKey = "TEST", + SecurityStamp = "stamp", + Kdf = KdfType.Argon2id, + KdfIterations = 4, + KdfMemory = 5, + KdfParallelism = 6 + }); + + var organization = await organizationRepository.CreateAsync(new Organization + { + Id = CoreHelpers.GenerateComb(), + Name = $"Test Org {id}", + BillingEmail = user1.Email, + Plan = "Test", + PrivateKey = "privatekey", + PublicKey = "publickey", + UseGroups = true, + Enabled = true, + UsePasswordManager = true + }); + + var orgUser1 = await organizationUserRepository.CreateAsync(new OrganizationUser + { + Id = CoreHelpers.GenerateComb(), + OrganizationId = organization.Id, + UserId = user1.Id, + Status = OrganizationUserStatusType.Confirmed, + Type = OrganizationUserType.Owner, + ResetPasswordKey = "resetpasswordkey1", + AccessSecretsManager = false + }); + + var orgUser2 = await organizationUserRepository.CreateAsync(new OrganizationUser + { + Id = CoreHelpers.GenerateComb(), + OrganizationId = organization.Id, + UserId = user2.Id, + Status = OrganizationUserStatusType.Invited, + Type = OrganizationUserType.User, + ResetPasswordKey = "resetpasswordkey2", + AccessSecretsManager = true + }); + + var responseModel = await organizationUserRepository.GetManyDetailsByOrganizationAsync_vNext(organization.Id, includeGroups: false, includeCollections: false); + + Assert.NotNull(responseModel); + Assert.Equal(2, responseModel.Count); + + var user1Result = responseModel.FirstOrDefault(u => u.Id == orgUser1.Id); + Assert.NotNull(user1Result); + Assert.Equal(user1.Name, user1Result.Name); + Assert.Equal(user1.Email, user1Result.Email); + Assert.Equal(orgUser1.Status, user1Result.Status); + Assert.Equal(orgUser1.Type, user1Result.Type); + Assert.Equal(organization.Id, user1Result.OrganizationId); + Assert.Equal(user1.Id, user1Result.UserId); + Assert.Empty(user1Result.Groups); + Assert.Empty(user1Result.Collections); + + var user2Result = responseModel.FirstOrDefault(u => u.Id == orgUser2.Id); + Assert.NotNull(user2Result); + Assert.Equal(user2.Name, user2Result.Name); + Assert.Equal(user2.Email, user2Result.Email); + Assert.Equal(orgUser2.Status, user2Result.Status); + Assert.Equal(orgUser2.Type, user2Result.Type); + Assert.Equal(organization.Id, user2Result.OrganizationId); + Assert.Equal(user2.Id, user2Result.UserId); + Assert.Empty(user2Result.Groups); + Assert.Empty(user2Result.Collections); + } + + [DatabaseTheory, DatabaseData] + public async Task GetManyDetailsByOrganizationAsync_vNext_WithGroupsAndCollections_ReturnsUserDetailsWithBoth( + IUserRepository userRepository, + IOrganizationRepository organizationRepository, + IOrganizationUserRepository organizationUserRepository, + IGroupRepository groupRepository, + ICollectionRepository collectionRepository) + { + var id = Guid.NewGuid(); + var requestTime = DateTime.UtcNow; + + var user1 = await userRepository.CreateAsync(new User + { + Id = CoreHelpers.GenerateComb(), + Name = "Test User 1", + Email = $"test1+{id}@example.com", + ApiKey = "TEST", + SecurityStamp = "stamp", + Kdf = KdfType.PBKDF2_SHA256, + KdfIterations = 1, + KdfMemory = 2, + KdfParallelism = 3 + }); + + var organization = await organizationRepository.CreateAsync(new Organization + { + Id = CoreHelpers.GenerateComb(), + Name = $"Test Org {id}", + BillingEmail = user1.Email, + Plan = "Test", + PrivateKey = "privatekey", + PublicKey = "publickey", + UseGroups = true, + Enabled = true + }); + + var group1 = await groupRepository.CreateAsync(new Group + { + Id = CoreHelpers.GenerateComb(), + OrganizationId = organization.Id, + Name = "Test Group 1", + ExternalId = "external-group-1" + }); + + var group2 = await groupRepository.CreateAsync(new Group + { + Id = CoreHelpers.GenerateComb(), + OrganizationId = organization.Id, + Name = "Test Group 2", + ExternalId = "external-group-2" + }); + + var collection1 = await collectionRepository.CreateAsync(new Collection + { + Id = CoreHelpers.GenerateComb(), + OrganizationId = organization.Id, + Name = "Test Collection 1", + ExternalId = "external-collection-1", + CreationDate = requestTime, + RevisionDate = requestTime + }); + + var collection2 = await collectionRepository.CreateAsync(new Collection + { + Id = CoreHelpers.GenerateComb(), + OrganizationId = organization.Id, + Name = "Test Collection 2", + ExternalId = "external-collection-2", + CreationDate = requestTime, + RevisionDate = requestTime + }); + + // Create organization user with both groups and collections using CreateManyAsync + var createOrgUserWithCollections = new List + { + new() + { + OrganizationUser = new OrganizationUser + { + Id = CoreHelpers.GenerateComb(), + OrganizationId = organization.Id, + UserId = user1.Id, + Status = OrganizationUserStatusType.Confirmed, + Type = OrganizationUserType.Owner, + AccessSecretsManager = false + }, + Collections = + [ + new CollectionAccessSelection + { + Id = collection1.Id, + ReadOnly = true, + HidePasswords = false, + Manage = false + }, + new CollectionAccessSelection + { + Id = collection2.Id, + ReadOnly = false, + HidePasswords = true, + Manage = true + } + ], + Groups = [group1.Id, group2.Id] + } + }; + + await organizationUserRepository.CreateManyAsync(createOrgUserWithCollections); + + var responseModel = await organizationUserRepository.GetManyDetailsByOrganizationAsync_vNext(organization.Id, includeGroups: true, includeCollections: true); + + Assert.NotNull(responseModel); + Assert.Single(responseModel); + + var user1Result = responseModel.First(); + + Assert.Equal(user1.Name, user1Result.Name); + Assert.Equal(user1.Email, user1Result.Email); + Assert.Equal(organization.Id, user1Result.OrganizationId); + Assert.Equal(user1.Id, user1Result.UserId); + + Assert.NotNull(user1Result.Groups); + Assert.Equal(2, user1Result.Groups.Count()); + Assert.Contains(group1.Id, user1Result.Groups); + Assert.Contains(group2.Id, user1Result.Groups); + + Assert.NotNull(user1Result.Collections); + Assert.Equal(2, user1Result.Collections.Count()); + Assert.Contains(user1Result.Collections, c => c.Id == collection1.Id); + Assert.Contains(user1Result.Collections, c => c.Id == collection2.Id); + } } From 79b004175cc634b8454e19697c63d375dcf4ce25 Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Mon, 2 Jun 2025 15:25:48 +0100 Subject: [PATCH 09/25] Add integration tests for GetManyByOrganizationWithClaimedDomainsAsync_vNext to validate behavior with verified and unverified domains. --- .../OrganizationUserRepositoryTests.cs | 177 ++++++++++++++++++ 1 file changed, 177 insertions(+) diff --git a/test/Infrastructure.IntegrationTest/AdminConsole/Repositories/OrganizationUserRepository/OrganizationUserRepositoryTests.cs b/test/Infrastructure.IntegrationTest/AdminConsole/Repositories/OrganizationUserRepository/OrganizationUserRepositoryTests.cs index 0fa8e6e897e8..d4fb7a85d339 100644 --- a/test/Infrastructure.IntegrationTest/AdminConsole/Repositories/OrganizationUserRepository/OrganizationUserRepositoryTests.cs +++ b/test/Infrastructure.IntegrationTest/AdminConsole/Repositories/OrganizationUserRepository/OrganizationUserRepositoryTests.cs @@ -867,4 +867,181 @@ public async Task GetManyDetailsByOrganizationAsync_vNext_WithGroupsAndCollectio Assert.Contains(user1Result.Collections, c => c.Id == collection1.Id); Assert.Contains(user1Result.Collections, c => c.Id == collection2.Id); } + + [DatabaseTheory, DatabaseData] + public async Task GetManyByOrganizationWithClaimedDomainsAsync_vNext_WithVerifiedDomain_WithOneMatchingEmailDomain_ReturnsSingle( + IUserRepository userRepository, + IOrganizationRepository organizationRepository, + IOrganizationUserRepository organizationUserRepository, + IOrganizationDomainRepository organizationDomainRepository) + { + var id = Guid.NewGuid(); + var domainName = $"{id}.example.com"; + var requestTime = DateTime.UtcNow; + + var user1 = await userRepository.CreateAsync(new User + { + Id = CoreHelpers.GenerateComb(), + Name = "Test User 1", + Email = $"test+{id}@{domainName}", + ApiKey = "TEST", + SecurityStamp = "stamp", + CreationDate = requestTime, + RevisionDate = requestTime, + AccountRevisionDate = requestTime + }); + + var user2 = await userRepository.CreateAsync(new User + { + Id = CoreHelpers.GenerateComb(), + Name = "Test User 2", + Email = $"test+{id}@x-{domainName}", // Different domain + ApiKey = "TEST", + SecurityStamp = "stamp", + CreationDate = requestTime, + RevisionDate = requestTime, + AccountRevisionDate = requestTime + }); + + var user3 = await userRepository.CreateAsync(new User + { + Id = CoreHelpers.GenerateComb(), + Name = "Test User 3", + Email = $"test+{id}@{domainName}.example.com", // Different domain + ApiKey = "TEST", + SecurityStamp = "stamp", + CreationDate = requestTime, + RevisionDate = requestTime, + AccountRevisionDate = requestTime + }); + + var organization = await organizationRepository.CreateAsync(new Organization + { + Id = CoreHelpers.GenerateComb(), + Name = $"Test Org {id}", + BillingEmail = user1.Email, + Plan = "Test", + Enabled = true, + CreationDate = requestTime, + RevisionDate = requestTime + }); + + var organizationDomain = new OrganizationDomain + { + Id = CoreHelpers.GenerateComb(), + OrganizationId = organization.Id, + DomainName = domainName, + Txt = "btw+12345", + CreationDate = requestTime + }; + organizationDomain.SetNextRunDate(12); + organizationDomain.SetVerifiedDate(); + organizationDomain.SetJobRunCount(); + await organizationDomainRepository.CreateAsync(organizationDomain); + + var orgUser1 = await organizationUserRepository.CreateAsync(new OrganizationUser + { + Id = CoreHelpers.GenerateComb(), + OrganizationId = organization.Id, + UserId = user1.Id, + Status = OrganizationUserStatusType.Confirmed, + Type = OrganizationUserType.Owner, + CreationDate = requestTime, + RevisionDate = requestTime + }); + + await organizationUserRepository.CreateAsync(new OrganizationUser + { + Id = CoreHelpers.GenerateComb(), + OrganizationId = organization.Id, + UserId = user2.Id, + Status = OrganizationUserStatusType.Confirmed, + Type = OrganizationUserType.User, + CreationDate = requestTime, + RevisionDate = requestTime + }); + + await organizationUserRepository.CreateAsync(new OrganizationUser + { + Id = CoreHelpers.GenerateComb(), + OrganizationId = organization.Id, + UserId = user3.Id, + Status = OrganizationUserStatusType.Confirmed, + Type = OrganizationUserType.User, + CreationDate = requestTime, + RevisionDate = requestTime + }); + + var responseModel = await organizationUserRepository.GetManyByOrganizationWithClaimedDomainsAsync_vNext(organization.Id); + + Assert.NotNull(responseModel); + Assert.Single(responseModel); + Assert.Equal(orgUser1.Id, responseModel.Single().Id); + Assert.Equal(user1.Id, responseModel.Single().UserId); + Assert.Equal(organization.Id, responseModel.Single().OrganizationId); + } + + [DatabaseTheory, DatabaseData] + public async Task GetManyByOrganizationWithClaimedDomainsAsync_vNext_WithNoVerifiedDomain_ReturnsEmpty( + IUserRepository userRepository, + IOrganizationRepository organizationRepository, + IOrganizationUserRepository organizationUserRepository, + IOrganizationDomainRepository organizationDomainRepository) + { + var id = Guid.NewGuid(); + var domainName = $"{id}.example.com"; + var requestTime = DateTime.UtcNow; + + var user1 = await userRepository.CreateAsync(new User + { + Id = CoreHelpers.GenerateComb(), + Name = "Test User 1", + Email = $"test+{id}@{domainName}", + ApiKey = "TEST", + SecurityStamp = "stamp", + CreationDate = requestTime, + RevisionDate = requestTime, + AccountRevisionDate = requestTime + }); + + var organization = await organizationRepository.CreateAsync(new Organization + { + Id = CoreHelpers.GenerateComb(), + Name = $"Test Org {id}", + BillingEmail = user1.Email, + Plan = "Test", + Enabled = true, + CreationDate = requestTime, + RevisionDate = requestTime + }); + + // Create domain but do NOT verify it + var organizationDomain = new OrganizationDomain + { + Id = CoreHelpers.GenerateComb(), + OrganizationId = organization.Id, + DomainName = domainName, + Txt = "btw+12345", + CreationDate = requestTime + }; + organizationDomain.SetNextRunDate(12); + // Note: NOT calling SetVerifiedDate() + await organizationDomainRepository.CreateAsync(organizationDomain); + + await organizationUserRepository.CreateAsync(new OrganizationUser + { + Id = CoreHelpers.GenerateComb(), + OrganizationId = organization.Id, + UserId = user1.Id, + Status = OrganizationUserStatusType.Confirmed, + Type = OrganizationUserType.Owner, + CreationDate = requestTime, + RevisionDate = requestTime + }); + + var responseModel = await organizationUserRepository.GetManyByOrganizationWithClaimedDomainsAsync_vNext(organization.Id); + + Assert.NotNull(responseModel); + Assert.Empty(responseModel); + } } From c1534d1e6d58a53d2e39fd3273b9bb4549df3346 Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Mon, 9 Jun 2025 11:04:40 +0100 Subject: [PATCH 10/25] Optimize performance by conditionally setting permissions only for Custom user types in OrganizationUserUserDetailsQuery. --- .../OrganizationUserUserDetailsQuery.cs | 25 +++++++++++++------ 1 file changed, 18 insertions(+), 7 deletions(-) diff --git a/src/Core/AdminConsole/OrganizationFeatures/OrganizationUsers/OrganizationUserUserDetailsQuery.cs b/src/Core/AdminConsole/OrganizationFeatures/OrganizationUsers/OrganizationUserUserDetailsQuery.cs index 498ec2a94ad6..aa2cd2df8f61 100644 --- a/src/Core/AdminConsole/OrganizationFeatures/OrganizationUsers/OrganizationUserUserDetailsQuery.cs +++ b/src/Core/AdminConsole/OrganizationFeatures/OrganizationUsers/OrganizationUserUserDetailsQuery.cs @@ -44,9 +44,12 @@ public async Task> GetOrganizationUserU return organizationUsers .Select(o => { - var userPermissions = o.GetPermissions(); - - o.Permissions = CoreHelpers.ClassToJsonData(userPermissions); + // Only set permissions for Custom user types for performance optimization + if (o.Type == OrganizationUserType.Custom) + { + var userPermissions = o.GetPermissions(); + o.Permissions = CoreHelpers.ClassToJsonData(userPermissions); + } return o; }); @@ -113,8 +116,12 @@ public async Task> GetOrganizationUserU var organizationUsersClaimedStatus = claimedStatusTask.Result; var responses = organizationUsers.Select(organizationUserDetails => { - var organizationUserPermissions = organizationUserDetails.GetPermissions(); - organizationUserDetails.Permissions = CoreHelpers.ClassToJsonData(organizationUserPermissions); + // Only set permissions for Custom user types for performance optimization + if (organizationUserDetails.Type == OrganizationUserType.Custom) + { + var organizationUserPermissions = organizationUserDetails.GetPermissions(); + organizationUserDetails.Permissions = CoreHelpers.ClassToJsonData(organizationUserPermissions); + } var userHasTwoFactorEnabled = organizationUsersTwoFactorEnabled[organizationUserDetails.Id]; var userIsClaimedByOrganization = organizationUsersClaimedStatus[organizationUserDetails.Id]; @@ -141,8 +148,12 @@ public async Task> GetOrganizationUserU var organizationUsersClaimedStatus = claimedStatusTask.Result; var responses = organizationUsers.Select(organizationUserDetails => { - var organizationUserPermissions = organizationUserDetails.GetPermissions(); - organizationUserDetails.Permissions = CoreHelpers.ClassToJsonData(organizationUserPermissions); + // Only set permissions for Custom user types for performance optimization + if (organizationUserDetails.Type == OrganizationUserType.Custom) + { + var organizationUserPermissions = organizationUserDetails.GetPermissions(); + organizationUserDetails.Permissions = CoreHelpers.ClassToJsonData(organizationUserPermissions); + } var userHasTwoFactorEnabled = organizationUsersTwoFactorEnabled[organizationUserDetails.Id]; var userIsClaimedByOrganization = organizationUsersClaimedStatus[organizationUserDetails.Id]; From 72b41c83869ed5e22fd22ba4afb91d7055183e2d Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Tue, 17 Jun 2025 16:07:54 +0100 Subject: [PATCH 11/25] Create UserEmailDomainView to extract email domains from users' email addresses --- src/Sql/dbo/Views/UserEmailDomainView.sql | 14 ++++++++++++++ 1 file changed, 14 insertions(+) create mode 100644 src/Sql/dbo/Views/UserEmailDomainView.sql diff --git a/src/Sql/dbo/Views/UserEmailDomainView.sql b/src/Sql/dbo/Views/UserEmailDomainView.sql new file mode 100644 index 000000000000..1354419dbe72 --- /dev/null +++ b/src/Sql/dbo/Views/UserEmailDomainView.sql @@ -0,0 +1,14 @@ +CREATE VIEW [dbo].[UserEmailDomainView] +WITH SCHEMABINDING +AS +SELECT + Id, + Email, + SUBSTRING(Email, CHARINDEX('@', Email) + 1, LEN(Email)) AS EmailDomain +FROM dbo.[User] +WHERE Email IS NOT NULL + AND CHARINDEX('@', Email) > 0 +GO + +CREATE UNIQUE CLUSTERED INDEX IX_UserEmailDomainView_Id +ON dbo.UserEmailDomainView (Id); From 26c288be374100f89535a51af7ff38c1b0616e24 Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Tue, 17 Jun 2025 16:08:40 +0100 Subject: [PATCH 12/25] Create stored procedure Organization_ReadByClaimedUserEmailDomain_V2 that uses UserEmailDomainView to fetch Email domains --- ...anization_ReadByClaimedUserEmailDomain_V2.sql | 16 ++++++++++++++++ 1 file changed, 16 insertions(+) create mode 100644 src/Sql/dbo/Stored Procedures/Organization_ReadByClaimedUserEmailDomain_V2.sql diff --git a/src/Sql/dbo/Stored Procedures/Organization_ReadByClaimedUserEmailDomain_V2.sql b/src/Sql/dbo/Stored Procedures/Organization_ReadByClaimedUserEmailDomain_V2.sql new file mode 100644 index 000000000000..8d6fe3be2c25 --- /dev/null +++ b/src/Sql/dbo/Stored Procedures/Organization_ReadByClaimedUserEmailDomain_V2.sql @@ -0,0 +1,16 @@ +CREATE PROCEDURE [dbo].[Organization_ReadByClaimedUserEmailDomain_V2] + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON; + + SELECT O.* + FROM dbo.[UserEmailDomainView] 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.EmailDomain = OD.[DomainName] + AND O.[Enabled] = 1 +END \ No newline at end of file From 1e0c6850844e96c47615e3d16fb1cab8738ef6fa Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Tue, 17 Jun 2025 16:10:20 +0100 Subject: [PATCH 13/25] Add GetByVerifiedUserEmailDomainAsync_vNext method to IOrganizationRepository and its implementations --- .../Repositories/IOrganizationRepository.cs | 5 +++++ .../Repositories/OrganizationRepository.cs | 13 +++++++++++++ .../Repositories/OrganizationRepository.cs | 6 ++++++ 3 files changed, 24 insertions(+) diff --git a/src/Core/AdminConsole/Repositories/IOrganizationRepository.cs b/src/Core/AdminConsole/Repositories/IOrganizationRepository.cs index 7fff0d437ffb..0decf4158077 100644 --- a/src/Core/AdminConsole/Repositories/IOrganizationRepository.cs +++ b/src/Core/AdminConsole/Repositories/IOrganizationRepository.cs @@ -24,6 +24,11 @@ public interface IOrganizationRepository : IRepository /// Gets the organizations that have a verified domain matching the user's email domain. /// Task> GetByVerifiedUserEmailDomainAsync(Guid userId); + /// + /// + /// This method is optimized for performance. + /// + Task> GetByVerifiedUserEmailDomainAsync_vNext(Guid userId); Task> GetAddableToProviderByUserIdAsync(Guid userId, ProviderType providerType); Task> GetManyByIdsAsync(IEnumerable ids); diff --git a/src/Infrastructure.Dapper/AdminConsole/Repositories/OrganizationRepository.cs b/src/Infrastructure.Dapper/AdminConsole/Repositories/OrganizationRepository.cs index 27a08df3ed37..ff5bfc14c0a4 100644 --- a/src/Infrastructure.Dapper/AdminConsole/Repositories/OrganizationRepository.cs +++ b/src/Infrastructure.Dapper/AdminConsole/Repositories/OrganizationRepository.cs @@ -183,6 +183,19 @@ public async Task> GetByVerifiedUserEmailDomainAsync(G } } + public async Task> GetByVerifiedUserEmailDomainAsync_vNext(Guid userId) + { + using (var connection = new SqlConnection(ConnectionString)) + { + var result = await connection.QueryAsync( + "[dbo].[Organization_ReadByClaimedUserEmailDomain_V2]", + new { UserId = userId }, + commandType: CommandType.StoredProcedure); + + return result.ToList(); + } + } + public async Task> GetAddableToProviderByUserIdAsync( Guid userId, ProviderType providerType) diff --git a/src/Infrastructure.EntityFramework/AdminConsole/Repositories/OrganizationRepository.cs b/src/Infrastructure.EntityFramework/AdminConsole/Repositories/OrganizationRepository.cs index c378fe5e7e81..134e94564abf 100644 --- a/src/Infrastructure.EntityFramework/AdminConsole/Repositories/OrganizationRepository.cs +++ b/src/Infrastructure.EntityFramework/AdminConsole/Repositories/OrganizationRepository.cs @@ -324,6 +324,12 @@ join od in dbContext.OrganizationDomains on ou.OrganizationId equals od.Organiza return await query.ToArrayAsync(); } + public async Task> GetByVerifiedUserEmailDomainAsync_vNext(Guid userId) + { + // No EF optimization is required for this query + return await GetByVerifiedUserEmailDomainAsync(userId); + } + public async Task> GetAddableToProviderByUserIdAsync( Guid userId, ProviderType providerType) From 0f70876f6067306deff13bb80383c0d963625276 Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Tue, 17 Jun 2025 16:10:55 +0100 Subject: [PATCH 14/25] Refactor OrganizationUser_ReadByOrganizationIdWithClaimedDomains_V2 stored procedure to use UserEmailDomainView for email domain extraction, improving query efficiency and clarity. --- ...ReadByOrganizationIdWithClaimedDomains_V2.sql | 16 +++++----------- 1 file changed, 5 insertions(+), 11 deletions(-) diff --git a/src/Sql/dbo/Stored Procedures/OrganizationUser_ReadByOrganizationIdWithClaimedDomains_V2.sql b/src/Sql/dbo/Stored Procedures/OrganizationUser_ReadByOrganizationIdWithClaimedDomains_V2.sql index 0655eecdbdc5..83a0503ebe12 100644 --- a/src/Sql/dbo/Stored Procedures/OrganizationUser_ReadByOrganizationIdWithClaimedDomains_V2.sql +++ b/src/Sql/dbo/Stored Procedures/OrganizationUser_ReadByOrganizationIdWithClaimedDomains_V2.sql @@ -4,17 +4,11 @@ AS BEGIN SET NOCOUNT ON; - WITH CTE_UserWithDomain AS ( - SELECT - OU.*, - SUBSTRING(U.Email, CHARINDEX('@', U.Email) + 1, LEN(U.Email)) AS EmailDomain - FROM [dbo].[OrganizationUserView] OU - INNER JOIN [dbo].[UserView] U ON OU.[UserId] = U.[Id] - WHERE OU.[OrganizationId] = @OrganizationId - ) SELECT OU.* - FROM CTE_UserWithDomain OU + FROM [dbo].[OrganizationUserView] OU + INNER JOIN [dbo].[UserEmailDomainView] U ON OU.[UserId] = U.[Id] INNER JOIN [dbo].[OrganizationDomainView] OD ON OU.[OrganizationId] = OD.[OrganizationId] - WHERE OD.[VerifiedDate] IS NOT NULL - AND OU.EmailDomain = OD.[DomainName] + WHERE OU.[OrganizationId] = @OrganizationId + AND OD.[VerifiedDate] IS NOT NULL + AND U.EmailDomain = OD.[DomainName] END From 2485331cc044b7ccb367730e7ed406fb8eed9934 Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Tue, 17 Jun 2025 16:11:06 +0100 Subject: [PATCH 15/25] Enhance IOrganizationUserRepository with detailed documentation for GetManyDetailsByOrganizationAsync method, clarifying its purpose and performance optimizations. Added remarks for better understanding of its functionality. --- .../Repositories/IOrganizationUserRepository.cs | 14 +++++++++++--- 1 file changed, 11 insertions(+), 3 deletions(-) diff --git a/src/Core/AdminConsole/Repositories/IOrganizationUserRepository.cs b/src/Core/AdminConsole/Repositories/IOrganizationUserRepository.cs index e9c7948254b6..9915d6483c62 100644 --- a/src/Core/AdminConsole/Repositories/IOrganizationUserRepository.cs +++ b/src/Core/AdminConsole/Repositories/IOrganizationUserRepository.cs @@ -23,11 +23,19 @@ public interface IOrganizationUserRepository : IRepository>> GetByIdWithCollectionsAsync(Guid id); Task GetDetailsByIdAsync(Guid id); Task<(OrganizationUserUserDetails? OrganizationUser, ICollection Collections)> GetDetailsByIdWithCollectionsAsync(Guid id); - Task> GetManyDetailsByOrganizationAsync(Guid organizationId, bool includeGroups = false, bool includeCollections = false); /// - /// Optimized version of with better performance. - /// Reduces database round trips by fetching all data in fewer queries. + /// Fetches all OrganizationUsers for an organization, including their details. /// + /// The ID of the organization to fetch OrganizationUsers for. + /// Whether to include group details. + /// Whether to include collection details. + /// A collection of OrganizationUserUserDetails. + Task> GetManyDetailsByOrganizationAsync(Guid organizationId, bool includeGroups = false, bool includeCollections = false); + /// + /// + /// This method is optimized for performance. + /// Reduces database round trips by fetching all data in fewer queries. + /// Task> GetManyDetailsByOrganizationAsync_vNext(Guid organizationId, bool includeGroups = false, bool includeCollections = false); Task> GetManyDetailsByUserAsync(Guid userId, OrganizationUserStatusType? status = null); From d6c0e8d971886a6461f49b49fae47beef244255b Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Tue, 17 Jun 2025 16:16:44 +0100 Subject: [PATCH 16/25] Fix missing newline at the end of Organization_ReadByClaimedUserEmailDomain_V2.sql to adhere to coding standards. --- .../Organization_ReadByClaimedUserEmailDomain_V2.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/src/Sql/dbo/Stored Procedures/Organization_ReadByClaimedUserEmailDomain_V2.sql b/src/Sql/dbo/Stored Procedures/Organization_ReadByClaimedUserEmailDomain_V2.sql index 8d6fe3be2c25..eff877bc9211 100644 --- a/src/Sql/dbo/Stored Procedures/Organization_ReadByClaimedUserEmailDomain_V2.sql +++ b/src/Sql/dbo/Stored Procedures/Organization_ReadByClaimedUserEmailDomain_V2.sql @@ -13,4 +13,4 @@ BEGIN AND OD.[VerifiedDate] IS NOT NULL AND U.EmailDomain = OD.[DomainName] AND O.[Enabled] = 1 -END \ No newline at end of file +END From df9a198affc5fa7194f8b9d9bc3937025aac56c3 Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Tue, 17 Jun 2025 16:17:12 +0100 Subject: [PATCH 17/25] Update the database migration script to include UserEmailDomainView --- ...25-06-02_00_OrgUsersQueryOptimizations.sql | 50 +++++++++++++++---- 1 file changed, 39 insertions(+), 11 deletions(-) diff --git a/util/Migrator/DbScripts/2025-06-02_00_OrgUsersQueryOptimizations.sql b/util/Migrator/DbScripts/2025-06-02_00_OrgUsersQueryOptimizations.sql index 3aadff70da66..dd346688eacf 100644 --- a/util/Migrator/DbScripts/2025-06-02_00_OrgUsersQueryOptimizations.sql +++ b/util/Migrator/DbScripts/2025-06-02_00_OrgUsersQueryOptimizations.sql @@ -1,3 +1,19 @@ +CREATE OR ALTER VIEW [dbo].[UserEmailDomainView] +WITH SCHEMABINDING +AS +SELECT + Id, + Email, + SUBSTRING(Email, CHARINDEX('@', Email) + 1, LEN(Email)) AS EmailDomain +FROM dbo.[User] +WHERE Email IS NOT NULL + AND CHARINDEX('@', Email) > 0 +GO + +CREATE UNIQUE CLUSTERED INDEX IX_UserEmailDomainView_Id +ON dbo.UserEmailDomainView (Id); +GO + CREATE OR ALTER PROCEDURE [dbo].[OrganizationUserUserDetails_ReadByOrganizationId_V2] @OrganizationId UNIQUEIDENTIFIER, @IncludeGroups BIT = 0, @@ -37,18 +53,30 @@ AS BEGIN SET NOCOUNT ON; - WITH CTE_UserWithDomain AS ( - SELECT - OU.*, - SUBSTRING(U.Email, CHARINDEX('@', U.Email) + 1, LEN(U.Email)) AS EmailDomain - FROM [dbo].[OrganizationUserView] OU - INNER JOIN [dbo].[UserView] U ON OU.[UserId] = U.[Id] - WHERE OU.[OrganizationId] = @OrganizationId - ) SELECT OU.* - FROM CTE_UserWithDomain OU + FROM [dbo].[OrganizationUserView] OU + INNER JOIN [dbo].[UserEmailDomainView] U ON OU.[UserId] = U.[Id] INNER JOIN [dbo].[OrganizationDomainView] OD ON OU.[OrganizationId] = OD.[OrganizationId] - WHERE OD.[VerifiedDate] IS NOT NULL - AND OU.EmailDomain = OD.[DomainName] + WHERE OU.[OrganizationId] = @OrganizationId + AND OD.[VerifiedDate] IS NOT NULL + AND U.EmailDomain = OD.[DomainName] +END +GO + +CREATE OR ALTER PROCEDURE [dbo].[Organization_ReadByClaimedUserEmailDomain_V2] + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON; + + SELECT O.* + FROM dbo.[UserEmailDomainView] 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.EmailDomain = OD.[DomainName] + AND O.[Enabled] = 1 END GO From 9ecf75854e5107d4bd1ae62eac0a3430c65a2d84 Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Tue, 17 Jun 2025 16:17:54 +0100 Subject: [PATCH 18/25] Bumped the date on the migration script --- ...mizations.sql => 2025-06-17_00_OrgUsersQueryOptimizations.sql} | 0 1 file changed, 0 insertions(+), 0 deletions(-) rename util/Migrator/DbScripts/{2025-06-02_00_OrgUsersQueryOptimizations.sql => 2025-06-17_00_OrgUsersQueryOptimizations.sql} (100%) diff --git a/util/Migrator/DbScripts/2025-06-02_00_OrgUsersQueryOptimizations.sql b/util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql similarity index 100% rename from util/Migrator/DbScripts/2025-06-02_00_OrgUsersQueryOptimizations.sql rename to util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql From 27284679635f5731e9ed079a3e90a1554e68267c Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Tue, 17 Jun 2025 16:31:08 +0100 Subject: [PATCH 19/25] Remove GetByVerifiedUserEmailDomainAsync_vNext method and its stored procedure. --- .../Repositories/IOrganizationRepository.cs | 5 ----- .../Repositories/OrganizationRepository.cs | 13 ------------- .../Repositories/OrganizationRepository.cs | 6 ------ ...ization_ReadByClaimedUserEmailDomain_V2.sql | 16 ---------------- ...025-06-17_00_OrgUsersQueryOptimizations.sql | 18 ------------------ 5 files changed, 58 deletions(-) delete mode 100644 src/Sql/dbo/Stored Procedures/Organization_ReadByClaimedUserEmailDomain_V2.sql diff --git a/src/Core/AdminConsole/Repositories/IOrganizationRepository.cs b/src/Core/AdminConsole/Repositories/IOrganizationRepository.cs index 0decf4158077..7fff0d437ffb 100644 --- a/src/Core/AdminConsole/Repositories/IOrganizationRepository.cs +++ b/src/Core/AdminConsole/Repositories/IOrganizationRepository.cs @@ -24,11 +24,6 @@ public interface IOrganizationRepository : IRepository /// Gets the organizations that have a verified domain matching the user's email domain. /// Task> GetByVerifiedUserEmailDomainAsync(Guid userId); - /// - /// - /// This method is optimized for performance. - /// - Task> GetByVerifiedUserEmailDomainAsync_vNext(Guid userId); Task> GetAddableToProviderByUserIdAsync(Guid userId, ProviderType providerType); Task> GetManyByIdsAsync(IEnumerable ids); diff --git a/src/Infrastructure.Dapper/AdminConsole/Repositories/OrganizationRepository.cs b/src/Infrastructure.Dapper/AdminConsole/Repositories/OrganizationRepository.cs index ff5bfc14c0a4..27a08df3ed37 100644 --- a/src/Infrastructure.Dapper/AdminConsole/Repositories/OrganizationRepository.cs +++ b/src/Infrastructure.Dapper/AdminConsole/Repositories/OrganizationRepository.cs @@ -183,19 +183,6 @@ public async Task> GetByVerifiedUserEmailDomainAsync(G } } - public async Task> GetByVerifiedUserEmailDomainAsync_vNext(Guid userId) - { - using (var connection = new SqlConnection(ConnectionString)) - { - var result = await connection.QueryAsync( - "[dbo].[Organization_ReadByClaimedUserEmailDomain_V2]", - new { UserId = userId }, - commandType: CommandType.StoredProcedure); - - return result.ToList(); - } - } - public async Task> GetAddableToProviderByUserIdAsync( Guid userId, ProviderType providerType) diff --git a/src/Infrastructure.EntityFramework/AdminConsole/Repositories/OrganizationRepository.cs b/src/Infrastructure.EntityFramework/AdminConsole/Repositories/OrganizationRepository.cs index 134e94564abf..c378fe5e7e81 100644 --- a/src/Infrastructure.EntityFramework/AdminConsole/Repositories/OrganizationRepository.cs +++ b/src/Infrastructure.EntityFramework/AdminConsole/Repositories/OrganizationRepository.cs @@ -324,12 +324,6 @@ join od in dbContext.OrganizationDomains on ou.OrganizationId equals od.Organiza return await query.ToArrayAsync(); } - public async Task> GetByVerifiedUserEmailDomainAsync_vNext(Guid userId) - { - // No EF optimization is required for this query - return await GetByVerifiedUserEmailDomainAsync(userId); - } - public async Task> GetAddableToProviderByUserIdAsync( Guid userId, ProviderType providerType) diff --git a/src/Sql/dbo/Stored Procedures/Organization_ReadByClaimedUserEmailDomain_V2.sql b/src/Sql/dbo/Stored Procedures/Organization_ReadByClaimedUserEmailDomain_V2.sql deleted file mode 100644 index eff877bc9211..000000000000 --- a/src/Sql/dbo/Stored Procedures/Organization_ReadByClaimedUserEmailDomain_V2.sql +++ /dev/null @@ -1,16 +0,0 @@ -CREATE PROCEDURE [dbo].[Organization_ReadByClaimedUserEmailDomain_V2] - @UserId UNIQUEIDENTIFIER -AS -BEGIN - SET NOCOUNT ON; - - SELECT O.* - FROM dbo.[UserEmailDomainView] 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.EmailDomain = OD.[DomainName] - AND O.[Enabled] = 1 -END diff --git a/util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql b/util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql index dd346688eacf..bfd08ca5a5c6 100644 --- a/util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql +++ b/util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql @@ -62,21 +62,3 @@ BEGIN AND U.EmailDomain = OD.[DomainName] END GO - -CREATE OR ALTER PROCEDURE [dbo].[Organization_ReadByClaimedUserEmailDomain_V2] - @UserId UNIQUEIDENTIFIER -AS -BEGIN - SET NOCOUNT ON; - - SELECT O.* - FROM dbo.[UserEmailDomainView] 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.EmailDomain = OD.[DomainName] - AND O.[Enabled] = 1 -END -GO From cfa0cb14297719d646755547b31460686e358abf Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Thu, 19 Jun 2025 11:10:24 +0100 Subject: [PATCH 20/25] Refactor UserEmailDomainView index creation to check for existence before creation --- src/Sql/dbo/Views/UserEmailDomainView.sql | 4 ++-- .../DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql | 7 +++++-- 2 files changed, 7 insertions(+), 4 deletions(-) diff --git a/src/Sql/dbo/Views/UserEmailDomainView.sql b/src/Sql/dbo/Views/UserEmailDomainView.sql index 1354419dbe72..cd9f09142830 100644 --- a/src/Sql/dbo/Views/UserEmailDomainView.sql +++ b/src/Sql/dbo/Views/UserEmailDomainView.sql @@ -10,5 +10,5 @@ WHERE Email IS NOT NULL AND CHARINDEX('@', Email) > 0 GO -CREATE UNIQUE CLUSTERED INDEX IX_UserEmailDomainView_Id -ON dbo.UserEmailDomainView (Id); +CREATE UNIQUE CLUSTERED INDEX [IX_UserEmailDomainView_Id] + ON [dbo].[UserEmailDomainView] ([Id]); diff --git a/util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql b/util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql index bfd08ca5a5c6..8896bddbe882 100644 --- a/util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql +++ b/util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql @@ -10,8 +10,11 @@ WHERE Email IS NOT NULL AND CHARINDEX('@', Email) > 0 GO -CREATE UNIQUE CLUSTERED INDEX IX_UserEmailDomainView_Id -ON dbo.UserEmailDomainView (Id); +IF NOT EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_UserEmailDomainView_Id') +BEGIN + CREATE UNIQUE CLUSTERED INDEX [IX_UserEmailDomainView_Id] + ON [dbo].[UserEmailDomainView] ([Id]); +END GO CREATE OR ALTER PROCEDURE [dbo].[OrganizationUserUserDetails_ReadByOrganizationId_V2] From 38214b44d5be017bb49dd16af56b8095d605823c Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Mon, 7 Jul 2025 14:45:07 +0100 Subject: [PATCH 21/25] Update OrganizationUser_ReadByOrganizationIdWithClaimedDomains_V2 to use CTE and add indexes --- ...dByOrganizationIdWithClaimedDomains_V2.sql | 25 +++++++--- src/Sql/dbo/Tables/OrganizationDomain.sql | 7 ++- src/Sql/dbo/Tables/OrganizationUser.sql | 5 ++ src/Sql/dbo/Tables/User.sql | 4 ++ src/Sql/dbo/Views/UserEmailDomainView.sql | 1 - ...25-06-17_00_OrgUsersQueryOptimizations.sql | 49 ++++++++++++++++--- 6 files changed, 76 insertions(+), 15 deletions(-) diff --git a/src/Sql/dbo/Stored Procedures/OrganizationUser_ReadByOrganizationIdWithClaimedDomains_V2.sql b/src/Sql/dbo/Stored Procedures/OrganizationUser_ReadByOrganizationIdWithClaimedDomains_V2.sql index 83a0503ebe12..9d1e8da1f14b 100644 --- a/src/Sql/dbo/Stored Procedures/OrganizationUser_ReadByOrganizationIdWithClaimedDomains_V2.sql +++ b/src/Sql/dbo/Stored Procedures/OrganizationUser_ReadByOrganizationIdWithClaimedDomains_V2.sql @@ -4,11 +4,24 @@ AS BEGIN SET NOCOUNT ON; + WITH OrgUsers AS ( + SELECT * + FROM [dbo].[OrganizationUserView] + WHERE [OrganizationId] = @OrganizationId + ), + UserDomains AS ( + SELECT U.[Id], U.[EmailDomain] + FROM [dbo].[UserEmailDomainView] U + WHERE EXISTS ( + SELECT 1 + FROM [dbo].[OrganizationDomainView] OD WITH (INDEX(IX_OrganizationDomain_Org_VerifiedDomain)) + WHERE OD.[OrganizationId] = @OrganizationId + AND OD.[VerifiedDate] IS NOT NULL + AND OD.[DomainName] = U.[EmailDomain] + ) + ) SELECT OU.* - FROM [dbo].[OrganizationUserView] OU - INNER JOIN [dbo].[UserEmailDomainView] U ON OU.[UserId] = U.[Id] - INNER JOIN [dbo].[OrganizationDomainView] OD ON OU.[OrganizationId] = OD.[OrganizationId] - WHERE OU.[OrganizationId] = @OrganizationId - AND OD.[VerifiedDate] IS NOT NULL - AND U.EmailDomain = OD.[DomainName] + FROM OrgUsers OU + JOIN UserDomains UD ON OU.[UserId] = UD.[Id] + OPTION (RECOMPILE); END diff --git a/src/Sql/dbo/Tables/OrganizationDomain.sql b/src/Sql/dbo/Tables/OrganizationDomain.sql index 615dcc1557c4..bef4a92b1579 100644 --- a/src/Sql/dbo/Tables/OrganizationDomain.sql +++ b/src/Sql/dbo/Tables/OrganizationDomain.sql @@ -25,5 +25,10 @@ GO CREATE NONCLUSTERED INDEX [IX_OrganizationDomain_DomainNameVerifiedDateOrganizationId] ON [dbo].[OrganizationDomain] ([DomainName],[VerifiedDate]) - INCLUDE ([OrganizationId]) + INCLUDE ([OrganizationId]); +GO + +CREATE NONCLUSTERED INDEX [IX_OrganizationDomain_Org_VerifiedDomain] + ON [dbo].[OrganizationDomain] ([OrganizationId] ASC, [DomainName] ASC) + WHERE [VerifiedDate] IS NOT NULL; GO diff --git a/src/Sql/dbo/Tables/OrganizationUser.sql b/src/Sql/dbo/Tables/OrganizationUser.sql index 331e85fe6371..ca8e3a5b67fa 100644 --- a/src/Sql/dbo/Tables/OrganizationUser.sql +++ b/src/Sql/dbo/Tables/OrganizationUser.sql @@ -27,3 +27,8 @@ GO CREATE NONCLUSTERED INDEX [IX_OrganizationUser_OrganizationId] ON [dbo].[OrganizationUser]([OrganizationId] ASC); +GO +CREATE NONCLUSTERED INDEX [IX_OrganizationUser_OrgId_UserId_Includes] + ON [dbo].[OrganizationUser]([OrganizationId] ASC, [UserId] ASC) + INCLUDE ([Id], [Email], [Key], [Status], [Type], [ExternalId], [CreationDate], [RevisionDate], [Permissions], [ResetPasswordKey], [AccessSecretsManager]); + diff --git a/src/Sql/dbo/Tables/User.sql b/src/Sql/dbo/Tables/User.sql index 188dd4ea3c73..239ee67f1109 100644 --- a/src/Sql/dbo/Tables/User.sql +++ b/src/Sql/dbo/Tables/User.sql @@ -54,3 +54,7 @@ GO CREATE NONCLUSTERED INDEX [IX_User_Premium_PremiumExpirationDate_RenewalReminderDate] ON [dbo].[User]([Premium] ASC, [PremiumExpirationDate] ASC, [RenewalReminderDate] ASC); +GO +CREATE NONCLUSTERED INDEX [IX_User_Id_EmailDomain] + ON [dbo].[User]([Id] ASC, [Email] ASC); + diff --git a/src/Sql/dbo/Views/UserEmailDomainView.sql b/src/Sql/dbo/Views/UserEmailDomainView.sql index cd9f09142830..fa5407b69164 100644 --- a/src/Sql/dbo/Views/UserEmailDomainView.sql +++ b/src/Sql/dbo/Views/UserEmailDomainView.sql @@ -1,5 +1,4 @@ CREATE VIEW [dbo].[UserEmailDomainView] -WITH SCHEMABINDING AS SELECT Id, diff --git a/util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql b/util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql index 8896bddbe882..056cc09bd7ee 100644 --- a/util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql +++ b/util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql @@ -1,5 +1,4 @@ CREATE OR ALTER VIEW [dbo].[UserEmailDomainView] -WITH SCHEMABINDING AS SELECT Id, @@ -17,6 +16,29 @@ BEGIN END GO +IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = 'IX_OrganizationUser_OrgId_UserId_Includes') + BEGIN + CREATE NONCLUSTERED INDEX [IX_OrganizationUser_OrgId_UserId_Includes] + ON [dbo].[OrganizationUser] ([OrganizationId], [UserId]) + INCLUDE ([Id], [Email], [Key], [Status], [Type], [ExternalId], [CreationDate], [RevisionDate], [Permissions], [ResetPasswordKey], [AccessSecretsManager]) + END +GO + +IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = 'IX_User_Id_EmailDomain') + BEGIN + CREATE NONCLUSTERED INDEX [IX_User_Id_EmailDomain] + ON [dbo].[User] ([Id], [Email]) + END +GO + +IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = 'IX_OrganizationDomain_Org_VerifiedDomain') + BEGIN + CREATE NONCLUSTERED INDEX [IX_OrganizationDomain_Org_VerifiedDomain] + ON [dbo].[OrganizationDomain] ([OrganizationId], [DomainName]) + WHERE [VerifiedDate] IS NOT NULL + END +GO + CREATE OR ALTER PROCEDURE [dbo].[OrganizationUserUserDetails_ReadByOrganizationId_V2] @OrganizationId UNIQUEIDENTIFIER, @IncludeGroups BIT = 0, @@ -56,12 +78,25 @@ AS BEGIN SET NOCOUNT ON; + WITH OrgUsers AS ( + SELECT * + FROM [dbo].[OrganizationUserView] + WHERE [OrganizationId] = @OrganizationId + ), + UserDomains AS ( + SELECT U.[Id], U.[EmailDomain] + FROM [dbo].[UserEmailDomainView] U + WHERE EXISTS ( + SELECT 1 + FROM [dbo].[OrganizationDomainView] OD WITH (INDEX(IX_OrganizationDomain_Org_VerifiedDomain)) + WHERE OD.[OrganizationId] = @OrganizationId + AND OD.[VerifiedDate] IS NOT NULL + AND OD.[DomainName] = U.[EmailDomain] + ) + ) SELECT OU.* - FROM [dbo].[OrganizationUserView] OU - INNER JOIN [dbo].[UserEmailDomainView] U ON OU.[UserId] = U.[Id] - INNER JOIN [dbo].[OrganizationDomainView] OD ON OU.[OrganizationId] = OD.[OrganizationId] - WHERE OU.[OrganizationId] = @OrganizationId - AND OD.[VerifiedDate] IS NOT NULL - AND U.EmailDomain = OD.[DomainName] + FROM OrgUsers OU + JOIN UserDomains UD ON OU.[UserId] = UD.[Id] + OPTION (RECOMPILE); END GO From 0d34e8709b83a60b7616debc1f430945d050d666 Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Mon, 7 Jul 2025 15:09:55 +0100 Subject: [PATCH 22/25] Remove creation of unique clustered index from UserEmailDomainView and related migration script adjustments --- src/Sql/dbo/Views/UserEmailDomainView.sql | 3 --- .../DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql | 7 ------- 2 files changed, 10 deletions(-) diff --git a/src/Sql/dbo/Views/UserEmailDomainView.sql b/src/Sql/dbo/Views/UserEmailDomainView.sql index fa5407b69164..84930a41f1d3 100644 --- a/src/Sql/dbo/Views/UserEmailDomainView.sql +++ b/src/Sql/dbo/Views/UserEmailDomainView.sql @@ -8,6 +8,3 @@ FROM dbo.[User] WHERE Email IS NOT NULL AND CHARINDEX('@', Email) > 0 GO - -CREATE UNIQUE CLUSTERED INDEX [IX_UserEmailDomainView_Id] - ON [dbo].[UserEmailDomainView] ([Id]); diff --git a/util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql b/util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql index 056cc09bd7ee..b353bc9cf359 100644 --- a/util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql +++ b/util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql @@ -9,13 +9,6 @@ WHERE Email IS NOT NULL AND CHARINDEX('@', Email) > 0 GO -IF NOT EXISTS (SELECT * FROM sys.indexes WHERE name = 'IX_UserEmailDomainView_Id') -BEGIN - CREATE UNIQUE CLUSTERED INDEX [IX_UserEmailDomainView_Id] - ON [dbo].[UserEmailDomainView] ([Id]); -END -GO - IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = 'IX_OrganizationUser_OrgId_UserId_Includes') BEGIN CREATE NONCLUSTERED INDEX [IX_OrganizationUser_OrgId_UserId_Includes] From 046794ca8019d925a6674d0bf98b6db72a1dd2e5 Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Wed, 9 Jul 2025 13:18:36 +0100 Subject: [PATCH 23/25] Update indexes and sproc --- ..._ReadByOrganizationIdWithClaimedDomains_V2.sql | 2 +- src/Sql/dbo/Tables/OrganizationDomain.sql | 5 +++-- src/Sql/dbo/Tables/OrganizationUser.sql | 8 +++++--- .../2025-06-17_00_OrgUsersQueryOptimizations.sql | 15 +++++++++------ 4 files changed, 18 insertions(+), 12 deletions(-) diff --git a/src/Sql/dbo/Stored Procedures/OrganizationUser_ReadByOrganizationIdWithClaimedDomains_V2.sql b/src/Sql/dbo/Stored Procedures/OrganizationUser_ReadByOrganizationIdWithClaimedDomains_V2.sql index 9d1e8da1f14b..64f3d81e08f0 100644 --- a/src/Sql/dbo/Stored Procedures/OrganizationUser_ReadByOrganizationIdWithClaimedDomains_V2.sql +++ b/src/Sql/dbo/Stored Procedures/OrganizationUser_ReadByOrganizationIdWithClaimedDomains_V2.sql @@ -14,7 +14,7 @@ BEGIN FROM [dbo].[UserEmailDomainView] U WHERE EXISTS ( SELECT 1 - FROM [dbo].[OrganizationDomainView] OD WITH (INDEX(IX_OrganizationDomain_Org_VerifiedDomain)) + FROM [dbo].[OrganizationDomainView] OD WHERE OD.[OrganizationId] = @OrganizationId AND OD.[VerifiedDate] IS NOT NULL AND OD.[DomainName] = U.[EmailDomain] diff --git a/src/Sql/dbo/Tables/OrganizationDomain.sql b/src/Sql/dbo/Tables/OrganizationDomain.sql index bef4a92b1579..582029acfeca 100644 --- a/src/Sql/dbo/Tables/OrganizationDomain.sql +++ b/src/Sql/dbo/Tables/OrganizationDomain.sql @@ -28,7 +28,8 @@ CREATE NONCLUSTERED INDEX [IX_OrganizationDomain_DomainNameVerifiedDateOrganizat INCLUDE ([OrganizationId]); GO -CREATE NONCLUSTERED INDEX [IX_OrganizationDomain_Org_VerifiedDomain] - ON [dbo].[OrganizationDomain] ([OrganizationId] ASC, [DomainName] ASC) +CREATE NONCLUSTERED INDEX [IX_OrganizationDomain_OrganizationId_VerifiedDate] + ON [dbo].[OrganizationDomain] ([OrganizationId], [VerifiedDate]) + INCLUDE ([DomainName]) WHERE [VerifiedDate] IS NOT NULL; GO diff --git a/src/Sql/dbo/Tables/OrganizationUser.sql b/src/Sql/dbo/Tables/OrganizationUser.sql index ca8e3a5b67fa..513a5f66961e 100644 --- a/src/Sql/dbo/Tables/OrganizationUser.sql +++ b/src/Sql/dbo/Tables/OrganizationUser.sql @@ -28,7 +28,9 @@ CREATE NONCLUSTERED INDEX [IX_OrganizationUser_OrganizationId] ON [dbo].[OrganizationUser]([OrganizationId] ASC); GO -CREATE NONCLUSTERED INDEX [IX_OrganizationUser_OrgId_UserId_Includes] - ON [dbo].[OrganizationUser]([OrganizationId] ASC, [UserId] ASC) - INCLUDE ([Id], [Email], [Key], [Status], [Type], [ExternalId], [CreationDate], [RevisionDate], [Permissions], [ResetPasswordKey], [AccessSecretsManager]); +CREATE NONCLUSTERED INDEX [IX_OrganizationUser_OrganizationId_UserId] + ON [dbo].[OrganizationUser] ([OrganizationId], [UserId]) + INCLUDE ([Email], [Status], [Type], [ExternalId], [CreationDate], + [RevisionDate], [Permissions], [ResetPasswordKey], [AccessSecretsManager]); +GO diff --git a/util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql b/util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql index b353bc9cf359..6b358229a4fa 100644 --- a/util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql +++ b/util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql @@ -9,11 +9,13 @@ WHERE Email IS NOT NULL AND CHARINDEX('@', Email) > 0 GO -IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = 'IX_OrganizationUser_OrgId_UserId_Includes') +-- Index on OrganizationUser for efficient filtering +IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = 'IX_OrganizationUser_OrganizationId_UserId') BEGIN - CREATE NONCLUSTERED INDEX [IX_OrganizationUser_OrgId_UserId_Includes] + CREATE NONCLUSTERED INDEX [IX_OrganizationUser_OrganizationId_UserId] ON [dbo].[OrganizationUser] ([OrganizationId], [UserId]) - INCLUDE ([Id], [Email], [Key], [Status], [Type], [ExternalId], [CreationDate], [RevisionDate], [Permissions], [ResetPasswordKey], [AccessSecretsManager]) + INCLUDE ([Email], [Status], [Type], [ExternalId], [CreationDate], + [RevisionDate], [Permissions], [ResetPasswordKey], [AccessSecretsManager]) END GO @@ -26,8 +28,9 @@ GO IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = 'IX_OrganizationDomain_Org_VerifiedDomain') BEGIN - CREATE NONCLUSTERED INDEX [IX_OrganizationDomain_Org_VerifiedDomain] - ON [dbo].[OrganizationDomain] ([OrganizationId], [DomainName]) + CREATE NONCLUSTERED INDEX [IX_OrganizationDomain_OrganizationId_VerifiedDate] + ON [dbo].[OrganizationDomain] ([OrganizationId], [VerifiedDate]) + INCLUDE ([DomainName]) WHERE [VerifiedDate] IS NOT NULL END GO @@ -81,7 +84,7 @@ BEGIN FROM [dbo].[UserEmailDomainView] U WHERE EXISTS ( SELECT 1 - FROM [dbo].[OrganizationDomainView] OD WITH (INDEX(IX_OrganizationDomain_Org_VerifiedDomain)) + FROM [dbo].[OrganizationDomainView] OD WHERE OD.[OrganizationId] = @OrganizationId AND OD.[VerifiedDate] IS NOT NULL AND OD.[DomainName] = U.[EmailDomain] From 8f8d3f22f4b73a2cd4d9b030a938ff30584d9c3d Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Tue, 22 Jul 2025 11:02:14 +0100 Subject: [PATCH 24/25] Fix index name when checking if it already exists --- .../2025-06-17_00_OrgUsersQueryOptimizations.sql | 16 ++++++++-------- 1 file changed, 8 insertions(+), 8 deletions(-) diff --git a/util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql b/util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql index 6b358229a4fa..7a1ba682769c 100644 --- a/util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql +++ b/util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql @@ -1,11 +1,11 @@ CREATE OR ALTER VIEW [dbo].[UserEmailDomainView] AS -SELECT +SELECT Id, Email, SUBSTRING(Email, CHARINDEX('@', Email) + 1, LEN(Email)) AS EmailDomain FROM dbo.[User] -WHERE Email IS NOT NULL +WHERE Email IS NOT NULL AND CHARINDEX('@', Email) > 0 GO @@ -14,7 +14,7 @@ IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = 'IX_OrganizationUser_Org BEGIN 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]) END GO @@ -26,7 +26,7 @@ IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = 'IX_User_Id_EmailDomain' END GO -IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = 'IX_OrganizationDomain_Org_VerifiedDomain') +IF NOT EXISTS(SELECT name FROM sys.indexes WHERE name = 'IX_OrganizationDomain_OrganizationId_VerifiedDate') BEGIN CREATE NONCLUSTERED INDEX [IX_OrganizationDomain_OrganizationId_VerifiedDate] ON [dbo].[OrganizationDomain] ([OrganizationId], [VerifiedDate]) @@ -44,8 +44,8 @@ BEGIN SET NOCOUNT ON -- Result Set 1: User Details (always returned) - SELECT * - FROM [dbo].[OrganizationUserUserDetailsView] + SELECT * + FROM [dbo].[OrganizationUserUserDetailsView] WHERE OrganizationId = @OrganizationId -- Result Set 2: Group associations (if requested) @@ -57,7 +57,7 @@ BEGIN WHERE ou.OrganizationId = @OrganizationId END - -- Result Set 3: Collection associations (if requested) + -- Result Set 3: Collection associations (if requested) IF @IncludeCollections = 1 BEGIN SELECT cu.* @@ -84,7 +84,7 @@ BEGIN FROM [dbo].[UserEmailDomainView] U WHERE EXISTS ( SELECT 1 - FROM [dbo].[OrganizationDomainView] OD + FROM [dbo].[OrganizationDomainView] OD WHERE OD.[OrganizationId] = @OrganizationId AND OD.[VerifiedDate] IS NOT NULL AND OD.[DomainName] = U.[EmailDomain] From 234c1b6186ee04bd7e786b571532bdc3a44a992f Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Tue, 22 Jul 2025 11:02:51 +0100 Subject: [PATCH 25/25] Bump up date on migration script --- ...mizations.sql => 2025-07-22_00_OrgUsersQueryOptimizations.sql} | 0 1 file changed, 0 insertions(+), 0 deletions(-) rename util/Migrator/DbScripts/{2025-06-17_00_OrgUsersQueryOptimizations.sql => 2025-07-22_00_OrgUsersQueryOptimizations.sql} (100%) diff --git a/util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql b/util/Migrator/DbScripts/2025-07-22_00_OrgUsersQueryOptimizations.sql similarity index 100% rename from util/Migrator/DbScripts/2025-06-17_00_OrgUsersQueryOptimizations.sql rename to util/Migrator/DbScripts/2025-07-22_00_OrgUsersQueryOptimizations.sql