• DateDiff and DateAdd have the tendency to round to whatever the "date part" is and, despite what many folks think, shouldn't be used to calculate what the difference between full dates and times are. Instead, simple subtraction should be used. For example...

    --===== Declare a couple of test variables to hold test data

    DECLARE @DateStart DATETIME

    DECLARE @DateEnd DATETIME

    --===== Preset the test variables with test data

    SELECT @DateStart = '02/Nov/06 9:14:21 AM',

    @DateEnd = '19/Apr/07 11:52:31 AM'

    --===== Calculate and display the difference of date/time between

    -- the two test variables

    SELECT @DateEnd-@DateStart AS [Difference between dates]

    Difference between dates

    ------------------------------------------------------

    1900-06-18 02:38:10.000

    (1 row(s) affected)

    Of course, the problem with that is that we're displaying the difference using SQL Server's default format. It's hard for people to look at that and say "Hmmmm... that's 6 months, 18 days, 2 hours, 38 minutes, and 10 seconds difference. The code did the trick in calculating correctly, it's just not displayed in a manner easily understood by humans.

    Teaching a man to fish... you're gonna have to trust me on this... Books On Line says that the underlying datatype for DATETIME is actually two integers that represent the number of days since 1900-01-01 00:00:00.000 AM (also known as "day zero"). DATETIMEs most correctly convert to FLOAT for math purposes. Just as in any type of math, half a day (12 noon, 1/2 of a day) would be represented by the decimal value of .5000000 and 6PM (3/4 of a day) would be represented by .75. So, in reality, the DATETIME datatype keeps track of the "Number of decimal fractional days". Midnight on 1900-01-02 would have the value of 1.000000 and noon on 1900-01-02 would have the value of 1.5...

    ... you with me, so far? Ok... back to the mathematical difference between dates and times...

    Let's see what happens if we convert the difference between @DateStart and @DateEnd using some simpler date/times so we can follow along in our heads... and lets display the difference as the number of fractional days instead of letting SQL Server have it's way with us...

    --===== Declare a couple of test variables to hold test data

    DECLARE @DateStart DATETIME

    DECLARE @DateEnd DATETIME

    --===== Preset the test variables with test data

    SELECT @DateStart = '2000-01-01 00:00:00 AM', --Midnight

    @DateEnd = '2000-01-02 12:00:00 PM' --Noon the next day

    --===== Calculate and display the difference of date/time between

    -- the two test variables as a floating point number

    SELECT CAST(@DateEnd-@DateStart AS FLOAT)

    In our heads, we can see that if we start at midnight on one day and go to noon the next day, that's a day and a half or 1.5... kinda proves what I've been saying so far. How can we format that for human consumption?

    I'm going to show you how, but you have to understand a couple of things...

    1. This type of formatting should be done in the GUI... repeat after me... "THIS TYPE OF FORMATTING SHOULD BE DONE IN THE GUI". The reason why is because the GUI is better at it, allows for local date/time display settings to come into play, and keeps SQL Server from spending extra clock cycles for formatting (distributed computing... let the client spend the clock cycles instead of the server). If there is no GUI to do the formatting (ie, you're outputing to a file), then the formatting can be done in SQL Server.

    2. Formatted date/times must never ever be stored in the database. Go ahead... get it into your head now... repeat it over and over. "FORMATTED DATE/TIMES MUST NEVER EVER BE STORED IN THE DATABASE." Stop and think about it... if we store the formatted differences in time in the database, we'll need to spend more clock cycles unformatting (changing back to DATETIME) to do any further calculations like adding up the individual differences to get a "total duration". It's like taking drugs... "Just say NO".

    Promise yourself that you'll obey the two rules above... they will make you a much better SQL Developer than you'll know. They are two base rules to doing things right in any form of SQL.

    Ok, back to your problems... Depending on what your requirements are, there are several ways to format a difference between dates/times (also known as "DeltaT" which is what I'll call it from now on). Let's assume that you want to display in the following format... ddddd DAYS(s) hh:mi:ss. In the example above, we'll need to display the whole portion of the number 1.5 as "1 DAY(s)"... and, we'll need to display the decimal portion as time as "12:00:00".

    We'll do this in pieces and then put it all together...

    For formatting the number of days, we need to take the following steps.

    1. Calculate the DeltaT

    2. Convert the DeltaT to FLOAT

    3. Use only the whole day portion being careful to not round up

    4. Convert the whole day portion to a character datatype so we can concatenate it to the word "DAY(s)". We also need to right justify the number so displays of other DeltaTs will line up for easy reading.

    5. Concatenate the result with the word "DAY(S)"

    Sounds really complicated, but it's simple, short, and can be done using a single formula...

    --===== Declare a couple of test variables to hold test data

    DECLARE @DateStart DATETIME

    DECLARE @DateEnd DATETIME

    --===== Preset the test variables with test data

    SELECT @DateStart = '2000-01-01 00:00:00 AM', --Midnight

    @DateEnd = '2000-01-02 12:00:00 PM' --Noon the next day

    --===== Calculate and display the difference in days

    SELECT STR(FLOOR(CAST(@DateEnd-@DateStart AS FLOAT)),5) + ' DAY(s)'

    Here's what the different pieces of code do... like any good math problem, we start from the inside parenthesis...

    1. Calculate the DeltaT

    @DateEnd-@DateStart

    2. Convert the DeltaT to FLOAT (using CAST)

    CAST(@DateEnd-@DateStart AS FLOAT)

    3. Use only the whole day portion being careful to not round up (using FLOOR)

    FLOOR(CAST(@DateEnd-@DateStart AS FLOAT))

    4. Convert the whole day portion to a character datatype so we can concatenate it to the word "DAY(s)". We also need to right justify the number so displays of other DeltaTs will line up for easy reading. (using STR for 5 characters, does the right justify, too!)

    STR(FLOOR(CAST(@DateEnd-@DateStart AS FLOAT)),5)

    5. Concatenate the result with the word "DAY(S)"

    STR(FLOOR(CAST(@DateEnd-@DateStart AS FLOAT)),5) + ' DAY(s) '

    That wasn't so bad, was it?

    Ok, now for the time portion... this is easy...

    1. Calculate the DeltaT

    2. Convert the DeltaT to FLOAT

    3. Use only the decimal portion (ie. fraction day or TIME) being careful not to round

    4. Convert the decimal portion to something that looks like a TIME and to a character datatype so we can concatenate it to days display we just calculated. We also need to right justify the time displays of other DeltaTs will line up for easy reading.

    Again, this is simple, short, and can be done using a single formula...

    --===== Declare a couple of test variables to hold test data

    DECLARE @DateStart DATETIME

    DECLARE @DateEnd DATETIME

    --===== Preset the test variables with test data

    SELECT @DateStart = '2000-01-01 00:00:00 AM', --Midnight

    @DateEnd = '2000-01-02 12:00:00 PM' --Noon the next day

    --===== Calculate and display the TIME

    SELECT CONVERT(CHAR(8),@DateEnd-@DateStart,108)

    Here's what the different pieces of code do...

    1. Calculate the DeltaT

    @DateEnd-@DateStart

    2. Convert the DeltaT to FLOAT

    Step not actually needed because we're using the instrinsic date functions of SQL Server to do this.

    3. Use only the decimal portion (ie. fraction day or TIME) being careful not to round

    Again, this step not actually needed because we're using the instrinsic date functions of SQL Server to do this.

    4. Convert the decimal portion to something that looks like a TIME and to a character datatype so we can concatenate it to days display we just calculated. We also need to right justify the time displays of other DeltaTs will line up for easy reading. (using CONVERT)

    CONVERT(CHAR(8),@DateEnd-@DateStart,108)

    Heh... guess step 4 takes a bit more explanation... CONVERT is the command to do steps 2, 3, 4. The CHAR(8) is the data type that we want the result to be (8 characters to hold the 8 character format of hh:mi:ss). The 108 is the format number I got from Books Online (lookup CONVERT) that will give me the hh:mi:ss format in 24 hour time. Since the 108 format only deals with the time portion of the DeltaT, theres no need to convert to FLOAT and no need to strip of the number of whole days.

    Ok... now, using the lessons we just learned, put it all together...

    --===== Declare a couple of test variables to hold test data

    DECLARE @DateStart DATETIME

    DECLARE @DateEnd DATETIME

    --===== Preset the test variables with test data

    SELECT @DateStart = '2000-01-01 00:00:00 AM', --Midnight

    @DateEnd = '2000-01-02 12:00:00 PM' --Noon the next day

    --===== Calculate and display the DeltaT in the (ddddd DAY(s) hh:mi:ss) format

    SELECT STR(FLOOR(CAST(@DateEnd-@DateStart AS FLOAT)),5) + ' DAY(s) '

    + CONVERT(CHAR(8),@DateEnd-@DateStart,108)

    You can just change the values for @DateStart and @DateEnd and your first two problems are solved. Pretty easy, huh?

    Again, don't even think about storing that garbage result in a perfectly good database... this type of stuff (formatting) is for display purposes only.

    The same method will work for your third problem... and I'm going to let you do it because I think this is homework and you need to try it on your own. I will give you a couple of hints though...

    1. Calculate two DeltaT's... 1 for problem 1 and 1 for problem 2

    2. Add the two DeltaT's together

    3. Format the result

    I know this is a bit long winded, but I saw the opportunity to teach someone something instead of just plopping a code answer out there. You have a bit of study to do to figure out what the individual functions like STR and CONVERT are actually capable of. And, if you have any questions that whose answers aren't in Books Online, feel free to post back.

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)