Skip to content
This repository has been archived by the owner on Jul 30, 2024. It is now read-only.
/ NuGet.Jobs Public archive

[2019.03.15] FI NuGet.Jobs DEV into MASTER #723

Merged
merged 1 commit into from
Mar 15, 2019
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
Expand Up @@ -4,54 +4,22 @@ AS
BEGIN
SET NOCOUNT ON;

DECLARE @6WeeksAgo DATE = CAST(DATEADD(WEEK, -6, @ReportGenerationTime) AS DATE)
DECLARE @MinDate DATE
DECLARE @MinWeekOfYear INT
DECLARE @MinYear INT

SELECT @MinWeekOfYear = [WeekOfYear],
@MinYear = [Year]
FROM [dbo].[Dimension_Date] (NOLOCK)
WHERE [Date] = CAST(DATEADD(day, -42, @ReportGenerationTime) AS DATE)

SELECT @MinDate = MIN([Date])
FROM [dbo].[Dimension_Date] (NOLOCK)
WHERE [WeekOfYear] = @MinWeekOfYear
AND [Year] = @MinYear
SELECT @MinDate = MIN(d1.Date)
FROM [dbo].View_Fixed_Week_Dimension_Date d1
JOIN [dbo].View_Fixed_Week_Dimension_Date d2 ON d2.[Date] = @6WeeksAgo AND d2.[WeekOfYear] = d1.[WeekOfYear] AND d2.[Year] = d1.[Year]
WHERE d1.[Date] >= DATEADD(WEEK, -1, @6WeeksAgo) AND d1.[Date] <= @6WeeksAgo

DECLARE @Cursor DATETIME = (SELECT ISNULL(MAX([Position]), @ReportGenerationTime) FROM [dbo].[Cursors] (NOLOCK) WHERE [Name] = 'GetDirtyPackageId')
DECLARE @MaxDate DATE = DATEADD(DAY, 42, @MinDate);
DECLARE @MaxDate DATE = DATEADD(WEEK, 6, @MinDate);

WITH WeekLookup AS
(
-- If we just take all the rows between @MinDate and @MaxDate from Dimension_Date table
-- we might end up the days from the week that contains 1st of January to have two
-- different week numbers:
-- 12/30/2018 -> 53rd of 2018
-- 12/31/2018 -> 53rd of 2018
-- 1/1/2019 -> 1st of 2019
-- 1/2/2019 -> 1st of 2019
-- etc.
-- which results in the wrong grouping when group by [WeekOfYear] and [Year] is done:
-- the single week gets split into two portions, one for the previous year and another for
-- the new one with aggregations calculated separately for each of the portions.
-- This CTE works around the issue by making sure that all days of the week map to
-- the same [WeekOfYear] and [Year], specifically to that of the first day of that week.
SELECT d.[Id], dd.[WeekOfYear], dd.[Year]
FROM [dbo].[Dimension_Date] AS d WITH(NOLOCK)
CROSS APPLY
(
SELECT TOP(1) [WeekOfYear], [Year]
FROM [dbo].[Dimension_Date] AS d2 WITH(NOLOCK)
WHERE d2.[Date] <= d.[Date] AND d2.[DayOfWeek] = 1
ORDER BY d2.[Date] DESC
) AS dd
WHERE d.[Date] >= @MinDate AND d.[Date] < @MaxDate AND d.[Date] <= @Cursor
)
SELECT D.[Year],
D.[WeekOfYear],
SUM(ISNULL(Facts.[DownloadCount], 0)) AS [Downloads]
FROM [dbo].[Fact_Download] AS Facts (NOLOCK)
INNER JOIN WeekLookup AS D ON D.Id = Facts.Dimension_Date_Id
INNER JOIN [dbo].View_Fixed_Week_Dimension_Date AS D ON D.Id = Facts.Dimension_Date_Id AND D.[Date] >= @MinDate AND D.[Date] < @MaxDate
GROUP BY D.[Year], D.[WeekOfYear]
ORDER BY [Year], [WeekOfYear]
END
1 change: 1 addition & 0 deletions src/Stats.Warehouse/Stats.Warehouse.sqlproj
Original file line number Diff line number Diff line change
Expand Up @@ -138,6 +138,7 @@
<Build Include="Programmability\Stored Procedures\dbo.CheckLogFileHasToolStatistics.sql" />
<Build Include="Programmability\Stored Procedures\dbo.DownloadReportRecentCommunityPopularity.sql" />
<Build Include="Programmability\Stored Procedures\dbo.DownloadReportRecentCommunityPopularityDetail.sql" />
<Build Include="Views\dbo.View_Fixed_Week_Dimension_Date.sql" />
</ItemGroup>
<ItemGroup>
<None Include="StaticCodeAnalysis.SuppressMessages.xml" />
Expand Down
27 changes: 27 additions & 0 deletions src/Stats.Warehouse/Views/dbo.View_Fixed_Week_Dimension_Date.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,27 @@
CREATE VIEW [dbo].View_Fixed_Week_Dimension_Date
WITH SCHEMABINDING
AS
-- [Dimension_Date] table have [WeekOfYear] and [Year] columns that are set to the
-- number of the week in a year and a year respectively.
-- This might lead to a situation around a new year day that within single week,
-- there are days that have different values of [WeekOfYear] and [Year]:
-- 12/30/2018 -> 53rd of 2018 [Sunday]
-- 12/31/2018 -> 53rd of 2018 [Monday]
-- 1/1/2019 -> 1st of 2019 [Tuesday]
-- 1/2/2019 -> 1st of 2019 [Wednesday]
-- etc.
-- which results in the wrong grouping when group by [WeekOfYear] and [Year] is done:
-- the single week gets split into two portions, one for the previous year and another for
-- the new one with aggregations calculated separately for each of the portions.
-- This view works around the issue by making sure that all days of the week map to
-- the same [WeekOfYear] and [Year], specifically to that of the first day of that week.
SELECT d.[Id], d.[Date], dd.WeekOfYear, dd.[Year]
FROM [dbo].Dimension_Date AS d WITH(NOLOCK)
CROSS APPLY
(
SELECT TOP(1) [WeekOfYear], [Year]
FROM [dbo].[Dimension_Date] AS d2 WITH(NOLOCK)
WHERE d2.[Date] IS NOT NULL AND d.[Date] IS NOT NULL AND d2.[DayOfWeek] IS NOT NULL
AND ISNULL(d2.[Date], '1980-01-01') <= ISNULL(d.[Date], '1980-01-01') AND ISNULL(d2.[DayOfWeek], 0) = 1
ORDER BY d2.[Date] DESC
) AS dd