How to convert Seconds to HH:MM:SS using T-SQL
You want to multiply out to milliseconds as the fractional part is discarded.
SELECT DATEADD(ms, 121.25 * 1000, 0)
If you want it without the date portion you can use CONVERT, with style 114
SELECT CONVERT(varchar, DATEADD(ms, 121.25 * 1000, 0), 114)
If your time amount exceeds 24 hours it won't be handled correctly with the DATEADD and CONVERT methods.
SELECT CONVERT(varchar, DATEADD(ms, 24*60*60 * 1000, 0), 114)
00:00:00:000
The following function will handle times exceeding 24 hours (~max 35,791,394 hours).
create function [dbo].[ConvertTimeToHHMMSS]
(
@time decimal(28,3),
@unit varchar(20)
)
returns varchar(20)
as
begin
declare @seconds decimal(18,3), @minutes int, @hours int;
if(@unit = 'hour' or @unit = 'hh' )
set @seconds = @time * 60 * 60;
else if(@unit = 'minute' or @unit = 'mi' or @unit = 'n')
set @seconds = @time * 60;
else if(@unit = 'second' or @unit = 'ss' or @unit = 's')
set @seconds = @time;
else set @seconds = 0; -- unknown time units
set @hours = convert(int, @seconds /60 / 60);
set @minutes = convert(int, (@seconds / 60) - (@hours * 60 ));
set @seconds = @seconds % 60;
return
convert(varchar(9), convert(int, @hours)) + ':' +
right('00' + convert(varchar(2), convert(int, @minutes)), 2) + ':' +
right('00' + convert(varchar(6), @seconds), 6)
end
Usage:
select dbo.ConvertTimeToHHMMSS(123, 's')
select dbo.ConvertTimeToHHMMSS(96.999, 'mi')
select dbo.ConvertTimeToHHMMSS(35791394.999, 'hh')
0:02:03.000
1:36:59.940
35791394:59:56.400
For those having issues with using DATEADD and CONVERT for seconds exceeding 24 hours, we can use modulus to get around that:
SELECT CONVERT(varchar, @seconds / 86400 ) + ':' + -- Days
CONVERT(varchar, DATEADD(ms, ( @seconds % 86400 ) * 1000, 0), 114)
as "Converted to D:HH:MM:SS.MS"