Skip to content

Commit 425d069

Browse files
TD-6520 : Refractored the SP to fix DTU Spike
1 parent 0ccba55 commit 425d069

File tree

1 file changed

+26
-14
lines changed

1 file changed

+26
-14
lines changed

WebAPI/LearningHub.Nhs.Database/Stored Procedures/Hierarchy/GetNodePathNodes.sql

Lines changed: 26 additions & 14 deletions
Original file line numberDiff line numberDiff line change
@@ -11,25 +11,37 @@
1111
-- 22-06-2023 RS Switched order of joins to ensure catalogue node is always returned first.
1212
-- 24-08-2023 RS Proper fix for ordering issue - STRING_SPLIT doesn't return substrings in order.
1313
-- 08-09-2023 RS A further fix for ordering issue that works on SQL Server 2019 (for developer installs).
14+
-- 17-12-2025 SA TD-6520 - Refractored the SP to fix the DTU spike.
1415
-------------------------------------------------------------------------------
1516
CREATE PROCEDURE [hierarchy].[GetNodePathNodes]
1617
(
17-
@NodePathId INT
18+
@NodePathId INT
1819
)
19-
2020
AS
21-
2221
BEGIN
22+
SET NOCOUNT ON;
2323

24-
SELECT
25-
CAST(value AS INT) AS NodeId,
26-
COALESCE(fnv.Name, cnv.Name) AS Name
27-
FROM hierarchy.NodePath np
28-
CROSS APPLY hub.fn_Split(NodePath, '\') as ss
29-
INNER JOIN hierarchy.NodeVersion nv ON nv.NodeId = ss.value
30-
LEFT JOIN hierarchy.CatalogueNodeVersion cnv ON cnv.NodeVersionId = nv.Id
31-
LEFT JOIN hierarchy.FolderNodeVersion fnv ON fnv.NodeVersionId = nv.Id
32-
WHERE np.Id = @NodePathId
33-
ORDER BY ss.idx
34-
24+
-- If NodePath is NVARCHAR, keep types consistent to avoid implicit conversions
25+
;WITH PathParts AS
26+
(
27+
SELECT
28+
ordinal,
29+
TRY_CAST(s.value AS int) AS NodeIdInt
30+
FROM hierarchy.NodePath AS np
31+
CROSS APPLY STRING_SPLIT(np.NodePath, N'\', 1) AS s -- 1 = ordinal
32+
WHERE np.Id = @NodePathId
33+
)
34+
SELECT
35+
pp.NodeIdInt AS NodeId,
36+
COALESCE(fnv.Name, cnv.Name) AS Name
37+
FROM PathParts AS pp
38+
JOIN hierarchy.NodeVersion AS nv
39+
ON nv.NodeId = pp.NodeIdInt
40+
LEFT JOIN hierarchy.CatalogueNodeVersion AS cnv
41+
ON cnv.NodeVersionId = nv.Id
42+
LEFT JOIN hierarchy.FolderNodeVersion AS fnv
43+
ON fnv.NodeVersionId = nv.Id
44+
WHERE pp.NodeIdInt IS NOT NULL
45+
ORDER BY pp.ordinal
46+
OPTION (RECOMPILE); -- helps if @NodePathId cardinality varies a lot
3547
END

0 commit comments

Comments
 (0)