+ Reply to Thread
Results 1 to 12 of 12

A challenge, Serious help requested

  1. #1
    Registered User
    Join Date
    09-25-2004
    Posts
    7

    A challenge, Serious help requested

    I would like to show the HRS AWAY for each day when a departure and return time are shown. There are times when 2 departure/return times are shown in a one week period. I have not been able to show HRS AWAY for days that are more than 2 days apart or cover multiple departure/return times. I have an example below which shows how this is set up. I hope someone can help with this one.

    Thanks

    Travel Time.txt

  2. #2
    MartinW
    Guest

    Re: A challenge, Serious help requested

    Hi 4844,

    Your link to excelforum failed.

    To calc your time away you just need to subtract the time and dates
    as follows.

    A1 : Departure date and time
    B1 : Return date and time

    In C1 put the formula =(B1-A1)*24 and format the cell as general.

    HTH
    Martin



  3. #3
    Sandy Mann
    Guest

    Re: A challenge, Serious help requested

    With your table in A1:D8 try:

    =IF(C2="",24,C2*24)-IF(B2="",0,B2*24)

    to return each day's away hours

    --
    HTH

    Sandy
    In Perth, the ancient capital of Scotland

    [email protected]
    [email protected] with @tiscali.co.uk


    "dps9460" <[email protected]> wrote in
    message news:[email protected]...
    >
    > I would like to show the HRS AWAY for each day when a departure and
    > return time are shown. There are times when 2 departure/return times
    > are shown in a one week period. I have not been able to show HRS AWAY
    > for days that are more than 2 days apart or cover multiple
    > departure/return times. I have an example below which shows how this is
    > set up. I hope someone can help with this one.
    >
    > Thanks
    >
    > 4844
    >
    >
    > +-------------------------------------------------------------------+
    > |Filename: Travel Time.txt |
    > |Download: http://www.excelforum.com/attachment.php?postid=4844 |
    > +-------------------------------------------------------------------+
    >
    > --
    > dps9460
    > ------------------------------------------------------------------------
    > dps9460's Profile:
    > http://www.excelforum.com/member.php...o&userid=14725
    > View this thread: http://www.excelforum.com/showthread...hreadid=548056
    >




  4. #4
    Forum Expert Ron Coderre's Avatar
    Join Date
    03-22-2005
    Location
    Boston, Massachusetts
    MS-Off Ver
    2013, 2016, O365
    Posts
    6,996
    dps9460

    Regarding your attached table (which isn't accessible on the Excel newsgroups, by the way):

    Day Dep Arr Hrs_away
    SUN 8:00 A 16
    MON 24
    TUE 24
    WED 6:00 P 18
    THUR 8:00 A 16
    FRI 24
    SAT 9:00 P 21

    Try this....
    With your data in A1:C8
    D2: =IF(B2<>"",1-B2,IF(C2<>"",C2,1))*24
    Copy that formula down as far as you need

    Does that help?

    Regards,
    Ron

  5. #5
    Sandy Mann
    Guest

    Re: A challenge, Serious help requested

    Ron that works as long as there is only one entry in that row. If there is
    a Dep and Arr time for the same day then it is as if the Arr time was not
    there.

    --
    Regards

    Sandy
    In Perth, the ancient capital of Scotland

    [email protected]
    [email protected] with @tiscali.co.uk


    "Ron Coderre" <[email protected]>
    wrote in message
    news:[email protected]...
    >
    > dps9460
    >
    > Regarding your attached table (which isn't accessible on the Excel
    > newsgroups, by the way):
    >
    > Day Dep Arr Hrs_away
    > SUN 8:00 A 16
    > MON 24
    > TUE 24
    > WED 6:00 P 18
    > THUR 8:00 A 16
    > FRI 24
    > SAT 9:00 P 21
    >
    > Try this....
    > With your data in A1:C8
    > D2: =IF(B2<>"",1-B2,IF(C2<>"",C2,1))*24
    > Copy that formula down as far as you need
    >
    > Does that help?
    >
    > Regards,
    > Ron
    >
    >
    > --
    > Ron Coderre
    > ------------------------------------------------------------------------
    > Ron Coderre's Profile:
    > http://www.excelforum.com/member.php...o&userid=21419
    > View this thread: http://www.excelforum.com/showthread...hreadid=548056
    >




  6. #6
    Sandy Mann
    Guest

    Re: A challenge, Serious help requested

    If you have any days when you are not away then you would have to enter 12
    AM in both the Departed & Returned columns, (or remove the formula)

    If you want the Hours Away to be time rather than decimal hours then use:

    =(IF(C2="",24,C2*24)-IF(B2="",0,B2*24))/24

    and custom format the column as [h]:mm

    --
    HTH

    Sandy
    In Perth, the ancient capital of Scotland

    [email protected]
    [email protected] with @tiscali.co.uk


    "Sandy Mann" <[email protected]> wrote in message
    news:[email protected]...
    > With your table in A1:D8 try:
    >
    > =IF(C2="",24,C2*24)-IF(B2="",0,B2*24)
    >
    > to return each day's away hours
    >
    > --
    > HTH
    >
    > Sandy
    > In Perth, the ancient capital of Scotland
    >
    > [email protected]
    > [email protected] with @tiscali.co.uk
    >
    >
    > "dps9460" <[email protected]> wrote in
    > message news:[email protected]...
    >>
    >> I would like to show the HRS AWAY for each day when a departure and
    >> return time are shown. There are times when 2 departure/return times
    >> are shown in a one week period. I have not been able to show HRS AWAY
    >> for days that are more than 2 days apart or cover multiple
    >> departure/return times. I have an example below which shows how this is
    >> set up. I hope someone can help with this one.
    >>
    >> Thanks
    >>
    >> 4844
    >>
    >>
    >> +-------------------------------------------------------------------+
    >> |Filename: Travel Time.txt |
    >> |Download: http://www.excelforum.com/attachment.php?postid=4844 |
    >> +-------------------------------------------------------------------+
    >>
    >> --
    >> dps9460
    >> ------------------------------------------------------------------------
    >> dps9460's Profile:
    >> http://www.excelforum.com/member.php...o&userid=14725
    >> View this thread:
    >> http://www.excelforum.com/showthread...hreadid=548056
    >>

    >
    >




  7. #7
    Registered User
    Join Date
    09-25-2004
    Posts
    7
    Quote Originally Posted by dps9460
    I would like to show the HRS AWAY for each day when a departure and return time are shown. There are times when 2 departure/return times are shown in a one week period. I have not been able to show HRS AWAY for days that are more than 2 days apart or cover multiple departure/return times. I have an example below which shows how this is set up. I hope someone can help with this one.

    Thanks

    Attachment 4844

    thanks for the replies everyone

    But what if there is a day with no travel. No departure no arrival, there should not be any time in the time away column. I been working with some of the formulas you all suggested and they are close to what I'm looking for. Somehow the departure has to be associated with the arrival time and then fill in all the time away columns from the departure through the arrival time to include the days in between.

    Thanks

  8. #8
    Forum Expert Ron Coderre's Avatar
    Join Date
    03-22-2005
    Location
    Boston, Massachusetts
    MS-Off Ver
    2013, 2016, O365
    Posts
    6,996
    dps9460:

    See if this gets you where you want to be.

    I wrapped Sandy's formula within this:
    D2: =IF(AND(ISBLANK(C2),MAX((C$2:C2>0)*ROW(C$2:C2))>=MAX((B$2:B2>0)*ROW(B$2:B2))),0,IF(C2="",24,C2*24)-IF(B2="",0,B2*24))

    Here's the logic

    If there's a departure time with no return time: Calc the time
    If there's a departure time and a return time: Calc the net time
    If there's a return time with no departure time: Calc the time
    If both cells are blank and the last departure has NOT returned: 24 hours
    If both cells are blank and the last departure HAS returned: Zero hours

    Does that help?

    Regards,
    Ron

  9. #9
    Sandy Mann
    Guest

    Re: A challenge, Serious help requested

    I follow your logic Ron but unfortunately it now returns 0 for all days when
    there is no Departure or Return time. I would suggest the formula that I
    posted originally:

    =IF(C2="",24,C2*24)-IF(B2="",0,B2*24)

    in D2 and

    =IF(AND(COUNT($B$2:B3)=COUNT($C$2:C3),COUNT(B3:C3)=0),"",IF(C3="",24,C3*24)-IF(B3="",0,B3*24))

    in D3 and copied down as far as necessary.


    --
    HTH

    Sandy
    In Perth, the ancient capital of Scotland

    [email protected]
    [email protected] with @tiscali.co.uk


    "Ron Coderre" <[email protected]>
    wrote in message
    news:[email protected]...
    >
    > dps9460:
    >
    > See if this gets you where you want to be.
    >
    > I wrapped Sandy's formula within this:
    > D2:
    > =IF(AND(ISBLANK(C2),MAX((C$2:C2>0)*ROW(C$2:C2))>=MAX((B$2:B2>0)*ROW(B$2:B2))),0,IF(C2="",24,C2*24)-IF(B2="",0,B2*24))
    >
    > Here's the logic
    >
    > If there's a departure time with no return time: Calc the time
    > If there's a departure time and a return time: Calc the net time
    > If there's a return time with no departure time: Calc the time
    > If both cells are blank and the last departure has NOT returned: 24
    > hours
    > If both cells are blank and the last departure HAS returned: Zero
    > hours
    >
    > Does that help?
    >
    > Regards,
    > Ron
    >
    >
    > --
    > Ron Coderre
    > ------------------------------------------------------------------------
    > Ron Coderre's Profile:
    > http://www.excelforum.com/member.php...o&userid=21419
    > View this thread: http://www.excelforum.com/showthread...hreadid=548056
    >




  10. #10
    Forum Expert Ron Coderre's Avatar
    Join Date
    03-22-2005
    Location
    Boston, Massachusetts
    MS-Off Ver
    2013, 2016, O365
    Posts
    6,996
    True, Sandy....I failed to mention that the formula I posted is an ARRAY FORMULA*.

    Your previously posted formula always calculates 24 hours when both cells are blank.

    I believe this formula satisfies the OP's requirements:
    =IF(AND(ISBLANK(C2),MAX((C$2:C2>0)*ROW(C$2:C2))>=MAX((B$2:B2>0)*ROW(B$2:B2))),0,IF(C2="",24,C2*24)-IF(B2="",0,B2*24))

    That array formula only calculates times for the trip duration, ignoring blank cells where no trip is in progress.

    (thanks for spotting the mispost)

    Regards,
    Ron

    *Note: For array formulas, hold down [Ctrl] and [Shift] when you press [Enter], instead of just pressing [Enter].

  11. #11
    Registered User
    Join Date
    09-25-2004
    Posts
    7

    Talking A challenge, Serious help requested

    Thank you both for all the help. Sandy's formula did exactly what I was looking for. I can now move on to easier problems.



    Thanks again
    Dave

  12. #12
    Sandy Mann
    Guest

    Re: A challenge, Serious help requested

    Hi Ron,

    > True, Sandy....I failed to mention that the formula I posted is an ARRAY
    > FORMULA*.


    Yes your use or ROW() should have alerted me to that fact.

    > Your previously posted formula always calculates 24 hours when both
    > cells are blank.


    If you mean the first formula I posted then yes that's right. My last
    formula however does the same as yours with the exception that it returns ""
    when there is no trip taking place.


    --
    HTH

    Sandy
    In Perth, the ancient capital of Scotland

    [email protected]
    [email protected] with @tiscali.co.uk


    "Ron Coderre" <[email protected]>
    wrote in message
    news:[email protected]...
    >
    > True, Sandy....I failed to mention that the formula I posted is an ARRAY
    > FORMULA*.
    >
    > Your previously posted formula always calculates 24 hours when both
    > cells are blank.
    >
    > I believe this formula satisfies the OP's requirements:
    > =IF(AND(ISBLANK(C2),MAX((C$2:C2>0)*ROW(C$2:C2))>=MAX((B$2:B2>0)*ROW(B$2:B2))),0,IF(C2="",24,C2*24)-IF(B2="",0,B2*24))
    >
    > That array formula only calculates times for the trip duration,
    > ignoring blank cells where no trip is in progress.
    >
    > (thanks for spotting the mispost)
    >
    > Regards,
    > Ron
    >
    > *Note: For array formulas, hold down [Ctrl] and [Shift] when you press
    > [Enter], instead of just pressing [Enter].
    >
    >
    > --
    > Ron Coderre
    > ------------------------------------------------------------------------
    > Ron Coderre's Profile:
    > http://www.excelforum.com/member.php...o&userid=21419
    > View this thread: http://www.excelforum.com/showthread...hreadid=548056
    >




+ 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