I am working on a project that requires reports that can dynamically group the source data on non-standard user defined intervals such as Production Shifts within a specified start and end range. Example user may want to see production information group by shift for the last two days. I created a table called ‘IntervalConfiguration’ that stores the configuration information required to create the grouping intervals with data as follow:
IntervalType SubIntervalType IntervalDuration IntervalDurationUnits IntervalStartReferenceTime IntervalRepeatDuration IntervalRepeatDurationUnits
------------------------- ------------------- -------------------- --------------------- -------------------------- ---------------------- ---------------------------
Production Day ProductionDay 1 Days 2013-01-07 07:00:00.000 1 Days
Production Month ProductionMonth 1 Months 2013-01-01 07:00:00.000 1 Months
Production Week ProductionWeek 1 Weeks 2013-01-07 08:45:00.000 1 Weeks
Production Year ProductionYear 1 Years 2013-01-01 08:45:00.000 1 Years
Site A - Production Shift Day 12 Hours 2013-01-06 07:00:00.000 24 Hours
Site A - Production Shift Night 12 Hours 2013-01-06 19:00:00.000 24 Hours
Site B - Production Shift Day 12 Hours 2013-01-06 06:45:00.000 24 Hours
Site B - Production Shift Night 12 Hours 2013-01-06 18:45:00.000 24 Hours
If a user selects ‘Site A - Production Shift’ as the grouping interval on the report and a start date of '01/01/2018' and end date of '01/05/2018' then the report has to create grouping intervals for day shifts where day shifts start at 7AM and ends at 7PM and night shift where night shift start at 7PM and ends at 7AM the next day. Also, only grouping intervals completely contained within the start and end date should be returned. Below is an example of expected grouping intervals for the scenario described.
SubIntervalType IntervalStart IntervalEnd
---------------- ----------------------- -----------------------
Day 2018-01-01 07:00:00.000 2018-01-01 19:00:00.000
Night 2018-01-01 19:00:00.000 2018-01-02 07:00:00.000
Day 2018-01-02 07:00:00.000 2018-01-02 19:00:00.000
Night 2018-01-02 19:00:00.000 2018-01-03 07:00:00.000
Day 2018-01-03 07:00:00.000 2018-01-03 19:00:00.000
Night 2018-01-03 19:00:00.000 2018-01-04 07:00:00.000
Day 2018-01-04 07:00:00.000 2018-01-04 19:00:00.000
If user selects Production Month as the grouping interval with a start date of '01/01/2018' and end date of '01/01/2019' then the report should generate the following grouping intervals.
SubIntervalType IntervalStart IntervalEnd
----------------- ----------------------- -----------------------
ProductionMonth 2018-01-01 07:00:00.000 2018-02-01 07:00:00.000
ProductionMonth 2018-02-01 07:00:00.000 2018-03-01 07:00:00.000
ProductionMonth 2018-03-01 07:00:00.000 2018-04-01 07:00:00.000
ProductionMonth 2018-04-01 07:00:00.000 2018-05-01 07:00:00.000
ProductionMonth 2018-05-01 07:00:00.000 2018-06-01 07:00:00.000
ProductionMonth 2018-06-01 07:00:00.000 2018-07-01 07:00:00.000
ProductionMonth 2018-07-01 07:00:00.000 2018-08-01 07:00:00.000
ProductionMonth 2018-08-01 07:00:00.000 2018-09-01 07:00:00.000
ProductionMonth 2018-09-01 07:00:00.000 2018-10-01 07:00:00.000
ProductionMonth 2018-10-01 07:00:00.000 2018-11-01 07:00:00.000
ProductionMonth 2018-11-01 07:00:00.000 2018-12-01 07:00:00.000
I have started building the following table valued function to dynamically create the desired grouping intervals.
CREATE FUNCTION [dbo].[GetIntervals]
(
@dateRangeStart datetime,
@dateRangeEnd datetime,
@groupByInterval NVARCHAR(200)
)
RETURNS @Intervals TABLE (
IntervalType NVARCHAR(100)
,SubIntervalType NVARCHAR(100)
,IntervalStart DATETIME
,IntervalEnd DATETIME
,IntervalDurationSeconds FLOAT
)
AS
BEGIN
DECLARE @activeIntervalDateTime DATETIME = DATEADD(millisecond, 3, @dateRangeStart);
DECLARE @intervalStartTime DATETIME = DATEADD(s, 1, @dateRangeStart);
DECLARE @intervalEndTime DATETIME = DATEADD(s, 1, @dateRangeStart);
DECLARE @intervalDurationSeconds FLOAT;
DECLARE @intervalName NVARCHAR(100);
DECLARE @subIntervalType NVARCHAR(100);
WHILE @intervalStartTime <= @dateRangeEnd
BEGIN
SELECT TOP 1
@intervalName = IntervalType ,@subIntervalType = SubIntervalType , @intervalStartTime = IntervalStart, @intervalEndTime = IntervalEnd
FROM (SELECT IntervalType, SubIntervalType, IntervalDuration, IntervalDurationUnits,
IntervalRepeatDuration, IntervalRepeatDurationUnits,
CASE IntervalRepeatDurationUnits
WHEN 'Hours' THEN (DateAdd(HH, (DateDiff(HH, IntervalStartReferenceTime, ActiveTimeNormalized ) / IntervalRepeatDuration) * IntervalRepeatDuration, IntervalStartReferenceTime))
WHEN 'Days' THEN (DateAdd(D, (DateDiff(D, IntervalStartReferenceTime, ActiveTimeNormalized ) / IntervalRepeatDuration) * IntervalRepeatDuration, IntervalStartReferenceTime))
WHEN 'Months'THEN (DateAdd(MM, (DateDiff(MM, IntervalStartReferenceTime, ActiveTimeNormalized ) / IntervalRepeatDuration) * IntervalRepeatDuration, IntervalStartReferenceTime))
END AS IntervalStart,
CASE IntervalRepeatDurationUnits
WHEN 'Hours' THEN (DateAdd(HH, IntervalDuration, DateAdd(HH, (DateDiff(HH, IntervalStartReferenceTime, ActiveTimeNormalized ) / IntervalRepeatDuration) * IntervalRepeatDuration, IntervalStartReferenceTime)))
WHEN 'Days' THEN
CASE IntervalDurationUnits
WHEN 'Hours' THEN (DateAdd(HH, IntervalDuration, DateAdd(D, (DateDiff(D, IntervalStartReferenceTime, ActiveTimeNormalized ) / IntervalRepeatDuration) * IntervalRepeatDuration, IntervalStartReferenceTime)))
WHEN 'Days' THEN (DateAdd(D, IntervalDuration, DateAdd(D, (DateDiff(D, IntervalStartReferenceTime, ActiveTimeNormalized ) / IntervalRepeatDuration) * IntervalRepeatDuration, IntervalStartReferenceTime)))
END
WHEN 'Months'THEN
CASE IntervalDurationUnits
WHEN 'Hours' THEN (DateAdd(HH, IntervalDuration, DateAdd(MM, (DateDiff(MM, IntervalStartReferenceTime, ActiveTimeNormalized ) / IntervalRepeatDuration) * IntervalRepeatDuration, IntervalStartReferenceTime)))
WHEN 'Days' THEN (DateAdd(D, IntervalDuration, DateAdd(MM, (DateDiff(MM, IntervalStartReferenceTime, ActiveTimeNormalized ) / IntervalRepeatDuration) * IntervalRepeatDuration, IntervalStartReferenceTime)))
WHEN 'Months' THEN (DateAdd(MM, IntervalDuration, DateAdd(MM, (DateDiff(MM, IntervalStartReferenceTime, ActiveTimeNormalized ) / IntervalRepeatDuration) * IntervalRepeatDuration, IntervalStartReferenceTime)))
END
END AS IntervalEnd
,IntervalStartReferenceTime
FROM (
SELECT IntervalType, SubIntervalType, IntervalDuration, IntervalDurationUnits, IntervalRepeatDuration, IntervalRepeatDurationUnits, IntervalStartReferenceTime,
CASE IntervalRepeatDurationUnits
WHEN 'Hours' THEN DATEADD(MILLISECOND, -1*(DATEPART(MILLISECOND, IntervalStartReferenceTime) + 3), DATEADD(SECOND, -1*DATEPART(SECOND, IntervalStartReferenceTime), DATEADD(MINUTE, -1*DATEPART(MINUTE, IntervalStartReferenceTime), @activeIntervalDateTime)))
WHEN 'Days' THEN DATEADD(MILLISECOND, -1*(DATEPART(MILLISECOND, IntervalStartReferenceTime) + 3), DATEADD(SECOND, -1*DATEPART(SECOND, IntervalStartReferenceTime), DATEADD(MINUTE, -1*DATEPART(MINUTE, IntervalStartReferenceTime), DATEADD(HOUR, -1*DATEPART(HOUR, IntervalStartReferenceTime), @activeIntervalDateTime))))
WHEN 'Months' THEN DATEADD(MILLISECOND, -1*(DATEPART(MILLISECOND, IntervalStartReferenceTime) + 3), DATEADD(SECOND, -1*DATEPART(SECOND, IntervalStartReferenceTime), DATEADD(MINUTE, -1*DATEPART(MINUTE, IntervalStartReferenceTime), DATEADD(HOUR, -1*DATEPART(HOUR, IntervalStartReferenceTime), DATEADD(DAY, -1*(DATEPART(DAY, IntervalStartReferenceTime) - 1), @activeIntervalDateTime)))))
END AS ActiveTimeNormalized
FROM dbo.IntervalConfiguration
) norm
WHERE IntervalType = @groupByInterval) interval
WHERE (@activeIntervalDateTime > IntervalStart) and (@activeIntervalDateTime <= IntervalEnd)
ORDER BY IntervalStartReferenceTime DESC
SET @intervalDurationSeconds = DATEDIFF(SECOND, @intervalStartTime, @intervalEndTime);
IF @intervalStartTime >= @dateRangeStart AND @intervalEndTime <= @dateRangeEnd
BEGIN
INSERT INTO @Intervals(
IntervalType
,SubIntervalType
,IntervalStart
,IntervalEnd
,IntervalDurationSeconds
)
VALUES(
@intervalName
,@subIntervalType
,@intervalStartTime
,@intervalEndTime
,@intervalDurationSeconds
)
END
SET @activeIntervalDateTime = DATEADD(MILLISECOND, 3, @intervalEndTime);
END
RETURN;
END
This function however is getting increasingly complex and hard to debug also I would like to eliminate the need to use While loops within the function. My question is this, is there a simpler way to achieve my requirements and is it possible to eliminate the need for a while loop?
You can definitely simplify the query and eliminate the while loop through the use of a tally table as demonstrated below:
CREATE FUNCTION [dbo].[GetIntervals]
(
@startRange datetime,
@endRange datetime,
@groupByPeriod NVARCHAR(200)
)
RETURNS TABLE
AS
RETURN
(
WITH Tally (N) AS
(
SELECT 0 UNION ALL
SELECT ROW_NUMBER() OVER (ORDER BY (SELECT NULL))
FROM (VALUES(0),(0),(0),(0),(0),(0),(0),(0),(0),(0)) a(n) -- 10 rows
CROSS JOIN (VALUES(0),(0),(0),(0),(0),(0),(0),(0),(0),(0)) b(n) -- 100 rows
CROSS JOIN (VALUES(0),(0),(0),(0),(0),(0),(0),(0),(0),(0)) c(n) -- 1,000 rows
CROSS JOIN (VALUES(0),(0),(0),(0),(0),(0),(0),(0),(0),(0)) d(n) -- 10,000 rows
--CROSS JOIN (VALUES(0),(0),(0),(0),(0),(0),(0),(0),(0),(0)) e(n) -- 100,000 rows
--CROSS JOIN (VALUES(0),(0),(0),(0),(0),(0),(0),(0),(0),(0)) f(n) -- 1,000,000 rows
),
Intervals
AS
(
SELECT I.IntervalType
,I.SubIntervalType
,I.IntervalDuration
,I.IntervalDurationUnits
,I.IntervalStartReferenceTime
,I.IntervalRepeatDuration
,I.IntervalRepeatDurationUnits
,(
CASE
WHEN I.IntervalRepeatDurationUnits = 'Years' AND N < 500 THEN DATEADD(YEAR, ((DATEDIFF(YEAR, I.IntervalStartReferenceTime, @startRange) / I.IntervalRepeatDuration) + N) * I.IntervalRepeatDuration ,I.IntervalStartReferenceTime)
WHEN I.IntervalRepeatDurationUnits = 'Months' AND N < 6000 THEN DATEADD(MONTH, ((DATEDIFF(MONTH, I.IntervalStartReferenceTime, @startRange) / I.IntervalRepeatDuration) + N) * I.IntervalRepeatDuration ,I.IntervalStartReferenceTime)
WHEN I.IntervalRepeatDurationUnits = 'Weeks' AND N < 24000 THEN DATEADD(WEEK, ((DATEDIFF(WEEK, I.IntervalStartReferenceTime, @startRange) / I.IntervalRepeatDuration) + N) * I.IntervalRepeatDuration ,I.IntervalStartReferenceTime)
WHEN I.IntervalRepeatDurationUnits = 'Days' THEN DATEADD(DAY, ((DATEDIFF(DAY, I.IntervalStartReferenceTime, @startRange) / I.IntervalRepeatDuration) + N) * I.IntervalRepeatDuration ,I.IntervalStartReferenceTime)
WHEN I.IntervalRepeatDurationUnits = 'Hours' THEN DATEADD(HOUR, ((DATEDIFF(HOUR, I.IntervalStartReferenceTime, @startRange) / I.IntervalRepeatDuration) + N) * I.IntervalRepeatDuration ,I.IntervalStartReferenceTime)
END
) AS IntervalStart
,Tally.N
FROM IntervalConfiguration I
CROSS JOIN Tally
WHERE (I.IntervalType = @groupByPeriod)
AND
(
N BETWEEN 0 AND (
CASE I.IntervalRepeatDurationUnits
WHEN 'Years' THEN DATEDIFF(YEAR, @startRange, @endRange) / I.IntervalRepeatDuration
WHEN 'Months' THEN DATEDIFF(MONTH, @startRange, @endRange) / I.IntervalRepeatDuration
WHEN 'Weeks' THEN DATEDIFF(WEEK, @startRange, @endRange) / I.IntervalRepeatDuration
WHEN 'Days' THEN DATEDIFF(DAY, @startRange, @endRange) / I.IntervalRepeatDuration
WHEN 'Hours' THEN DATEDIFF(HOUR, @startRange, @endRange) / I.IntervalRepeatDuration
END)
)
)
SELECT TOP 100 PERCENT
I.IntervalType
,I.SubIntervalType
,I.IntervalDuration
,I.IntervalDurationUnits
,I.IntervalStartReferenceTime
,I.IntervalRepeatDuration
,I.IntervalRepeatDurationUnits
,I.IntervalStart
,(
CASE I.IntervalDurationUnits
WHEN 'Years' THEN DATEADD(YEAR, I.IntervalDuration, I.IntervalStart)
WHEN 'Months' THEN DATEADD(MONTH, I.IntervalDuration, I.IntervalStart)
WHEN 'Weeks' THEN DATEADD(WEEK, I.IntervalDuration, I.IntervalStart)
WHEN 'Days' THEN DATEADD(DAY, I.IntervalDuration, I.IntervalStart)
WHEN 'Hours' THEN DATEADD(HOUR, I.IntervalDuration, I.IntervalStart)
END
) AS IntervalEnd
,N
FROM Intervals I
WHERE I.IntervalStart >= @startRange
AND
(
CASE I.IntervalDurationUnits
WHEN 'Years' THEN DATEADD(YEAR, I.IntervalDuration, I.IntervalStart)
WHEN 'Months' THEN DATEADD(MONTH, I.IntervalDuration, I.IntervalStart)
WHEN 'Weeks' THEN DATEADD(WEEK, I.IntervalDuration, I.IntervalStart)
WHEN 'Days' THEN DATEADD(DAY, I.IntervalDuration, I.IntervalStart)
WHEN 'Hours' THEN DATEADD(HOUR, I.IntervalDuration, I.IntervalStart)
END
) <= @endRange
ORDER BY I.IntervalStart
)