+ Reply to Thread
Results 1 to 5 of 5

Time Calculations:initially looking

  1. #1
    Jai_Friday
    Guest

    Time Calculations:initially looking

    How can you calculate times??

    Initially looking through the help file it shows the following function

    =TEXT(H1-I1,"h:mm")

    which calculates the diffence in hours and minutes between two times, however

    if the values are 00:09:00 and 00:10:00 it won't calculate it give a #VALUE
    if the values are 00:10:00 and 00:09:00 it will calculate

    What am I doing wrong

    Thanks in advance

    Jai

  2. #2
    JE McGimpsey
    Guest

    re: Time Calculations:initially looking

    IF you're using the WinXL default 1900 date system, you can't display
    negative times, so TEXT() returns the #VALUE! error.

    If you use the 1904 date system (Tools/Options/Calculation...) you can
    display negative times using TEXT().

    NOTE that TEXT() is not necessary, you can use

    =H1-I1

    by itself, then use

    Format/Cell/Number/Custom h:mm

    to display the result in the way you want.


    In article <AFBCB055-C5B9-4DCE-95C4-F45581AE26C3@microsoft.com>,
    Jai_Friday <JaiFriday@discussions.microsoft.com> wrote:

    > How can you calculate times??
    >
    > Initially looking through the help file it shows the following function
    >
    > =TEXT(H1-I1,"h:mm")
    >
    > which calculates the diffence in hours and minutes between two times, however
    >
    > if the values are 00:09:00 and 00:10:00 it won't calculate it give a #VALUE
    > if the values are 00:10:00 and 00:09:00 it will calculate
    >
    > What am I doing wrong
    >
    > Thanks in advance
    >
    > Jai


  3. #3
    Rob Hick
    Guest

    re: Time Calculations:initially looking

    Dates and times in excel are stored as numbers - the date part being an
    integer and the time part being a decimal (enter a date and time in
    excel and the n change the formatting to number ot see an example).

    The TEXT function simply converts a number to a string based on the
    format you supply. So what your function is actually doing is simply
    taking one number from another and then returning the result as a
    string formatted as h:mm.

    When you put the earlier time before the later time, the result will be
    negative, since the decimal increases through the day (0.25 = 06:00,
    0.5 = 12:00 etc). So the reason it returns an error is because you are
    asking it to format a negative number as h:mm, which
    as far as it is concerned is nonsense.

    So the trick is to return the ABSOLUTE difference between the times,
    then it won't matter whether you put the earlier time first of second
    (assuming that is what you want to do). You can acheive this using the
    ABS function, e.g.:

    =TEXT(ABS(H1-I1),"h:mm")

    Personally, I think that format is a bit confusing so I'd play around
    with something like:

    =TEXT(ABS(H1-I1),"h ""hours"", m ""minutes""")

    The double quotes allow you to enter whatever text you like.

    Rob



    Jai_Friday wrote:
    > How can you calculate times??
    >
    > Initially looking through the help file it shows the following function
    >
    > =TEXT(H1-I1,"h:mm")
    >
    > which calculates the diffence in hours and minutes between two times, however
    >
    > if the values are 00:09:00 and 00:10:00 it won't calculate it give a #VALUE
    > if the values are 00:10:00 and 00:09:00 it will calculate
    >
    > What am I doing wrong
    >
    > Thanks in advance
    >
    > Jai



  4. #4
    JE McGimpsey
    Guest

    re: Time Calculations:initially looking

    Note that it's only nonsense using the 1900 Date system. It works fine
    in the 1904 system...


    In article <1153152994.439478.303060@m73g2000cwd.googlegroups.com>,
    "Rob Hick" <rob.hick@nbs.nhs.uk> wrote:

    > So the reason it returns an error is because you are
    > asking it to format a negative number as h:mm, which
    > as far as it is concerned is nonsense.


  5. #5
    Rob Hick
    Guest

    re: Time Calculations:initially looking


    JE McGimpsey wrote:
    > Note that it's only nonsense using the 1900 Date system. It works fine
    > in the 1904 system...


    I didn't realise that - thanks. I still prefer the solution where it
    doesn't matter which setting is chosen; changing settings to make
    things work has a tendency to come round later and bite you on the ***!



    >
    > In article <1153152994.439478.303060@m73g2000cwd.googlegroups.com>,
    > "Rob Hick" <rob.hick@nbs.nhs.uk> wrote:
    >
    > > So the reason it returns an error is because you are
    > > asking it to format a negative number as h:mm, which
    > > as far as it is concerned is nonsense.



+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1