December 18, 2017 at 9:14 am
It is right?
CREATE FUNCTION dbo.ufn_DifferenceBetweenDates
(
@Date1 Datetime, -- Dia inicio
@Date2 Datetime -- Dia fin
-- Formato: #d HH:MM:SS
-- Sample:
-- Set dateformat ymd
-- SELECT dbo.ufn_CalcularDiferenciaenHoras('2017-10-01 01:46:00', '2017-10-17 10:45:00')
-- Return: 16d 08:59:00
)
RETURNS VARCHAR(MAX)
AS
BEGIN
DECLARE @OUT VARCHAR(100)
DECLARE @segundos BIGINT
SET @segundos = ( SELECT datediff(SECOND,@Date1, @Date2) ) -- AS Segundos
SET @segundos = ISNULL(@segundos, 0)
SET @OUT ='0d 00:00:00'
IF (@segundos < 0)
RETURN @OUT
SET @OUT = CONVERT(VARCHAR, FLOOR(@segundos / 86400) ) + 'd ' -- days
SET @segundos = @segundos % 86400
SET @OUT = @OUT + Right('0'+ CONVERT(VARCHAR, FLOOR(@segundos / 3600)),2) + ':' -- hours
SET @segundos = @segundos % 3600
SET @OUT = @OUT + Right('0'+ CONVERT(VARCHAR, FLOOR(@segundos / 60)),2) + ':' -- minutes
SET @OUT = @OUT + Right('0'+ CONVERT(VARCHAR, @segundos % 60),2) -- seconds
-------------
RETURN @OUT
-------------
END
GO
December 18, 2017 at 1:44 pm
I would take some benefit of using the integers behind and performance improvement of using an inline table-valued function.
CREATE FUNCTION dbo.ifn_DifferenceBetweenDates
(
@Date1 Datetime, -- Dia inicio
@Date2 Datetime -- Dia fin
-- Formato: #d HH:MM:SS
-- Sample:
-- Set dateformat ymd
-- SELECT *
-- FROM SomeTable st
-- CROSS APPLY dbo.ifn_DifferenceBetweenDates( st.Date1, st.Date2) --Samples '2017-10-01 01:46:00', '2017-10-17 10:45:00'
-- Return: 16d 08:59:00
)
RETURNS TABLE
AS
RETURN
SELECT CONVERT( varchar(10), CONVERT(int, Date2 - Date1)) + 'd ' + CONVERT(char(8), Date2 - Date1, 108) AS DiferenciaenHoras
FROM (SELECT CASE WHEN @Date1 <= @Date2 THEN @Date1 ELSE @Date2 END AS Date1,
CASE WHEN @Date1 <= @Date2 THEN @Date2 ELSE @Date1 END AS Date2)x
GO
December 18, 2017 at 2:24 pm
Luis Cazares - Monday, December 18, 2017 1:44 PMI would take some benefit of using the integers behind and performance improvement of using an inline table-valued function.
CREATE FUNCTION dbo.ifn_DifferenceBetweenDates
(
@Date1 Datetime, -- Dia inicio
@Date2 Datetime -- Dia fin
-- Formato: #d HH:MM:SS
-- Sample:
-- Set dateformat ymd
-- SELECT *
-- FROM SomeTable st
-- CROSS APPLY dbo.ifn_DifferenceBetweenDates( st.Date1, st.Date2) --Samples '2017-10-01 01:46:00', '2017-10-17 10:45:00'
-- Return: 16d 08:59:00
)
RETURNS TABLE
AS
RETURN
SELECT CONVERT( varchar(10), CONVERT(int, Date2 - Date1)) + 'd ' + CONVERT(char(8), Date2 - Date1, 108) AS DiferenciaenHoras
FROM (SELECT CASE WHEN @Date1 <= @Date2 THEN @Date1 ELSE @Date2 END AS Date1,
CASE WHEN @Date1 <= @Date2 THEN @Date2 ELSE @Date1 END AS Date2)xGO
+1000. It also avoids returning a short string as a MAX blob not to mention avoiding a scalar function.
Ah... sorry. Found the same error in it that Scott did.
--Jeff Moden
Change is inevitable... Change for the better is not.
December 19, 2017 at 8:28 am
Below is alternative method that's closer to the original technique (for good or ill). Btw, there's a minor bug in the other code that doesn't reduce the day count if the first date has a later time than the second date.
SELECT *
FROM (VALUES
('2017-10-01 10:46:00', '2017-10-17 01:45:00'),
('2017-10-17 10:46:00', '2017-10-01 01:45:00')
) dates(date1,date2)
CROSS APPLY dbo.ifn_DifferenceBetweenDates( date1, date2 )
CROSS APPLY dbo.ufn_DifferenceBetweenDates2 ( date1, date2 )
CREATE FUNCTION dbo.ufn_DifferenceBetweenDates2
(
@Date1 datetime, --Dia inicio
@Date2 datetime --Dia fin
)
RETURNS TABLE
AS
RETURN (
SELECT CAST(CAST(dias AS varchar(5)) + 'd ' +
CONVERT(varchar(8), DATEADD(SECOND, segundos, 0) , 8) AS varchar(16)) AS DiferenciaenHoras
FROM (
SELECT CASE WHEN @Date1 > @Date2 THEN 0 ELSE DATEDIFF(SECOND, @Date1, @Date2) / (60*60*24) END AS dias,
CASE WHEN @Date1 > @Date2 THEN 0 ELSE DATEDIFF(SECOND, @Date1, @Date2) % (60*60*24) END AS segundos
) AS cálculos
)
GO
SQL DBA,SQL Server MVP(07, 08, 09) "It's a dog-eat-dog world, and I'm wearing Milk-Bone underwear." "Norm", on "Cheers". Also from "Cheers", from "Carla": "You need to know 3 things about Tortelli men: Tortelli men draw women like flies; Tortelli men treat women like flies; Tortelli men's brains are in their flies".
December 19, 2017 at 9:56 pm
ScottPletcher - Tuesday, December 19, 2017 8:28 AMBelow is alternative method that's closer to the original technique (for good or ill). Btw, there's a minor bug in the other code that doesn't reduce the day count if the first date has a later time than the second date.SELECT *
FROM (VALUES
('2017-10-01 10:46:00', '2017-10-17 01:45:00'),
('2017-10-17 10:46:00', '2017-10-01 01:45:00')
) dates(date1,date2)
CROSS APPLY dbo.ifn_DifferenceBetweenDates( date1, date2 )
CROSS APPLY dbo.ufn_DifferenceBetweenDates2 ( date1, date2 )
CREATE FUNCTION dbo.ufn_DifferenceBetweenDates2
(
@Date1 datetime, --Dia inicio
@Date2 datetime --Dia fin
)
RETURNS TABLE
AS
RETURN (
SELECT CAST(CAST(dias AS varchar(5)) + 'd ' +
CONVERT(varchar(8), DATEADD(SECOND, segundos, 0) , 8) AS varchar(16)) AS DiferenciaenHoras
FROM (
SELECT CASE WHEN @Date1 > @Date2 THEN 0 ELSE DATEDIFF(SECOND, @Date1, @Date2) / (60*60*24) END AS dias,
CASE WHEN @Date1 > @Date2 THEN 0 ELSE DATEDIFF(SECOND, @Date1, @Date2) % (60*60*24) END AS segundos
) AS cálculos
)
GO
Your method is prone to the limits of DATEDIFF(SECOND, which results in the following error...
Msg 535, Level 16, State 0, Line 8
The datediff function resulted in an overflow. The number of dateparts separating two date/time instances is too large. Try to use datediff with a less precise datepart.
The maximum period that can be resolved by DATEDIFF(SECONDS is "only" 68 years, 1 month, 19 days, and 03:14:07.000.
Since this is a 2016 forum, you could use the new DATEDIFF_BIG function that they created to cover up the mistakes they made with not allowing direct datetime math for the DATE and DATETIME2 datatypes.
--Jeff Moden
Change is inevitable... Change for the better is not.
December 19, 2017 at 11:10 pm
Itzik Ben-Gan has a function...
http://www.itprotoday.com/microsoft-sql-server/how-compute-date-and-time-difference-parts
December 22, 2017 at 3:00 pm
robinson.netdevelop - Monday, December 18, 2017 9:14 AMIt is right?CREATE FUNCTION dbo.ufn_DifferenceBetweenDates
(
@Date1 Datetime, -- Dia inicio
@Date2 Datetime -- Dia fin
-- Formato: #d HH:MM:SS
-- Sample:
-- Set dateformat ymd
-- SELECT dbo.ufn_CalcularDiferenciaenHoras('2017-10-01 01:46:00', '2017-10-17 10:45:00')
-- Return: 16d 08:59:00
)
RETURNS VARCHAR(MAX)
AS
BEGIN
DECLARE @OUT VARCHAR(100)
DECLARE @segundos BIGINT
SET @segundos = ( SELECT datediff(SECOND,@Date1, @Date2) ) -- AS Segundos
SET @segundos = ISNULL(@segundos, 0)
SET @OUT ='0d 00:00:00'
IF (@segundos < 0)
RETURN @OUT
SET @OUT = CONVERT(VARCHAR, FLOOR(@segundos / 86400) ) + 'd ' -- days
SET @segundos = @segundos % 86400
SET @OUT = @OUT + Right('0'+ CONVERT(VARCHAR, FLOOR(@segundos / 3600)),2) + ':' -- hours
SET @segundos = @segundos % 3600
SET @OUT = @OUT + Right('0'+ CONVERT(VARCHAR, FLOOR(@segundos / 60)),2) + ':' -- minutes
SET @OUT = @OUT + Right('0'+ CONVERT(VARCHAR, @segundos % 60),2) -- seconds-------------
RETURN @OUT
-------------
ENDGO
Just a couple of recommendations...
First, avoid using VARCHAR(MAX) for returns that will never be more than just 18 characters. It'll help with memory requirements and make your scalar function a touch faster.
Second, I personally don't like the use of "Hungarian Notation" to include the object type in the name of the object. It's normally not necessary but I also understand if you have to follow some company spec that requires you to do so.
Third, you should name variables either for what the actually contain or what they'll be used for instead of generalizing them as just Date1 and Date2 and then having to add comments to let everyone know what they are.
Last but not least, scalar functions like this ten to be about 7 times slower than necessary. There is another method, which will be covered in the second bit of code below. First, here's how I'd write your scalar function if I had to follow a "Hungarian Notation" naming convention. It's similar to what other people have done on this thread but has a much broader range (1 second less than 10,000 years) and it handles problems like the one Scott pointed out.
CREATE FUNCTION dbo.ufn_DifferenceBetweenDates
/**********************************************************************************************************************
Purpose:
Given two dates/times, return the formatted span of time represented by the two dates in the form of #d hh:mi:ss to a
max of 18 characters where "#" is the number of days and will be some value from -2958463 thru 2958463.
-----------------------------------------------------------------------------------------------------------------------
Usage Examples:
--===== Inputs in ascending temporal order left to right.
SELECT dbo.ufn_DifferenceBetweenDates('2017-10-01 01:46:01', '2017-10-17 10:45:00');
Returns: 16d 08:58:59
--===== Inputs in descending temporal order left to right.
SELECT dbo.ufn_DifferenceBetweenDates('2017-10-17 10:45:00','2017-10-01 01:46:01');
Returns: -16d 08:58:59
-----------------------------------------------------------------------------------------------------------------------
1. Note that this is a Scalar function and will be ~7 times slower than an iTVF (Inline Table Value Function).
2. Note that the maximum span that can be returned by this function is 1 second less than 10,000 years of days
or 2958463d 23:59:59 or -2958463d 23:59:59.
3. RETURN type is VARCHAR(18)
4. This function works in all versions of SQL Server from 2000 to current.
-----------------------------------------------------------------------------------------------------------------------
Revision History:
Rev 00 - 22 Dec 2017 - Jeff Moden
- Inital creation and unit test.
- Ref: https://www.sqlservercentral.com/Forums/FindPost1913258.aspx
**********************************************************************************************************************/
--===== Declare the I/O for this scalar function.
(
@StartDT DATETIME
,@EndDT DATETIME
)
RETURNS VARCHAR(18)
AS
BEGIN
RETURN CASE --Calculate and format the span according to the given format depending on the direction of the inputs.
WHEN @StartDT <= @EndDT
THEN CONVERT(VARCHAR(8), DATEDIFF(dd,0,@EndDT-@StartDT)) +'d ' + CONVERT(CHAR(8),@EndDT-@StartDT,108)
ELSE CONVERT(VARCHAR(8),-DATEDIFF(dd,0,@StartDT-@EndDT)) +'d ' + CONVERT(CHAR(8),@StartDT-@EndDT,108)
END
;
END
;
GO
Last but not least, Scalar functions are ~7 times slower than an "iSF" or "Inline Scalar Value Function", which don't currently exist in SQL Server. We can, however, fake it using a "single cell" iTVF or "Inline Table Value Function". It needs to be called in a slightly different fashion but it's well worth it for performance. Here's the code as I would write it without "Hungarian Notation" and includes different usage examples.
CREATE FUNCTION dbo.DifferenceBetweenDates
/**********************************************************************************************************************
Purpose:
Given two dates/times in the correct left to right order, return a formatted period represented by the two dates in
the form of #d hh:mi:ss (or -#d hh:mi:ss) to a max of 18 characters where "#" will be some value from -2958463 thru
2958463, which is only 1 day short of a day-span of 10,000 years.
-----------------------------------------------------------------------------------------------------------------------
Usage Examples:
--===== Basic Syntax for Single Period
SELECT Span FROM dbo.DifferenceBetweenDates(@StartDT,@EndDT)
;
--===== Basic Syntax for Multiple Rows from a Table.
SELECT ca.Span
,st.SomeColumns
FROM dbo.SomeTable st
CROSS APPLY dbo.DifferenceBetweenDates(st.StartDT,st.EndDT) ca
;
-----------------------------------------------------------------------------------------------------------------------
Developer notes:
1. This is a high performance iTVF (inline Table Valued Function), which executes about 7 times faster than the
equivalent Scalar function. Please see the following URL for more information on this subject.
http://www.sqlservercentral.com/articles/T-SQL/91724/
2. Note that the maximum span that can be returned by this function is 1 second less than 10,000 years of days
or 2958463d 23:59:59 (when @StartDate <= @EndDate) or -2958463d 23:59:59 (when @StartDate > @EndDate).
3. RETURN type is VARCHAR(18)
4. This function works in all versions of SQL Server from 2000 to current.
-----------------------------------------------------------------------------------------------------------------------
Revision History:
Rev 00 - 22 Dec 2017 - Jeff Moden
- Inital creation and unit test.
- Ref: https://www.sqlservercentral.com/Forums/FindPost1913258.aspx
**********************************************************************************************************************/
--===== Define the I/O for this function
(
@StartDT DATETIME
,@EndDT DATETIME
)
RETURNS TABLE WITH SCHEMABINDING AS
RETURN
--===== Calculate format, and return the period as a "single cell" table depending on the direction of the inputs.
SELECT Span = CASE
WHEN @StartDT <= @EndDT
THEN CONVERT(VARCHAR(8), DATEDIFF(dd,0,@EndDT-@StartDT)) +'d ' + CONVERT(CHAR(8),@EndDT-@StartDT,108)
ELSE CONVERT(VARCHAR(8),-DATEDIFF(dd,0,@StartDT-@EndDT)) +'d ' + CONVERT(CHAR(8),@StartDT-@EndDT,108)
END
;
GO
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply