Skip to content

Commit 72bb06a

Browse files
Auth/PM-16947 - Device Management - Adjust Device + pending auth request get query (#5250)
* Added userId check on query * Added required field to inner select * PM-16947 - Update to filter inner subquery on user id per discussion with Robert * Updated to use new query with ROW_NUMBER * More query optimizations to eliminate returning old requests for a device * Fixed approval condition to be NULL as 0 means denied. * Added negation of @ExpirationMinutes --------- Co-authored-by: Todd Martin <tmartin@bitwarden.com>
1 parent aa0b35a commit 72bb06a

File tree

2 files changed

+43
-11
lines changed

2 files changed

+43
-11
lines changed

src/Sql/Auth/dbo/Stored Procedures/Device_ReadActiveWithPendingAuthRequestsByUserId.sql

Lines changed: 14 additions & 11 deletions
Original file line numberDiff line numberDiff line change
@@ -10,18 +10,21 @@ BEGIN
1010
AR.Id as AuthRequestId,
1111
AR.CreationDate as AuthRequestCreationDate
1212
FROM dbo.DeviceView D
13-
LEFT JOIN (
14-
SELECT TOP 1 -- Take only the top record sorted by auth request creation date
15-
Id,
16-
CreationDate,
17-
RequestDeviceIdentifier
13+
LEFT JOIN (
14+
SELECT
15+
Id,
16+
CreationDate,
17+
RequestDeviceIdentifier,
18+
Approved,
19+
ROW_NUMBER() OVER (PARTITION BY RequestDeviceIdentifier ORDER BY CreationDate DESC) as rn
1820
FROM dbo.AuthRequestView
19-
WHERE Type IN (0, 1) -- Include only AuthenticateAndUnlock and Unlock types, excluding Admin Approval (type 2)
20-
AND CreationDate >= DATEADD(MINUTE, -@ExpirationMinutes, GETUTCDATE()) -- Ensure the request hasn't expired
21-
AND Approved IS NULL -- Include only requests that haven't been acknowledged or approved
22-
ORDER BY CreationDate DESC
23-
) AR ON D.Identifier = AR.RequestDeviceIdentifier
21+
WHERE Type IN (0, 1) -- AuthenticateAndUnlock and Unlock types only
22+
AND CreationDate >= DATEADD(MINUTE, -@ExpirationMinutes, GETUTCDATE()) -- Ensure the request hasn't expired
23+
AND UserId = @UserId -- Requests for this user only
24+
) AR -- This join will get the most recent request per device, regardless of approval status
25+
ON D.Identifier = AR.RequestDeviceIdentifier AND AR.rn = 1 AND AR.Approved IS NULL -- Get only the most recent unapproved request per device
2426
WHERE
25-
D.UserId = @UserId
27+
D.UserId = @UserId -- Include only devices for this user
2628
AND D.Active = 1; -- Include only active devices
2729
END;
30+
Lines changed: 29 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,29 @@
1+
CREATE OR ALTER PROCEDURE [dbo].[Device_ReadActiveWithPendingAuthRequestsByUserId]
2+
@UserId UNIQUEIDENTIFIER,
3+
@ExpirationMinutes INT
4+
AS
5+
BEGIN
6+
SET NOCOUNT ON;
7+
8+
SELECT
9+
D.*,
10+
AR.Id as AuthRequestId,
11+
AR.CreationDate as AuthRequestCreationDate
12+
FROM dbo.DeviceView D
13+
LEFT JOIN (
14+
SELECT
15+
Id,
16+
CreationDate,
17+
RequestDeviceIdentifier,
18+
Approved,
19+
ROW_NUMBER() OVER (PARTITION BY RequestDeviceIdentifier ORDER BY CreationDate DESC) as rn
20+
FROM dbo.AuthRequestView
21+
WHERE Type IN (0, 1) -- AuthenticateAndUnlock and Unlock types only
22+
AND CreationDate >= DATEADD(MINUTE, -@ExpirationMinutes, GETUTCDATE()) -- Ensure the request hasn't expired
23+
AND UserId = @UserId -- Requests for this user only
24+
) AR -- This join will get the most recent request per device, regardless of approval status
25+
ON D.Identifier = AR.RequestDeviceIdentifier AND AR.rn = 1 AND AR.Approved IS NULL -- Get only the most recent unapproved request per device
26+
WHERE
27+
D.UserId = @UserId -- Include only devices for this user
28+
AND D.Active = 1; -- Include only active devices
29+
END;

0 commit comments

Comments
 (0)