+ Reply to Thread
Results 1 to 4 of 4

Time difference between two dates and times, taking into account working days

  1. #1
    Registered User
    Join Date
    04-21-2009
    Location
    Birmingham, England
    MS-Off Ver
    Excel 2007
    Posts
    42

    Time difference between two dates and times, taking into account working days

    Hi all,

    I've got two columns with the dates and times a case was closed. I need to work out the amount of time that passed between the case being opened and the case being closed, but I also need this to take into account weekends and holidays. At present the formula being used (I've inherited this spreadsheet) is NETWORKDAYS, which works to some extent, but the issue we are having is if a case was logged at 17:50 on 7 March and then closed at 08:30 on 8 March, this returns a value of 2, when really we'd want that to return zero. I need it to count a working day once 24 hours has passed. Is this possible, been trying to work this out for a while but now my head has stopped working.

    Thanks in advance as always

    Jon

  2. #2
    Forum Expert Pepe Le Mokko's Avatar
    Join Date
    05-14-2009
    Location
    Belgium
    MS-Off Ver
    O365 v 2402
    Posts
    13,448

    Re: Time difference between two dates and times, taking into account working days

    Hi
    instead of using the startdate ( say in A1) as is replace it in the networkdays function with =int(A1)+1 and the enddate with =int(A2)-1

  3. #3
    Registered User
    Join Date
    04-21-2009
    Location
    Birmingham, England
    MS-Off Ver
    Excel 2007
    Posts
    42

    Re: Time difference between two dates and times, taking into account working days

    Ah thanks, it's not 100% what I'm after, but I honestly don't think we'll be able to achieve that with formula so it's close enough!

    Thanks again

    Jon

  4. #4
    Forum Expert daddylonglegs's Avatar
    Join Date
    01-14-2006
    Location
    England
    MS-Off Ver
    2016
    Posts
    14,675

    Re: Time difference between two dates and times, taking into account working days

    Quote Originally Posted by Jonsocks View Post
    ....but I honestly don't think we'll be able to achieve that with formula ....
    I think you can.....

    assuming cases are only opened or closed on working days then you can count full days like this

    =NETWORKDAYS(A2,B2,holidays)-1-(MOD(B2,1)<MOD(A2,1))

    for your example that will give zero....and should work in all other circumstances
    Audere est facere

+ 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