1
0
mirror of https://github.com/bitwarden/server.git synced 2025-06-30 15:42:48 -05:00

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.

This commit is contained in:
Ike Kottlowski
2025-06-27 14:43:03 -04:00
parent 52df8f6583
commit 144787ec23
2 changed files with 53 additions and 80 deletions

View File

@ -1,46 +1,13 @@
CREATE PROCEDURE [dbo].[AuthRequest_ReadPendingByUserId]
CREATE OR ALTER PROCEDURE [dbo].[AuthRequest_ReadPendingByUserId]
@UserId UNIQUEIDENTIFIER, @UserId UNIQUEIDENTIFIER,
@ExpirationMinutes INT @ExpirationMinutes INT
AS AS
BEGIN BEGIN
SET NOCOUNT ON; SET NOCOUNT ON
; SELECT *
WITH FROM [dbo].[AuthRequestPendingDetailsView]
PendingRequests WHERE [UserId] = @UserId
AS AND [CreationDate] >= DATEADD(MINUTE, -@ExpirationMinutes, GETUTCDATE())
( END
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;

View File

@ -1,47 +1,53 @@
-- Adds a stored procedure to read pending authentication requests by user ID. CREATE OR ALTER VIEW [dbo].[AuthRequestPendingDetailsView]
CREATE OR ALTER PROCEDURE [dbo].[AuthRequest_ReadPendingByUserId]
@UserId UNIQUEIDENTIFIER,
@ExpirationMinutes INT
AS AS
BEGIN
SET NOCOUNT ON;
;
WITH WITH
PendingRequests PendingRequests
AS AS
( (
SELECT SELECT
AR.*, [AR].*,
D.Id AS DeviceId, [D].[Id] AS [DeviceId],
ROW_NUMBER() OVER (PARTITION BY AR.RequestDeviceIdentifier ORDER BY AR.CreationDate DESC) AS rn ROW_NUMBER() OVER (PARTITION BY [AR].[RequestDeviceIdentifier] ORDER BY [AR].[CreationDate] DESC) AS [rn]
FROM dbo.AuthRequestView AR FROM [dbo].[AuthRequest] [AR]
LEFT JOIN Device D ON AR.RequestDeviceIdentifier = D.Identifier LEFT JOIN [dbo].[Device] [D]
AND D.UserId = AR.UserId ON [AR].[RequestDeviceIdentifier] = [D].[Identifier]
WHERE AR.Type IN (0, 1) -- 0 = AuthenticateAndUnlock, 1 = Unlock AND [D].[UserId] = [AR].[UserId]
AND AR.CreationDate >= DATEADD(MINUTE, -@ExpirationMinutes, GETUTCDATE()) WHERE [AR].[Type] IN (0, 1) -- 0 = AuthenticateAndUnlock, 1 = Unlock
AND AR.UserId = @UserId
) )
SELECT SELECT
PR.Id, [PR].[Id],
PR.UserId, [PR].[UserId],
PR.OrganizationId, [PR].[OrganizationId],
PR.Type, [PR].[Type],
PR.RequestDeviceIdentifier, [PR].[RequestDeviceIdentifier],
PR.RequestDeviceType, [PR].[RequestDeviceType],
PR.RequestIpAddress, [PR].[RequestIpAddress],
PR.RequestCountryName, [PR].[RequestCountryName],
PR.ResponseDeviceId, [PR].[ResponseDeviceId],
PR.AccessCode, [PR].[AccessCode],
PR.PublicKey, [PR].[PublicKey],
PR.[Key], [PR].[Key],
PR.MasterPasswordHash, [PR].[MasterPasswordHash],
PR.Approved, [PR].[Approved],
PR.CreationDate, [PR].[CreationDate],
PR.ResponseDate, [PR].[ResponseDate],
PR.AuthenticationDate, [PR].[AuthenticationDate],
PR.DeviceId [PR].[DeviceId]
FROM PendingRequests PR FROM [PendingRequests] [PR]
WHERE rn = 1 WHERE [PR].[rn] = 1
AND PR.Approved IS NULL; AND [PR].[Approved] IS NULL -- since we only want pending requests we only want the most recent that is also approved = null
END; 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