I recently encountered an interesting question on the forums the other day. The question was how to determine the average time taken by a single execution of the report provided we know how many times the report ran and the total time taken for all those executions.
The challenge is that the total time taken for all the report executions is a timespan value (datatype TIME in SQL Server). A TIME value cannot be divided by an INTEGER. If we try to do that, we run into an error – an operand clash.
USE [tempdb]; GO DECLARE @timeSpan TIME = '03:18:20'; DECLARE @numberOfExecutions INT = 99; SELECT @timeSpan/@numberOfExecutions; GO
Msg 206, Level 16, State 2, Line 6 Operand type clash: time is incompatible with int
The solution is to realize that a timespan/TIME value is ultimately the number of seconds passed from a given instant. Once the timespan is converted to the appropriate unit (number of seconds), dividing by the number of executions should be quite simple.
Here’s the working example:
USE [tempdb]; GO DECLARE @timeSpan TIME = '03:18:20'; DECLARE @numberOfExecutions INT = 99; SELECT @timeSpan AS TotalActiveTime, DATEDIFF(SECOND,'1900-01-01 00:00:00.000',CAST(@timeSpan AS DATETIME)) AS TotalExecutionTimeInSeconds, DATEDIFF(SECOND,'1900-01-01 00:00:00.000',CAST(@timeSpan AS DATETIME))/(@numberOfExecutions * 1.0) AS TimePerExecution; GO /* RESULTS TotalActiveTime TotalExecutionTimeInSeconds TimePerExecution ---------------- --------------------------- ------------------- 03:18:20.0000000 11900 120.20202020202020 */
I trust this simple thought will help in resolving a business problem someday.
Until we meet next time,
Be courteous. Drive responsibly.
Pingback: #0410 – SQL Server – Dividing a TimeSpan by an Integer to find average time per execution - SSWUG.ORG