Files
server/util/Migrator/DbScripts/2025-10-15_00_RefactorPolicyDetailsQueries.sql

Ignoring revisions in .git-blame-ignore-revs. Click here to bypass and see the normal blame view.

86 lines
2.1 KiB
MySQL
Raw Normal View History

[PM-23134] Update PolicyDetails sprocs for performance (#6421) * Add integration tests for GetByUserIdWithPolicyDetailsAsync in OrganizationUserRepository - Implemented multiple test cases to verify the behavior of GetByUserIdWithPolicyDetailsAsync for different user statuses (Confirmed, Accepted, Invited, Revoked). - Ensured that the method returns correct policy details based on user status and organization. - Added tests for scenarios with multiple organizations and non-existing policy types. - Included checks for provider users and custom user permissions. These tests enhance coverage and ensure the correctness of policy retrieval logic. * Add UserProviderAccessView to identify which organizations a user can access as a provider * Refactor PolicyDetails_ReadByUserId stored procedure to improve user access logic - Introduced a Common Table Expression (CTE) for organization users to streamline the selection process based on user status and email. - Added a CTE for providers to enhance clarity and maintainability. - Updated the main query to utilize the new CTEs, improving readability and performance. - Ensured that the procedure correctly identifies provider access based on user permissions. * Refactor OrganizationUser_ReadByUserIdWithPolicyDetails stored procedure to enhance user access logic - Introduced a Common Table Expression (CTE) for organization users to improve selection based on user status and email. - Updated the main query to utilize the new CTEs, enhancing readability and performance. - Adjusted the logic for identifying provider access to ensure accurate policy retrieval based on user permissions. * Add new SQL migration script to refactor policy details queries - Created a new view, UserProviderAccessView, to streamline user access to provider organizations. - Introduced two stored procedures: PolicyDetails_ReadByUserId and OrganizationUser_ReadByUserIdWithPolicyDetails, enhancing the logic for retrieving policy details based on user ID and policy type. - Utilized Common Table Expressions (CTEs) to improve query readability and performance, ensuring accurate policy retrieval based on user permissions and organization status. * Remove GetPolicyDetailsByUserIdTests * Refactor PolicyRequirementQuery to use GetPolicyDetailsByUserIdsAndPolicyType and update unit tests * Remove GetPolicyDetailsByUserId method from IPolicyRepository and its implementations in PolicyRepository classes * Revert changes to PolicyDetails_ReadByUserId stored procedure * Refactor OrganizationUser_ReadByUserIdWithPolicyDetails stored procedure to use UNION instead of OR * Reduce UserEmail variable size from NVARCHAR(320) to NVARCHAR(256) for consistency in stored procedures * Bump date on migration script
2025-10-22 13:20:53 +01:00
CREATE OR ALTER VIEW [dbo].[UserProviderAccessView]
AS
SELECT DISTINCT
PU.[UserId],
PO.[OrganizationId]
FROM
[dbo].[ProviderUserView] PU
INNER JOIN
[dbo].[ProviderOrganizationView] PO ON PO.[ProviderId] = PU.[ProviderId]
GO
CREATE OR ALTER PROCEDURE [dbo].[OrganizationUser_ReadByUserIdWithPolicyDetails]
@UserId UNIQUEIDENTIFIER,
@PolicyType TINYINT
AS
BEGIN
SET NOCOUNT ON
DECLARE @UserEmail NVARCHAR(256)
SELECT @UserEmail = Email
FROM
[dbo].[UserView]
WHERE
Id = @UserId
;WITH OrgUsers AS
(
-- All users except invited (Status <> 0): direct UserId match
SELECT
OU.[Id],
OU.[OrganizationId],
OU.[Type],
OU.[Status],
OU.[Permissions]
FROM
[dbo].[OrganizationUserView] OU
WHERE
OU.[Status] <> 0
AND OU.[UserId] = @UserId
UNION ALL
-- Invited users: email match
SELECT
OU.[Id],
OU.[OrganizationId],
OU.[Type],
OU.[Status],
OU.[Permissions]
FROM
[dbo].[OrganizationUserView] OU
WHERE
OU.[Status] = 0
AND OU.[Email] = @UserEmail
AND @UserEmail IS NOT NULL
),
Providers AS
(
SELECT
OrganizationId
FROM
[dbo].[UserProviderAccessView]
WHERE
UserId = @UserId
)
SELECT
OU.[Id] AS [OrganizationUserId],
P.[OrganizationId],
P.[Type] AS [PolicyType],
P.[Enabled] AS [PolicyEnabled],
P.[Data] AS [PolicyData],
OU.[Type] AS [OrganizationUserType],
OU.[Status] AS [OrganizationUserStatus],
OU.[Permissions] AS [OrganizationUserPermissionsData],
CASE WHEN PR.[OrganizationId] IS NULL THEN 0 ELSE 1 END AS [IsProvider]
FROM
[dbo].[PolicyView] P
INNER JOIN
OrgUsers OU ON P.[OrganizationId] = OU.[OrganizationId]
LEFT JOIN
Providers PR ON PR.[OrganizationId] = OU.[OrganizationId]
WHERE
P.[Type] = @PolicyType
END
GO