From 144787ec2384fac2a67b5f4ad1fd7735186a2f2b Mon Sep 17 00:00:00 2001 From: Ike Kottlowski Date: Fri, 27 Jun 2025 14:43:03 -0400 Subject: [PATCH] feat: change stored procedure to create a view that stores the previous query so it can be accessed through a more simple parameterized stored procedure. --- .../AuthRequest_ReadPendingByUserId.sql | 49 ++--------- ...-00_AddReadPendingAuthRequestsByUserId.sql | 84 ++++++++++--------- 2 files changed, 53 insertions(+), 80 deletions(-) diff --git a/src/Sql/dbo/Auth/Stored Procedures/AuthRequest_ReadPendingByUserId.sql b/src/Sql/dbo/Auth/Stored Procedures/AuthRequest_ReadPendingByUserId.sql index 2d2d00ff8d..c686154815 100644 --- a/src/Sql/dbo/Auth/Stored Procedures/AuthRequest_ReadPendingByUserId.sql +++ b/src/Sql/dbo/Auth/Stored Procedures/AuthRequest_ReadPendingByUserId.sql @@ -1,46 +1,13 @@ -CREATE PROCEDURE [dbo].[AuthRequest_ReadPendingByUserId] + +CREATE OR ALTER PROCEDURE [dbo].[AuthRequest_ReadPendingByUserId] @UserId UNIQUEIDENTIFIER, @ExpirationMinutes INT AS BEGIN - SET NOCOUNT ON; + SET NOCOUNT ON - ; - WITH - PendingRequests - AS - ( - SELECT - AR.*, - D.Id AS DeviceId, - ROW_NUMBER() OVER (PARTITION BY AR.RequestDeviceIdentifier ORDER BY AR.CreationDate DESC) AS rn - FROM dbo.AuthRequestView AR - LEFT JOIN Device D ON AR.RequestDeviceIdentifier = D.Identifier - AND D.UserId = AR.UserId - WHERE AR.Type IN (0, 1) -- 0 = AuthenticateAndUnlock, 1 = Unlock - AND AR.CreationDate >= DATEADD(MINUTE, -@ExpirationMinutes, GETUTCDATE()) - AND AR.UserId = @UserId - ) - SELECT - PR.Id, - PR.UserId, - PR.OrganizationId, - PR.Type, - PR.RequestDeviceIdentifier, - PR.RequestDeviceType, - PR.RequestIpAddress, - PR.RequestCountryName, - PR.ResponseDeviceId, - PR.AccessCode, - PR.PublicKey, - PR.[Key], - PR.MasterPasswordHash, - PR.Approved, - PR.CreationDate, - PR.ResponseDate, - PR.AuthenticationDate, - PR.DeviceId - FROM PendingRequests PR - WHERE rn = 1 - AND PR.Approved IS NULL; -END; + SELECT * + FROM [dbo].[AuthRequestPendingDetailsView] + WHERE [UserId] = @UserId + AND [CreationDate] >= DATEADD(MINUTE, -@ExpirationMinutes, GETUTCDATE()) +END \ No newline at end of file diff --git a/util/Migrator/DbScripts/2025-06-04-00_AddReadPendingAuthRequestsByUserId.sql b/util/Migrator/DbScripts/2025-06-04-00_AddReadPendingAuthRequestsByUserId.sql index 4510c2a7dc..9151247426 100644 --- a/util/Migrator/DbScripts/2025-06-04-00_AddReadPendingAuthRequestsByUserId.sql +++ b/util/Migrator/DbScripts/2025-06-04-00_AddReadPendingAuthRequestsByUserId.sql @@ -1,47 +1,53 @@ --- Adds a stored procedure to read pending authentication requests by user ID. -CREATE OR ALTER PROCEDURE [dbo].[AuthRequest_ReadPendingByUserId] - @UserId UNIQUEIDENTIFIER, - @ExpirationMinutes INT +CREATE OR ALTER VIEW [dbo].[AuthRequestPendingDetailsView] AS -BEGIN - SET NOCOUNT ON; - - ; WITH PendingRequests AS ( SELECT - AR.*, - D.Id AS DeviceId, - ROW_NUMBER() OVER (PARTITION BY AR.RequestDeviceIdentifier ORDER BY AR.CreationDate DESC) AS rn - FROM dbo.AuthRequestView AR - LEFT JOIN Device D ON AR.RequestDeviceIdentifier = D.Identifier - AND D.UserId = AR.UserId - WHERE AR.Type IN (0, 1) -- 0 = AuthenticateAndUnlock, 1 = Unlock - AND AR.CreationDate >= DATEADD(MINUTE, -@ExpirationMinutes, GETUTCDATE()) - AND AR.UserId = @UserId + [AR].*, + [D].[Id] AS [DeviceId], + ROW_NUMBER() OVER (PARTITION BY [AR].[RequestDeviceIdentifier] ORDER BY [AR].[CreationDate] DESC) AS [rn] + FROM [dbo].[AuthRequest] [AR] + LEFT JOIN [dbo].[Device] [D] + ON [AR].[RequestDeviceIdentifier] = [D].[Identifier] + AND [D].[UserId] = [AR].[UserId] + WHERE [AR].[Type] IN (0, 1) -- 0 = AuthenticateAndUnlock, 1 = Unlock ) SELECT - PR.Id, - PR.UserId, - PR.OrganizationId, - PR.Type, - PR.RequestDeviceIdentifier, - PR.RequestDeviceType, - PR.RequestIpAddress, - PR.RequestCountryName, - PR.ResponseDeviceId, - PR.AccessCode, - PR.PublicKey, - PR.[Key], - PR.MasterPasswordHash, - PR.Approved, - PR.CreationDate, - PR.ResponseDate, - PR.AuthenticationDate, - PR.DeviceId - FROM PendingRequests PR - WHERE rn = 1 - AND PR.Approved IS NULL; -END; + [PR].[Id], + [PR].[UserId], + [PR].[OrganizationId], + [PR].[Type], + [PR].[RequestDeviceIdentifier], + [PR].[RequestDeviceType], + [PR].[RequestIpAddress], + [PR].[RequestCountryName], + [PR].[ResponseDeviceId], + [PR].[AccessCode], + [PR].[PublicKey], + [PR].[Key], + [PR].[MasterPasswordHash], + [PR].[Approved], + [PR].[CreationDate], + [PR].[ResponseDate], + [PR].[AuthenticationDate], + [PR].[DeviceId] + FROM [PendingRequests] [PR] + WHERE [PR].[rn] = 1 + AND [PR].[Approved] IS NULL -- since we only want pending requests we only want the most recent that is also approved = null + GO + +CREATE OR ALTER PROCEDURE [dbo].[AuthRequest_ReadPendingByUserId] + @UserId UNIQUEIDENTIFIER, + @ExpirationMinutes INT +AS +BEGIN + SET NOCOUNT ON + + SELECT * + FROM [dbo].[AuthRequestPendingDetailsView] + WHERE [UserId] = @UserId + AND [CreationDate] >= DATEADD(MINUTE, -@ExpirationMinutes, GETUTCDATE()) +END + GO \ No newline at end of file