Skip to content

Commit

Permalink
Prototype for moving UpdateIsLatest to DB
Browse files Browse the repository at this point in the history
  • Loading branch information
chenriksson committed Jan 6, 2017
1 parent 24265c2 commit 57e7eaa
Show file tree
Hide file tree
Showing 22 changed files with 1,149 additions and 236 deletions.
9 changes: 8 additions & 1 deletion NuGetGallery.sln
Original file line number Diff line number Diff line change
@@ -1,7 +1,7 @@

Microsoft Visual Studio Solution File, Format Version 12.00
# Visual Studio 14
VisualStudioVersion = 14.0.23107.0
VisualStudioVersion = 14.0.25420.1
MinimumVisualStudioVersion = 10.0.40219.1
Project("{2150E333-8FDC-42A3-9474-1A3956D46DE8}") = ".nuget", ".nuget", "{96E4AFF8-D3A1-4102-ADCF-05F186F916A9}"
ProjectSection(SolutionItems) = preProject
Expand Down Expand Up @@ -30,6 +30,8 @@ Project("{2150E333-8FDC-42A3-9474-1A3956D46DE8}") = "0. Shared", "0. Shared", "{
EndProject
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}"
EndProject
Project("{FAE04EC0-301F-11D3-BF4B-00C04F79EFBC}") = "NuGetGallery.DB.Facts", "tests\NuGetGallery.DB.Facts\NuGetGallery.DB.Facts.csproj", "{28923926-2CDE-4CD1-8199-7DECCBED6756}"
EndProject
Global
GlobalSection(SolutionConfigurationPlatforms) = preSolution
Debug|Any CPU = Debug|Any CPU
Expand Down Expand Up @@ -64,6 +66,10 @@ Global
{6931C2EE-E081-4518-9798-D34D83B35BF6}.Debug|Any CPU.Build.0 = Debug|Any CPU
{6931C2EE-E081-4518-9798-D34D83B35BF6}.Release|Any CPU.ActiveCfg = Release|Any CPU
{6931C2EE-E081-4518-9798-D34D83B35BF6}.Release|Any CPU.Build.0 = Release|Any CPU
{28923926-2CDE-4CD1-8199-7DECCBED6756}.Debug|Any CPU.ActiveCfg = Debug|Any CPU
{28923926-2CDE-4CD1-8199-7DECCBED6756}.Debug|Any CPU.Build.0 = Debug|Any CPU
{28923926-2CDE-4CD1-8199-7DECCBED6756}.Release|Any CPU.ActiveCfg = Release|Any CPU
{28923926-2CDE-4CD1-8199-7DECCBED6756}.Release|Any CPU.Build.0 = Release|Any CPU
EndGlobalSection
GlobalSection(SolutionProperties) = preSolution
HideSolutionNode = FALSE
Expand All @@ -76,5 +82,6 @@ Global
{097B2CDD-9623-4C34-93C2-D373D51F5B4E} = {155100FF-524B-4CAF-93C6-A57478B3DBAD}
{8AC9E39E-366C-47E5-80AE-38E71CD31386} = {39E54EC3-CBAA-453A-BE64-748FE1559A58}
{6931C2EE-E081-4518-9798-D34D83B35BF6} = {05998089-58F5-4A84-8C11-C5C6244A6F89}
{28923926-2CDE-4CD1-8199-7DECCBED6756} = {39E54EC3-CBAA-453A-BE64-748FE1559A58}
EndGlobalSection
EndGlobal
Original file line number Diff line number Diff line change
@@ -0,0 +1,42 @@
-- Copyright (c) .NET Foundation. All rights reserved.
-- Licensed under the Apache License, Version 2.0. See License.txt in the project root for license information.
IF (OBJECT_ID(N'[dbo].[SplitVersion]') IS NOT NULL)
DROP FUNCTION [dbo].[SplitVersion]
GO

CREATE FUNCTION [dbo].[SplitVersion]
(
@Version NVARCHAR(64)
)
RETURNS NVARCHAR(96)
AS
BEGIN
-- see http://semver.org (i.e., 'versionPart(-labelsPart)?(+buildPart)?'
DECLARE @versionPart NVARCHAR(64),
@labelsPart NVARCHAR(64),
@buildPart NVARCHAR(64),
@temp NVARCHAR(64)

-- split build part first in case '+' precedes '-'
DECLARE @pos INT = CHARINDEX('+', @Version),
@len INT = LEN(@Version)

SELECT @pos = IIF(@pos <= 0, @len+1, @pos)
SELECT @temp = SUBSTRING(@Version,0,@pos),
@buildPart = SUBSTRING(@Version,@pos+1,@len)

-- split version and labels parts
SELECT @pos = CHARINDEX('-', @temp),
@len = LEN(@temp)
SELECT @pos = IIF(@pos <= 0, @len+1, @pos)
SELECT @versionPart = SUBSTRING(@temp,0,@pos),
@labelsPart = SUBSTRING(@temp,@pos+1,@len)

-- verify version part is valid hierarchy
IF ( TRY_CAST('/' + @versionPart + '/' AS HIERARCHYID) IS NULL )
SELECT @versionPart = '',
@labelsPart = @temp

RETURN '<v vp="' + @versionPart + '" lp="' + @labelsPart + '" bp="' + @buildPart + '" />'
END
GO
Original file line number Diff line number Diff line change
@@ -0,0 +1,109 @@
-- Copyright (c) .NET Foundation. All rights reserved.
-- Licensed under the Apache License, Version 2.0. See License.txt in the project root for license information.
IF (OBJECT_ID(N'[dbo].[OrderPackagesByVersion]') IS NOT NULL)
DROP PROCEDURE [dbo].[OrderPackagesByVersion]
GO

CREATE PROCEDURE OrderPackagesByVersion
@PackageRegistrationKey INT
AS
BEGIN
DECLARE @labels TABLE
(
[Key] INT,
[Version] NVARCHAR(64),
[VersionPart] NVARCHAR(64),
[VersionPartHier] HIERARCHYID,
[LabelsPart] NVARCHAR(64),
[BuildPart] NVARCHAR(64),
[Label] NVARCHAR(64),
[Node] INT,
[DenseRank] INT
)

-- 1. Split version strings into parts and label parts into label identifiers

-- q3: split labels part into label identifiers (split across new rows)
INSERT INTO @labels
SELECT q3.[Key], q3.[Version],
q3.[VersionPart], q3.[VersionPartHier], q3.[LabelsPart], q3.[BuildPart],
v.id.value('.', 'VARCHAR(64)') AS Label,
ROW_NUMBER() OVER (PARTITION BY q3.[Key] ORDER BY q3.[Key]) AS Node,
0 AS DenseRank
FROM
(
-- q2: split labels part into label identifiers (xml)
SELECT q2.*, CAST('<id>'+REPLACE(q2.LabelsPart, '.', '</id><id>')+'</id>' AS XML) AS Labels
FROM
(
-- q1: split version string into parts (new columns)
SELECT q1.*,
v.c.value('@vp', 'VARCHAR(64)') AS VersionPart,
TRY_CAST('/' + v.c.value('@vp', 'VARCHAR(64)') + '/' AS HIERARCHYID) AS VersionPartHier,
v.c.value('@lp', 'VARCHAR(64)') AS LabelsPart,
v.c.value('@bp', 'VARCHAR(64)') AS BuildPart
FROM
(
-- split version string into parts (xml)
SELECT [Key], [Version], CAST([dbo].[SplitVersion]([Version]) AS XML) AS VersionParts
FROM [dbo].[Packages]
WHERE [PackageRegistrationKey] = @PackageRegistrationKey AND
-- filter early to simplify IsLatest calculations
[Listed] = 1 AND [Deleted] = 0
) AS q1
OUTER APPLY q1.VersionParts.nodes('v') AS v(c)
) AS q2
) AS q3
CROSS APPLY q3.Labels.nodes('id') AS v(id)

-- 2. Calculate numeric rankings across all label identifiers in the same node index

UPDATE T SET DenseRank = dr
FROM (
-- collation is case insensitive by default
SELECT DenseRank, DENSE_RANK() OVER (
PARTITION BY Node ORDER BY
-- no labels first
IIF(NULLIF(Label, '') IS NULL, 1, 0),
-- numeric over alphanumeric
IIF(TRY_CAST(Label AS INT) IS NULL, 1, 0),
-- numeric comparison when possible, else alphanumeric
TRY_CAST(Label AS INT), Label
) AS dr
FROM @labels
) AS T

-- 3. Calculate IsLatest flags and cache version order in case we want to use in future

-- review: should IsLatestStable calc use BuildPart, and can there be duplicate versions with different build metadata?
SELECT q3.*,
CAST(IIF(ROW_NUMBER() OVER (
ORDER BY q3.[VersionPartHier] DESC, q3.[LabelsPartHier] DESC, q3.[BuildPart] DESC
)=1, 1, 0) AS BIT) as IsLatest,
CAST(IIF(NULLIF(q3.[LabelsPart], '') IS NULL AND NULLIF(q3.[BuildPart], '') IS NULL AND ROW_NUMBER() OVER (
ORDER BY NULLIF(q3.[LabelsPart], ''), NULLIF(q3.[BuildPart], ''), q3.[VersionPartHier] DESC, q3.[BuildPart] DESC
)=1, 1, 0) AS BIT) as IsLatestStable,
CAST(ROW_NUMBER() OVER (
ORDER BY q3.[VersionPartHier] DESC, q3.[LabelsPartHier] DESC, q3.[BuildPart] DESC) AS INT) as VersionRank
FROM (
-- q2: join on DenseRanks to finish conversion of alphanumeric label parts into orderable hierarchy ids
SELECT
q2.[Key], q2.[Version],
q2.[VersionPart], q2.[VersionPartHier], q2.[LabelsPart],
STUFF((SELECT '.' + CAST([DenseRank] AS VARCHAR(64))
FROM @labels q1
WHERE q2.[Key] = q1.[Key] FOR XML PATH('')
), 1, 1, '') AS LabelsPartHierStr,
CAST('/' +
STUFF((SELECT '.' + CAST([DenseRank] AS VARCHAR(64))
FROM @labels q1
WHERE q2.[Key] = q1.[Key] FOR XML PATH('')
), 1, 1, '') +
'/' AS HIERARCHYID) AS LabelsPartHier,
q2.[BuildPart]
FROM @labels q2
GROUP BY [Key], [Version], [VersionPart], [VersionPartHier], [LabelsPart], [BuildPart]
) AS q3
ORDER BY VersionRank
END
GO
Original file line number Diff line number Diff line change
@@ -0,0 +1,34 @@
-- Copyright (c) .NET Foundation. All rights reserved.
-- Licensed under the Apache License, Version 2.0. See License.txt in the project root for license information.
IF (OBJECT_ID(N'[dbo].[UpdateIsLatestFlags]') IS NOT NULL)
DROP PROCEDURE [dbo].[UpdateIsLatestFlags]
GO

CREATE PROCEDURE [dbo].[UpdateIsLatestFlags]
@PackageRegistrationKey INT
AS
BEGIN
DECLARE @orderedPackages [dbo].[PackageVersionHierarchyTableType],
@lock INT

EXEC @lock = sp_getapplock @Resource='UpdateIsLatestFlags', @LockMode='Exclusive', @LockTimeout=5000
IF ( @lock >= 0 )
BEGIN
-- clear IsLatest flags first since OrderPackagesByVersion filters out unlisted and deleted packages
UPDATE [dbo].[Packages]
SET [IsLatest] = 0, [IsLatestStable] = 0, [LastUpdated] = GETUTCDATE()
WHERE [PackageRegistrationKey] = @PackageRegistrationKey AND
([IsLatest] = 1 OR [IsLatestStable] = 1)

-- order listed and undeleted packages and update IsLatest flags
INSERT INTO @orderedPackages EXEC [dbo].[OrderPackagesByVersion] @PackageRegistrationKey

UPDATE [dbo].[Packages]
SET [IsLatest] = op.[IsLatest], [IsLatestStable] = op.[IsLatestStable], [LastUpdated] = GETUTCDATE()
FROM @orderedPackages AS op
WHERE [Key] = op.[PackageKey] AND
[dbo].[Packages].[IsLatest] != op.[IsLatest] AND
[dbo].[Packages].[IsLatestStable] != op.[IsLatestStable]
END
END
GO
Original file line number Diff line number Diff line change
@@ -0,0 +1,59 @@
-- Copyright (c) .NET Foundation. All rights reserved.
-- Licensed under the Apache License, Version 2.0. See License.txt in the project root for license information.

-- Update IsLatest flags when package listed or deleted state changes
IF (OBJECT_ID(N'[dbo].[tr_UpdateIsLatestFlags_Update]') IS NOT NULL)
DROP TRIGGER [dbo].[tr_UpdateIsLatestFlags_Update]
GO

CREATE TRIGGER [dbo].[tr_UpdateIsLatestFlags_Update]
ON [dbo].[Packages]
AFTER UPDATE
AS
DECLARE @packageRegistrationKey INT

SELECT @packageRegistrationKey=PackageRegistrationKey
FROM INSERTED

IF ( UPDATE (Listed) OR UPDATE(Deleted) )
EXEC [dbo].[UpdateIsLatestFlags] @packageRegistrationKey
GO

-- Update IsLatest flags when latest package is deleted
IF (OBJECT_ID(N'[dbo].[tr_UpdateIsLatestFlags_Delete]') IS NOT NULL)
DROP TRIGGER [dbo].[tr_UpdateIsLatestFlags_Delete]
GO

CREATE TRIGGER [dbo].[tr_UpdateIsLatestFlags_Delete]
ON [dbo].[Packages]
AFTER DELETE
AS
DECLARE @packageRegistrationKey INT,
@isLatest BIT,
@isLatestStable BIT

SELECT @packageRegistrationKey=PackageRegistrationKey,
@isLatest = IsLatest,
@isLatestStable = IsLatestStable
FROM DELETED

IF ( (@isLatest | @isLatestStable) = 1 )
EXEC [dbo].[UpdateIsLatestFlags] @packageRegistrationKey
GO

-- Update IsLatest flags when new package is inserted
IF (OBJECT_ID(N'[dbo].[tr_UpdateIsLatestFlags_Insert]') IS NOT NULL)
DROP TRIGGER [dbo].[tr_UpdateIsLatestFlags_Insert]
GO

CREATE TRIGGER [dbo].[tr_UpdateIsLatestFlags_Insert]
ON [dbo].[Packages]
AFTER INSERT
AS
DECLARE @packageRegistrationKey INT

SELECT @packageRegistrationKey=PackageRegistrationKey
FROM INSERTED

EXEC [dbo].[UpdateIsLatestFlags] @packageRegistrationKey
GO
Original file line number Diff line number Diff line change
@@ -0,0 +1,24 @@
-- Copyright (c) .NET Foundation. All rights reserved.
-- Licensed under the Apache License, Version 2.0. See License.txt in the project root for license information.
IF (TYPE_ID(N'[dbo].[PackageVersionHierarchyTableType]') IS NOT NULL)
DROP TYPE [dbo].[PackageVersionHierarchyTableType]
GO

CREATE TYPE [dbo].[PackageVersionHierarchyTableType] AS TABLE
(
-- input from Packages table
[PackageKey] INT,
[Version] NVARCHAR(64),

-- output from OrderPackagesByVersion sproc
[VersionPart] NVARCHAR(64),
[VersionPartHier] HIERARCHYID,
[LabelsPart] NVARCHAR(64),
[LabelsPartHierStr] NVARCHAR(64),
[LabelsPartHier] HIERARCHYID,
[BuildPart] NVARCHAR(64),
[IsLatest] BIT,
[IsLatestStable] BIT,
[VersionRank] INT
)
GO

Some generated files are not rendered by default. Learn more about how customized files appear on GitHub.

21 changes: 21 additions & 0 deletions src/NuGetGallery/Migrations/201612191615418_UpdateIsLatest.cs
Original file line number Diff line number Diff line change
@@ -0,0 +1,21 @@
// Copyright (c) .NET Foundation. All rights reserved.
// Licensed under the Apache License, Version 2.0. See License.txt in the project root for license information.
namespace NuGetGallery.Migrations
{
public partial class UpdateIsLatest : SqlResourceMigration
{
public UpdateIsLatest() :
base (new []
{
// keeping SQL compliant with both SqlAzure and SQL 2012 (localdb) for self host
"NuGetGallery.Infrastructure.Programmability.Types.PackageVersionHierarchyTableType.sql",
"NuGetGallery.Infrastructure.Programmability.Functions.SplitVersion.sql",
"NuGetGallery.Infrastructure.Programmability.Procedures.OrderPackagesByVersion.sql",
"NuGetGallery.Infrastructure.Programmability.Procedures.UpdateIsLatestFlags.sql",
"NuGetGallery.Infrastructure.Programmability.Triggers.UpdateIsLatestFlagsTriggers.sql"
})
{
}

}
}
Loading

0 comments on commit 57e7eaa

Please sign in to comment.