December 7, 2017 at 8:25 am
Hello again, SQL experts,
I'm facing an interesting challenge. I have a production process that runs from 8 AM to 7 PM. Process capacity is 750 units per hour *except* for the 11 AM to noon hour and the 3 PM to 4 PM hour, which each have a capacity of 600 units. My challenge is to estimate the remaining capacity to end of day at any given time (down to the minute) during the day.
For example, at 8 AM, remaining capacity is 7,950, which is the total daily capacity. At 11:45 AM, remaining capacity is 5,250, which is .25 * 11 AM capacity (650) + capacity from 12:00 PM - 7:00 PM.
All of the solutions that pop into my head seem pretty clunky, so I'm wondering if anyone knows of an elegant way to do this in SQL.
Thanks in advance!
George
December 7, 2017 at 10:35 am
I suspect there's an all math way to do it, but take a look at the following, which illustrates the process somewhat:DECLARE @TIME AS time = GETDATE();
DECLARE @TIME_2 AS time = CASE WHEN DATEPART(hour, @TIME) = 23 THEN @TIME ELSE DATEADD(hour, 1, CAST(@TIME AS datetime)) END;
DECLARE @HOUR AS tinyint = DATEPART(hour, @TIME);
DECLARE @MINUTES AS tinyint = DATEPART(minute, @TIME);
CREATE TABLE #CAPACITY_OVER_TIME (
TIME_SEQUENCE_NUMBER tinyint NOT NULL PRIMARY KEY CLUSTERED,
START_TIME time NOT NULL,
END_TIME time NOT NULL,
CAPACITY int NOT NULL
);
INSERT INTO #CAPACITY_OVER_TIME (TIME_SEQUENCE_NUMBER, START_TIME, END_TIME, CAPACITY)
SELECT 0, '00:00:00.000', '01:00:00.000', 0 UNION ALL
SELECT 1, '01:00:00.000', '02:00:00.000', 0 UNION ALL
SELECT 2, '02:00:00.000', '03:00:00.000', 0 UNION ALL
SELECT 3, '03:00:00.000', '04:00:00.000', 0 UNION ALL
SELECT 4, '04:00:00.000', '05:00:00.000', 0 UNION ALL
SELECT 5, '05:00:00.000', '06:00:00.000', 0 UNION ALL
SELECT 6, '06:00:00.000', '07:00:00.000', 0 UNION ALL
SELECT 7, '07:00:00.000', '08:00:00.000', 0 UNION ALL
SELECT 8, '08:00:00.000', '09:00:00.000', 750 UNION ALL
SELECT 9, '09:00:00.000', '10:00:00.000', 750 UNION ALL
SELECT 10, '10:00:00.000', '11:00:00.000', 750 UNION ALL
SELECT 11, '11:00:00.000', '12:00:00.000', 600 UNION ALL
SELECT 12, '12:00:00.000', '13:00:00.000', 750 UNION ALL
SELECT 13, '13:00:00.000', '14:00:00.000', 750 UNION ALL
SELECT 14, '14:00:00.000', '15:00:00.000', 750 UNION ALL
SELECT 15, '15:00:00.000', '16:00:00.000', 600 UNION ALL
SELECT 16, '16:00:00.000', '17:00:00.000', 750 UNION ALL
SELECT 17, '17:00:00.000', '18:00:00.000', 750 UNION ALL
SELECT 18, '18:00:00.000', '19:00:00.000', 750 UNION ALL
SELECT 19, '19:00:00.000', '20:00:00.000', 0 UNION ALL
SELECT 20, '20:00:00.000', '21:00:00.000', 0 UNION ALL
SELECT 21, '21:00:00.000', '22:00:00.000', 0 UNION ALL
SELECT 22, '22:00:00.000', '23:00:00.000', 0 UNION ALL
SELECT 23, '23:00:00.000', '23:59:59.997', 0;
SELECT @TIME AS TIME_TO_MEASURE, @TIME_2 AS NEXT_HOUR, @HOUR AS CURRENT_HOUR, 60 - @MINUTES AS MINUTES_REMAINING,
*,
ROUND(
SUM(CASE
WHEN C.END_TIME > @TIME_2 THEN C.CAPACITY
ELSE 0
END +
CASE
WHEN C.TIME_SEQUENCE_NUMBER = @HOUR THEN ((60 - @MINUTES) / 60.) * C.CAPACITY
ELSE 0
END) OVER(ORDER BY C.TIME_SEQUENCE_NUMBER), 0) AS REMAINING_CAPACITY
FROM #CAPACITY_OVER_TIME AS C
WHERE C.END_TIME > @TIME_2
OR C.TIME_SEQUENCE_NUMBER = @HOUR;
DROP TABLE #CAPACITY_OVER_TIME;
Steve (aka sgmunson) 🙂 🙂 🙂
Rent Servers for Income (picks and shovels strategy)
December 7, 2017 at 11:04 am
I like Steve's solution. I'd be tempted to make a permanent table that tracks capacity by time (and potentially by machine/location/etc). Then use that as a way of performing calculations.
December 7, 2017 at 12:00 pm
Since you are only looking for an estimate of capacity remaining this should work:DECLARE @DailyCapacity INT = 7950, -- Daily capacity
@Minutes DECIMAL(18,2) = 660, -- Total minutes available per day
@StartTime TIME = '08:00:00', -- Daily start time from capacity calculation
@TestTime DATETIME = GETDATE();
SELECT @DailyCapacity, @Minutes, @StartTime, ROUND(@DailyCapacity * ((@Minutes - DATEDIFF(MINUTE,@StartTime,CAST(@TestTime AS TIME))) / @Minutes),0);
December 10, 2017 at 10:10 pm
I'm with Steve. I love "Helper Tables" because you can change their content instead of changing code. If it were my task, here's the table that I'd build.
CREATE TABLE dbo.CapacityByPeriod
(
PeriodStartTime TIME NOT NULL
,PeriodEndTime TIME NOT NULL
,PeriodCapacity INT NOT NULL
,PeriodMinutes AS DATEDIFF(mi,PeriodStartTime,PeriodEndTime) PERSISTED --Just in case it ever comes up. ;)
,PeriodPerMinuteCapacity AS PeriodCapacity*1.0/DATEDIFF(mi,PeriodStartTime,PeriodEndTime) PERSISTED
CONSTRAINT PK_CapacityByPeriod PRIMARY KEY CLUSTERED (PeriodStartTime)
)
;
INSERT INTO dbo.CapacityByPeriod
(PeriodStartTime,PeriodEndTime,PeriodCapacity)
VALUES ('00:00','08:00', 0 )
,('08:00','09:00', 750)
,('09:00','10:00', 750)
,('10:00','11:00', 750)
,('11:00','12:00', 600)
,('12:00','13:00', 750)
,('13:00','14:00', 750)
,('14:00','15:00', 750)
,('15:00','16:00', 600)
,('16:00','17:00', 750)
,('17:00','18:00', 750)
,('18:00','19:00', 750)
,('19:00','23:59:59.9999999', 0)
;
Then, I'd build this function and use it according to the "Usage" examples in the header. If your DBA(s) object to functions or helper tables, please see the "Developer Notes" in the header of the function for how to convince them otherwise.
CREATE FUNCTION dbo.TimeCapacityRemaining
/****************************************************************************************
Purpose:
Given a 24 hour time of day, return the remaining capacity for the day according to the
dbo.CapacityByPeriod table.
-----------------------------------------------------------------------------------------
Dependencies:
dbo.CapacityByPeriod (Table) must be in the same database.
-----------------------------------------------------------------------------------------
Usage:
--===== Syntax
SELECT CapacityRemaining FROM dbo.TimeCapacityRemaining(@pSomeTime)
;
--===== Example Usage for 6:42 PM
SELECT CapacityRemaining FROM dbo.TimeCapacityRemaining('18:42')
;
--===== Example Usage using a variable
DECLARE @SomeTime TIME = '18:42';
SELECT CapacityRemaining FROM dbo.TimeCapacityRemaining(@SomeTime)
;
--===== Example Usage when played against a TIME column in a table.
SELECT st.TimeColumn
,cr.CapacityRemaining
FROM dbo.SomeTable st
CROSS APPLY dbo.TimeCapacityRemaining(st.TimeColumn) cr
;
-----------------------------------------------------------------------------------------
Developer Notes:
1. If your DBA(s) object to using functions, tell them that this is a high performance
"iTVF" (Inline Table Value Function) that works as fast as if the code were inline
in a query. If they don't believe you or continue to object just because it's a
function, direct them to Reference #1 below for repeatable and demonstrable proof
that it's not a problem.
2. If they still insist on not letting you use it just because it's a function, thank
them for their time and then recommend to management that they get a smarter DBA.
Before they leave, ask them if they know how to get the current date and time. ;)
3. If the DBA(s) object to the use of "Helper Tables", refer to Note 2 above.
-----------------------------------------------------------------------------------------
References:
1. http://www.sqlservercentral.com/articles/T-SQL/91724/
2. https://www.sqlservercentral.com/Forums/1911664/Calculating-varying-process-capacity
-----------------------------------------------------------------------------------------
Revision History:
Rev 00 - 10 Dec 2017 - Jeff Moden
- Initial creation and unit test according to Reference 2.
****************************************************************************************/
--===== Declare the I/O for this function
(@pSomeTime TIME)
RETURNS TABLE WITH SCHEMABINDING AS
RETURN
--===== Return the remaining capacity for the day using the given time as a starting point.
SELECT CapacityRemaining =
(--=== Aggregate the capacity of the remaining whole periods.
SELECT SUM(PeriodCapacity)
FROM dbo.CapacityByPeriod
WHERE PeriodStartTime >= @pSomeTime
)
+ (--==== Calculate the capacity of time remaining in the current period.
SELECT DATEDIFF(mi,@pSomeTime,PeriodEndTime) * PeriodPerMinuteCapacity
FROM dbo.CapacityByPeriod
WHERE PeriodStartTime <= @pSomeTime AND @pSomeTime < PeriodEndTime
)
;
As a bit of a sidebar, the times in the table do NOT need to be at the top of the hour. They can be anytime provided that you pay attention and avoid gaps and overlaps in the table and that the first start time is 00:00 and the last end time is 23:59:59.99999.
--Jeff Moden
Change is inevitable... Change for the better is not.
December 11, 2017 at 7:38 am
Thanks, all! Very helpful!
George
December 11, 2017 at 8:45 am
Jeff Moden - Sunday, December 10, 2017 10:10 PMI'm with Steve. I love "Helper Tables" because you can change their content instead of changing code. If it were my task, here's the table that I'd build.
CREATE TABLE dbo.CapacityByPeriod
(
PeriodStartTime TIME NOT NULL
,PeriodEndTime TIME NOT NULL
,PeriodCapacity INT NOT NULL
,PeriodMinutes AS DATEDIFF(mi,PeriodStartTime,PeriodEndTime) PERSISTED --Just in case it ever comes up. ;)
,PeriodPerMinuteCapacity AS PeriodCapacity*1.0/DATEDIFF(mi,PeriodStartTime,PeriodEndTime) PERSISTED
CONSTRAINT PK_CapacityByPeriod PRIMARY KEY CLUSTERED (PeriodStartTime)
)
;
INSERT INTO dbo.CapacityByPeriod
(PeriodStartTime,PeriodEndTime,PeriodCapacity)
VALUES ('00:00','08:00', 0 )
,('08:00','09:00', 750)
,('09:00','10:00', 750)
,('10:00','11:00', 750)
,('11:00','12:00', 600)
,('12:00','13:00', 750)
,('13:00','14:00', 750)
,('14:00','15:00', 750)
,('15:00','16:00', 600)
,('16:00','17:00', 750)
,('17:00','18:00', 750)
,('18:00','19:00', 750)
,('19:00','23:59:59.9999999', 0)
;Then, I'd build this function and use it according to the "Usage" examples in the header. If your DBA(s) object to functions or helper tables, please see the "Developer Notes" in the header of the function for how to convince them otherwise.
CREATE FUNCTION dbo.TimeCapacityRemaining
/****************************************************************************************
Purpose:
Given a 24 hour time of day, return the remaining capacity for the day according to the
dbo.CapacityByPeriod table.
-----------------------------------------------------------------------------------------
Dependencies:
dbo.CapacityByPeriod (Table) must be in the same database.
-----------------------------------------------------------------------------------------
Usage:
--===== Syntax
SELECT CapacityRemaining FROM dbo.TimeCapacityRemaining(@pSomeTime)
;
--===== Example Usage for 6:42 PM
SELECT CapacityRemaining FROM dbo.TimeCapacityRemaining('18:42')
;
--===== Example Usage using a variable
DECLARE @SomeTime TIME = '18:42';
SELECT CapacityRemaining FROM dbo.TimeCapacityRemaining(@SomeTime)
;
--===== Example Usage when played against a TIME column in a table.
SELECT st.TimeColumn
,cr.CapacityRemaining
FROM dbo.SomeTable st
CROSS APPLY dbo.TimeCapacityRemaining(st.TimeColumn) cr
;
-----------------------------------------------------------------------------------------
Developer Notes:
1. If your DBA(s) object to using functions, tell them that this is a high performance
"iTVF" (Inline Table Value Function) that works as fast as if the code were inline
in a query. If they don't believe you or continue to object just because it's a
function, direct them to Reference #1 below for repeatable and demonstrable proof
that it's not a problem.
2. If they still insist on not letting you use it just because it's a function, thank
them for their time and then recommend to management that they get a smarter DBA.
Before they leave, ask them if they know how to get the current date and time. ;)
3. If the DBA(s) object to the use of "Helper Tables", refer to Note 2 above.
-----------------------------------------------------------------------------------------
References:
1. http://www.sqlservercentral.com/articles/T-SQL/91724/
2. https://www.sqlservercentral.com/Forums/1911664/Calculating-varying-process-capacity
-----------------------------------------------------------------------------------------
Revision History:
Rev 00 - 10 Dec 2017 - Jeff Moden
- Initial creation and unit test according to Reference 2.
****************************************************************************************/
--===== Declare the I/O for this function
(@pSomeTime TIME)
RETURNS TABLE WITH SCHEMABINDING AS
RETURN
--===== Return the remaining capacity for the day using the given time as a starting point.
SELECT CapacityRemaining =
(--=== Aggregate the capacity of the remaining whole periods.
SELECT SUM(PeriodCapacity)
FROM dbo.CapacityByPeriod
WHERE PeriodStartTime >= @pSomeTime
)
+ (--==== Calculate the capacity of time remaining in the current period.
SELECT DATEDIFF(mi,@pSomeTime,PeriodEndTime) * PeriodPerMinuteCapacity
FROM dbo.CapacityByPeriod
WHERE PeriodStartTime <= @pSomeTime AND @pSomeTime < PeriodEndTime
)
;As a bit of a sidebar, the times in the table do NOT need to be at the top of the hour. They can be anytime provided that you pay attention and avoid gaps and overlaps in the table and that the first start time is 00:00 and the last end time is 23:59:59.99999.
Again, this is a situation where you can improve the efficiency by thinking outside of the box. You can cut the number of scans/reads in half. By focusing on the period start time, you are forced to divide your results into two subsets: periods that start after the relevant time and the one period that starts before, but ends after the relevant time. If, instead, you focus on the period end time, you only have one set: periods that end after the relevant time (regardless of whether they start before or after the relevant time).
SELECT SUM(
CASE
WHEN PeriodStartTime <= @pSomeTime
THEN DATEDIFF(mi,@pSomeTime,PeriodEndTime) * PeriodPerMinuteCapacity
ELSE PeriodCapacity
END
) AS Capacity_Remaining
FROM dbo.CapacityByPeriod
WHERE @pSomeTime < PeriodEndTime
;
Drew
J. Drew Allen
Business Intelligence Analyst
Philadelphia, PA
December 11, 2017 at 9:09 am
Nice, Drew... very clever!
December 11, 2017 at 3:56 pm
drew.allen - Monday, December 11, 2017 8:45 AMJeff Moden - Sunday, December 10, 2017 10:10 PMI'm with Steve. I love "Helper Tables" because you can change their content instead of changing code. If it were my task, here's the table that I'd build.
CREATE TABLE dbo.CapacityByPeriod
(
PeriodStartTime TIME NOT NULL
,PeriodEndTime TIME NOT NULL
,PeriodCapacity INT NOT NULL
,PeriodMinutes AS DATEDIFF(mi,PeriodStartTime,PeriodEndTime) PERSISTED --Just in case it ever comes up. ;)
,PeriodPerMinuteCapacity AS PeriodCapacity*1.0/DATEDIFF(mi,PeriodStartTime,PeriodEndTime) PERSISTED
CONSTRAINT PK_CapacityByPeriod PRIMARY KEY CLUSTERED (PeriodStartTime)
)
;
INSERT INTO dbo.CapacityByPeriod
(PeriodStartTime,PeriodEndTime,PeriodCapacity)
VALUES ('00:00','08:00', 0 )
,('08:00','09:00', 750)
,('09:00','10:00', 750)
,('10:00','11:00', 750)
,('11:00','12:00', 600)
,('12:00','13:00', 750)
,('13:00','14:00', 750)
,('14:00','15:00', 750)
,('15:00','16:00', 600)
,('16:00','17:00', 750)
,('17:00','18:00', 750)
,('18:00','19:00', 750)
,('19:00','23:59:59.9999999', 0)
;Then, I'd build this function and use it according to the "Usage" examples in the header. If your DBA(s) object to functions or helper tables, please see the "Developer Notes" in the header of the function for how to convince them otherwise.
CREATE FUNCTION dbo.TimeCapacityRemaining
/****************************************************************************************
Purpose:
Given a 24 hour time of day, return the remaining capacity for the day according to the
dbo.CapacityByPeriod table.
-----------------------------------------------------------------------------------------
Dependencies:
dbo.CapacityByPeriod (Table) must be in the same database.
-----------------------------------------------------------------------------------------
Usage:
--===== Syntax
SELECT CapacityRemaining FROM dbo.TimeCapacityRemaining(@pSomeTime)
;
--===== Example Usage for 6:42 PM
SELECT CapacityRemaining FROM dbo.TimeCapacityRemaining('18:42')
;
--===== Example Usage using a variable
DECLARE @SomeTime TIME = '18:42';
SELECT CapacityRemaining FROM dbo.TimeCapacityRemaining(@SomeTime)
;
--===== Example Usage when played against a TIME column in a table.
SELECT st.TimeColumn
,cr.CapacityRemaining
FROM dbo.SomeTable st
CROSS APPLY dbo.TimeCapacityRemaining(st.TimeColumn) cr
;
-----------------------------------------------------------------------------------------
Developer Notes:
1. If your DBA(s) object to using functions, tell them that this is a high performance
"iTVF" (Inline Table Value Function) that works as fast as if the code were inline
in a query. If they don't believe you or continue to object just because it's a
function, direct them to Reference #1 below for repeatable and demonstrable proof
that it's not a problem.
2. If they still insist on not letting you use it just because it's a function, thank
them for their time and then recommend to management that they get a smarter DBA.
Before they leave, ask them if they know how to get the current date and time. ;)
3. If the DBA(s) object to the use of "Helper Tables", refer to Note 2 above.
-----------------------------------------------------------------------------------------
References:
1. http://www.sqlservercentral.com/articles/T-SQL/91724/
2. https://www.sqlservercentral.com/Forums/1911664/Calculating-varying-process-capacity
-----------------------------------------------------------------------------------------
Revision History:
Rev 00 - 10 Dec 2017 - Jeff Moden
- Initial creation and unit test according to Reference 2.
****************************************************************************************/
--===== Declare the I/O for this function
(@pSomeTime TIME)
RETURNS TABLE WITH SCHEMABINDING AS
RETURN
--===== Return the remaining capacity for the day using the given time as a starting point.
SELECT CapacityRemaining =
(--=== Aggregate the capacity of the remaining whole periods.
SELECT SUM(PeriodCapacity)
FROM dbo.CapacityByPeriod
WHERE PeriodStartTime >= @pSomeTime
)
+ (--==== Calculate the capacity of time remaining in the current period.
SELECT DATEDIFF(mi,@pSomeTime,PeriodEndTime) * PeriodPerMinuteCapacity
FROM dbo.CapacityByPeriod
WHERE PeriodStartTime <= @pSomeTime AND @pSomeTime < PeriodEndTime
)
;As a bit of a sidebar, the times in the table do NOT need to be at the top of the hour. They can be anytime provided that you pay attention and avoid gaps and overlaps in the table and that the first start time is 00:00 and the last end time is 23:59:59.99999.
Again, this is a situation where you can improve the efficiency by thinking outside of the box. You can cut the number of scans/reads in half. By focusing on the period start time, you are forced to divide your results into two subsets: periods that start after the relevant time and the one period that starts before, but ends after the relevant time. If, instead, you focus on the period end time, you only have one set: periods that end after the relevant time (regardless of whether they start before or after the relevant time).
SELECT SUM(
CASE
WHEN PeriodStartTime <= @pSomeTime
THEN DATEDIFF(mi,@pSomeTime,PeriodEndTime) * PeriodPerMinuteCapacity
ELSE PeriodCapacity
END
) AS Capacity_Remaining
FROM dbo.CapacityByPeriod
WHERE @pSomeTime < PeriodEndTime
;Drew
Heh... remind me not to post code after midnight. Nice job, Drew.
--Jeff Moden
Change is inevitable... Change for the better is not.
December 14, 2017 at 5:32 am
@ Jeff,
Is that midnight your time, my time or SQLServerCentral time :0
December 16, 2017 at 7:18 pm
aaron.reese - Thursday, December 14, 2017 5:32 AM@ Jeff,Is that midnight your time, my time or SQLServerCentral time :0
Dunno anymore. I posted after midnight but the post says I posted at 10:10PM. I check the "local time" on my profile. It's correct. Maybe it's a spurious pip that occurred when I used DBCC TIMEWARP. 😉
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 11 posts - 1 through 10 (of 10 total)
You must be logged in to reply to this topic. Login to reply