Skip to content

Commit 57e7eaa

Browse files
author
Christy Henriksson
committed
Prototype for moving UpdateIsLatest to DB
1 parent 24265c2 commit 57e7eaa

22 files changed

+1149
-236
lines changed

NuGetGallery.sln

Lines changed: 8 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1,7 +1,7 @@
11

22
Microsoft Visual Studio Solution File, Format Version 12.00
33
# Visual Studio 14
4-
VisualStudioVersion = 14.0.23107.0
4+
VisualStudioVersion = 14.0.25420.1
55
MinimumVisualStudioVersion = 10.0.40219.1
66
Project("{2150E333-8FDC-42A3-9474-1A3956D46DE8}") = ".nuget", ".nuget", "{96E4AFF8-D3A1-4102-ADCF-05F186F916A9}"
77
ProjectSection(SolutionItems) = preProject
@@ -30,6 +30,8 @@ Project("{2150E333-8FDC-42A3-9474-1A3956D46DE8}") = "0. Shared", "0. Shared", "{
3030
EndProject
3131
Project("{FAE04EC0-301F-11D3-BF4B-00C04F79EFBC}") = "NuGet.Services.Search.Client", "src\NuGet.Services.Search.Client\NuGet.Services.Search.Client.csproj", "{6931C2EE-E081-4518-9798-D34D83B35BF6}"
3232
EndProject
33+
Project("{FAE04EC0-301F-11D3-BF4B-00C04F79EFBC}") = "NuGetGallery.DB.Facts", "tests\NuGetGallery.DB.Facts\NuGetGallery.DB.Facts.csproj", "{28923926-2CDE-4CD1-8199-7DECCBED6756}"
34+
EndProject
3335
Global
3436
GlobalSection(SolutionConfigurationPlatforms) = preSolution
3537
Debug|Any CPU = Debug|Any CPU
@@ -64,6 +66,10 @@ Global
6466
{6931C2EE-E081-4518-9798-D34D83B35BF6}.Debug|Any CPU.Build.0 = Debug|Any CPU
6567
{6931C2EE-E081-4518-9798-D34D83B35BF6}.Release|Any CPU.ActiveCfg = Release|Any CPU
6668
{6931C2EE-E081-4518-9798-D34D83B35BF6}.Release|Any CPU.Build.0 = Release|Any CPU
69+
{28923926-2CDE-4CD1-8199-7DECCBED6756}.Debug|Any CPU.ActiveCfg = Debug|Any CPU
70+
{28923926-2CDE-4CD1-8199-7DECCBED6756}.Debug|Any CPU.Build.0 = Debug|Any CPU
71+
{28923926-2CDE-4CD1-8199-7DECCBED6756}.Release|Any CPU.ActiveCfg = Release|Any CPU
72+
{28923926-2CDE-4CD1-8199-7DECCBED6756}.Release|Any CPU.Build.0 = Release|Any CPU
6773
EndGlobalSection
6874
GlobalSection(SolutionProperties) = preSolution
6975
HideSolutionNode = FALSE
@@ -76,5 +82,6 @@ Global
7682
{097B2CDD-9623-4C34-93C2-D373D51F5B4E} = {155100FF-524B-4CAF-93C6-A57478B3DBAD}
7783
{8AC9E39E-366C-47E5-80AE-38E71CD31386} = {39E54EC3-CBAA-453A-BE64-748FE1559A58}
7884
{6931C2EE-E081-4518-9798-D34D83B35BF6} = {05998089-58F5-4A84-8C11-C5C6244A6F89}
85+
{28923926-2CDE-4CD1-8199-7DECCBED6756} = {39E54EC3-CBAA-453A-BE64-748FE1559A58}
7986
EndGlobalSection
8087
EndGlobal
Lines changed: 42 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,42 @@
1+
-- Copyright (c) .NET Foundation. All rights reserved.
2+
-- Licensed under the Apache License, Version 2.0. See License.txt in the project root for license information.
3+
IF (OBJECT_ID(N'[dbo].[SplitVersion]') IS NOT NULL)
4+
DROP FUNCTION [dbo].[SplitVersion]
5+
GO
6+
7+
CREATE FUNCTION [dbo].[SplitVersion]
8+
(
9+
@Version NVARCHAR(64)
10+
)
11+
RETURNS NVARCHAR(96)
12+
AS
13+
BEGIN
14+
-- see http://semver.org (i.e., 'versionPart(-labelsPart)?(+buildPart)?'
15+
DECLARE @versionPart NVARCHAR(64),
16+
@labelsPart NVARCHAR(64),
17+
@buildPart NVARCHAR(64),
18+
@temp NVARCHAR(64)
19+
20+
-- split build part first in case '+' precedes '-'
21+
DECLARE @pos INT = CHARINDEX('+', @Version),
22+
@len INT = LEN(@Version)
23+
24+
SELECT @pos = IIF(@pos <= 0, @len+1, @pos)
25+
SELECT @temp = SUBSTRING(@Version,0,@pos),
26+
@buildPart = SUBSTRING(@Version,@pos+1,@len)
27+
28+
-- split version and labels parts
29+
SELECT @pos = CHARINDEX('-', @temp),
30+
@len = LEN(@temp)
31+
SELECT @pos = IIF(@pos <= 0, @len+1, @pos)
32+
SELECT @versionPart = SUBSTRING(@temp,0,@pos),
33+
@labelsPart = SUBSTRING(@temp,@pos+1,@len)
34+
35+
-- verify version part is valid hierarchy
36+
IF ( TRY_CAST('/' + @versionPart + '/' AS HIERARCHYID) IS NULL )
37+
SELECT @versionPart = '',
38+
@labelsPart = @temp
39+
40+
RETURN '<v vp="' + @versionPart + '" lp="' + @labelsPart + '" bp="' + @buildPart + '" />'
41+
END
42+
GO
Lines changed: 109 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,109 @@
1+
-- Copyright (c) .NET Foundation. All rights reserved.
2+
-- Licensed under the Apache License, Version 2.0. See License.txt in the project root for license information.
3+
IF (OBJECT_ID(N'[dbo].[OrderPackagesByVersion]') IS NOT NULL)
4+
DROP PROCEDURE [dbo].[OrderPackagesByVersion]
5+
GO
6+
7+
CREATE PROCEDURE OrderPackagesByVersion
8+
@PackageRegistrationKey INT
9+
AS
10+
BEGIN
11+
DECLARE @labels TABLE
12+
(
13+
[Key] INT,
14+
[Version] NVARCHAR(64),
15+
[VersionPart] NVARCHAR(64),
16+
[VersionPartHier] HIERARCHYID,
17+
[LabelsPart] NVARCHAR(64),
18+
[BuildPart] NVARCHAR(64),
19+
[Label] NVARCHAR(64),
20+
[Node] INT,
21+
[DenseRank] INT
22+
)
23+
24+
-- 1. Split version strings into parts and label parts into label identifiers
25+
26+
-- q3: split labels part into label identifiers (split across new rows)
27+
INSERT INTO @labels
28+
SELECT q3.[Key], q3.[Version],
29+
q3.[VersionPart], q3.[VersionPartHier], q3.[LabelsPart], q3.[BuildPart],
30+
v.id.value('.', 'VARCHAR(64)') AS Label,
31+
ROW_NUMBER() OVER (PARTITION BY q3.[Key] ORDER BY q3.[Key]) AS Node,
32+
0 AS DenseRank
33+
FROM
34+
(
35+
-- q2: split labels part into label identifiers (xml)
36+
SELECT q2.*, CAST('<id>'+REPLACE(q2.LabelsPart, '.', '</id><id>')+'</id>' AS XML) AS Labels
37+
FROM
38+
(
39+
-- q1: split version string into parts (new columns)
40+
SELECT q1.*,
41+
v.c.value('@vp', 'VARCHAR(64)') AS VersionPart,
42+
TRY_CAST('/' + v.c.value('@vp', 'VARCHAR(64)') + '/' AS HIERARCHYID) AS VersionPartHier,
43+
v.c.value('@lp', 'VARCHAR(64)') AS LabelsPart,
44+
v.c.value('@bp', 'VARCHAR(64)') AS BuildPart
45+
FROM
46+
(
47+
-- split version string into parts (xml)
48+
SELECT [Key], [Version], CAST([dbo].[SplitVersion]([Version]) AS XML) AS VersionParts
49+
FROM [dbo].[Packages]
50+
WHERE [PackageRegistrationKey] = @PackageRegistrationKey AND
51+
-- filter early to simplify IsLatest calculations
52+
[Listed] = 1 AND [Deleted] = 0
53+
) AS q1
54+
OUTER APPLY q1.VersionParts.nodes('v') AS v(c)
55+
) AS q2
56+
) AS q3
57+
CROSS APPLY q3.Labels.nodes('id') AS v(id)
58+
59+
-- 2. Calculate numeric rankings across all label identifiers in the same node index
60+
61+
UPDATE T SET DenseRank = dr
62+
FROM (
63+
-- collation is case insensitive by default
64+
SELECT DenseRank, DENSE_RANK() OVER (
65+
PARTITION BY Node ORDER BY
66+
-- no labels first
67+
IIF(NULLIF(Label, '') IS NULL, 1, 0),
68+
-- numeric over alphanumeric
69+
IIF(TRY_CAST(Label AS INT) IS NULL, 1, 0),
70+
-- numeric comparison when possible, else alphanumeric
71+
TRY_CAST(Label AS INT), Label
72+
) AS dr
73+
FROM @labels
74+
) AS T
75+
76+
-- 3. Calculate IsLatest flags and cache version order in case we want to use in future
77+
78+
-- review: should IsLatestStable calc use BuildPart, and can there be duplicate versions with different build metadata?
79+
SELECT q3.*,
80+
CAST(IIF(ROW_NUMBER() OVER (
81+
ORDER BY q3.[VersionPartHier] DESC, q3.[LabelsPartHier] DESC, q3.[BuildPart] DESC
82+
)=1, 1, 0) AS BIT) as IsLatest,
83+
CAST(IIF(NULLIF(q3.[LabelsPart], '') IS NULL AND NULLIF(q3.[BuildPart], '') IS NULL AND ROW_NUMBER() OVER (
84+
ORDER BY NULLIF(q3.[LabelsPart], ''), NULLIF(q3.[BuildPart], ''), q3.[VersionPartHier] DESC, q3.[BuildPart] DESC
85+
)=1, 1, 0) AS BIT) as IsLatestStable,
86+
CAST(ROW_NUMBER() OVER (
87+
ORDER BY q3.[VersionPartHier] DESC, q3.[LabelsPartHier] DESC, q3.[BuildPart] DESC) AS INT) as VersionRank
88+
FROM (
89+
-- q2: join on DenseRanks to finish conversion of alphanumeric label parts into orderable hierarchy ids
90+
SELECT
91+
q2.[Key], q2.[Version],
92+
q2.[VersionPart], q2.[VersionPartHier], q2.[LabelsPart],
93+
STUFF((SELECT '.' + CAST([DenseRank] AS VARCHAR(64))
94+
FROM @labels q1
95+
WHERE q2.[Key] = q1.[Key] FOR XML PATH('')
96+
), 1, 1, '') AS LabelsPartHierStr,
97+
CAST('/' +
98+
STUFF((SELECT '.' + CAST([DenseRank] AS VARCHAR(64))
99+
FROM @labels q1
100+
WHERE q2.[Key] = q1.[Key] FOR XML PATH('')
101+
), 1, 1, '') +
102+
'/' AS HIERARCHYID) AS LabelsPartHier,
103+
q2.[BuildPart]
104+
FROM @labels q2
105+
GROUP BY [Key], [Version], [VersionPart], [VersionPartHier], [LabelsPart], [BuildPart]
106+
) AS q3
107+
ORDER BY VersionRank
108+
END
109+
GO
Lines changed: 34 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,34 @@
1+
-- Copyright (c) .NET Foundation. All rights reserved.
2+
-- Licensed under the Apache License, Version 2.0. See License.txt in the project root for license information.
3+
IF (OBJECT_ID(N'[dbo].[UpdateIsLatestFlags]') IS NOT NULL)
4+
DROP PROCEDURE [dbo].[UpdateIsLatestFlags]
5+
GO
6+
7+
CREATE PROCEDURE [dbo].[UpdateIsLatestFlags]
8+
@PackageRegistrationKey INT
9+
AS
10+
BEGIN
11+
DECLARE @orderedPackages [dbo].[PackageVersionHierarchyTableType],
12+
@lock INT
13+
14+
EXEC @lock = sp_getapplock @Resource='UpdateIsLatestFlags', @LockMode='Exclusive', @LockTimeout=5000
15+
IF ( @lock >= 0 )
16+
BEGIN
17+
-- clear IsLatest flags first since OrderPackagesByVersion filters out unlisted and deleted packages
18+
UPDATE [dbo].[Packages]
19+
SET [IsLatest] = 0, [IsLatestStable] = 0, [LastUpdated] = GETUTCDATE()
20+
WHERE [PackageRegistrationKey] = @PackageRegistrationKey AND
21+
([IsLatest] = 1 OR [IsLatestStable] = 1)
22+
23+
-- order listed and undeleted packages and update IsLatest flags
24+
INSERT INTO @orderedPackages EXEC [dbo].[OrderPackagesByVersion] @PackageRegistrationKey
25+
26+
UPDATE [dbo].[Packages]
27+
SET [IsLatest] = op.[IsLatest], [IsLatestStable] = op.[IsLatestStable], [LastUpdated] = GETUTCDATE()
28+
FROM @orderedPackages AS op
29+
WHERE [Key] = op.[PackageKey] AND
30+
[dbo].[Packages].[IsLatest] != op.[IsLatest] AND
31+
[dbo].[Packages].[IsLatestStable] != op.[IsLatestStable]
32+
END
33+
END
34+
GO
Lines changed: 59 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,59 @@
1+
-- Copyright (c) .NET Foundation. All rights reserved.
2+
-- Licensed under the Apache License, Version 2.0. See License.txt in the project root for license information.
3+
4+
-- Update IsLatest flags when package listed or deleted state changes
5+
IF (OBJECT_ID(N'[dbo].[tr_UpdateIsLatestFlags_Update]') IS NOT NULL)
6+
DROP TRIGGER [dbo].[tr_UpdateIsLatestFlags_Update]
7+
GO
8+
9+
CREATE TRIGGER [dbo].[tr_UpdateIsLatestFlags_Update]
10+
ON [dbo].[Packages]
11+
AFTER UPDATE
12+
AS
13+
DECLARE @packageRegistrationKey INT
14+
15+
SELECT @packageRegistrationKey=PackageRegistrationKey
16+
FROM INSERTED
17+
18+
IF ( UPDATE (Listed) OR UPDATE(Deleted) )
19+
EXEC [dbo].[UpdateIsLatestFlags] @packageRegistrationKey
20+
GO
21+
22+
-- Update IsLatest flags when latest package is deleted
23+
IF (OBJECT_ID(N'[dbo].[tr_UpdateIsLatestFlags_Delete]') IS NOT NULL)
24+
DROP TRIGGER [dbo].[tr_UpdateIsLatestFlags_Delete]
25+
GO
26+
27+
CREATE TRIGGER [dbo].[tr_UpdateIsLatestFlags_Delete]
28+
ON [dbo].[Packages]
29+
AFTER DELETE
30+
AS
31+
DECLARE @packageRegistrationKey INT,
32+
@isLatest BIT,
33+
@isLatestStable BIT
34+
35+
SELECT @packageRegistrationKey=PackageRegistrationKey,
36+
@isLatest = IsLatest,
37+
@isLatestStable = IsLatestStable
38+
FROM DELETED
39+
40+
IF ( (@isLatest | @isLatestStable) = 1 )
41+
EXEC [dbo].[UpdateIsLatestFlags] @packageRegistrationKey
42+
GO
43+
44+
-- Update IsLatest flags when new package is inserted
45+
IF (OBJECT_ID(N'[dbo].[tr_UpdateIsLatestFlags_Insert]') IS NOT NULL)
46+
DROP TRIGGER [dbo].[tr_UpdateIsLatestFlags_Insert]
47+
GO
48+
49+
CREATE TRIGGER [dbo].[tr_UpdateIsLatestFlags_Insert]
50+
ON [dbo].[Packages]
51+
AFTER INSERT
52+
AS
53+
DECLARE @packageRegistrationKey INT
54+
55+
SELECT @packageRegistrationKey=PackageRegistrationKey
56+
FROM INSERTED
57+
58+
EXEC [dbo].[UpdateIsLatestFlags] @packageRegistrationKey
59+
GO
Lines changed: 24 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,24 @@
1+
-- Copyright (c) .NET Foundation. All rights reserved.
2+
-- Licensed under the Apache License, Version 2.0. See License.txt in the project root for license information.
3+
IF (TYPE_ID(N'[dbo].[PackageVersionHierarchyTableType]') IS NOT NULL)
4+
DROP TYPE [dbo].[PackageVersionHierarchyTableType]
5+
GO
6+
7+
CREATE TYPE [dbo].[PackageVersionHierarchyTableType] AS TABLE
8+
(
9+
-- input from Packages table
10+
[PackageKey] INT,
11+
[Version] NVARCHAR(64),
12+
13+
-- output from OrderPackagesByVersion sproc
14+
[VersionPart] NVARCHAR(64),
15+
[VersionPartHier] HIERARCHYID,
16+
[LabelsPart] NVARCHAR(64),
17+
[LabelsPartHierStr] NVARCHAR(64),
18+
[LabelsPartHier] HIERARCHYID,
19+
[BuildPart] NVARCHAR(64),
20+
[IsLatest] BIT,
21+
[IsLatestStable] BIT,
22+
[VersionRank] INT
23+
)
24+
GO

src/NuGetGallery/Migrations/201612191615418_UpdateIsLatest.Designer.cs

Lines changed: 29 additions & 0 deletions
Some generated files are not rendered by default. Learn more about customizing how changed files appear on GitHub.
Lines changed: 21 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,21 @@
1+
// Copyright (c) .NET Foundation. All rights reserved.
2+
// Licensed under the Apache License, Version 2.0. See License.txt in the project root for license information.
3+
namespace NuGetGallery.Migrations
4+
{
5+
public partial class UpdateIsLatest : SqlResourceMigration
6+
{
7+
public UpdateIsLatest() :
8+
base (new []
9+
{
10+
// keeping SQL compliant with both SqlAzure and SQL 2012 (localdb) for self host
11+
"NuGetGallery.Infrastructure.Programmability.Types.PackageVersionHierarchyTableType.sql",
12+
"NuGetGallery.Infrastructure.Programmability.Functions.SplitVersion.sql",
13+
"NuGetGallery.Infrastructure.Programmability.Procedures.OrderPackagesByVersion.sql",
14+
"NuGetGallery.Infrastructure.Programmability.Procedures.UpdateIsLatestFlags.sql",
15+
"NuGetGallery.Infrastructure.Programmability.Triggers.UpdateIsLatestFlagsTriggers.sql"
16+
})
17+
{
18+
}
19+
20+
}
21+
}

0 commit comments

Comments
 (0)