Error Checking in Excel
Thanks Thanks:  0
Likes Likes:  0
Results 1 to 6 of 6

Thread: Calculating working hours between 2 dates

  1. #1
    Guest

    Default

    I wish to calculate how many WORKING hours between 2 dates. The ricky bit is I want it to also disregard weekends and ideally bank holidays. eg 10/02/02 09:00 and 14/02/02 10:00 (where 11th and 12 are Sat/Sun), I want it to come back with 9 hours.

  2. #2
    MrExcel MVP Aladin Akyurek's Avatar
    Join Date
    Feb 2002
    Location
    The Hague, NL
    Posts
    83,657
    Post Thanks / Like
    Mentioned
    33 Post(s)
    Tagged
    6 Thread(s)

    Default

    On 2002-02-23 03:31, Anonymous wrote:
    I wish to calculate how many WORKING hours between 2 dates. The ricky bit is I want it to also disregard weekends and ideally bank holidays. eg 10/02/02 09:00 and 14/02/02 10:00 (where 11th and 12 are Sat/Sun), I want it to come back with 9 hours.
    Just curious: How did you compute 9 hours?


  3. #3
    Guest

    Default

    Sorry.....I knew what I meant.....8 working hours a day (9 till 5 is 8 hours)and in my example i quoted till 10am the next working day i.e. 8 hours plus 1 hour the next day. Basically, if I use networkdays function I get a result of 1, where as I want to know the number of hours, not days! I need the calculation to take weekends out of the result.

  4. #4
    MrExcel MVP
    Join Date
    Feb 2002
    Location
    Denver, CO
    Posts
    1,743
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    Edited:

    =IF(NETWORKDAYS(A1,B1)>2,(NETWORKDAYS(A1,B1)-2)*8+(("17:00"-MOD(A1,1))+(MOD(B1,1)-"9:00"))*24,IF(INT(A1)=INT(B1),(B1-A1)*24,(("17:00"-MOD(A1,1))+(MOD(B1,1)-"9:00"))*24))
    to allow for correct calc on same day.

    Original
    =IF(NETWORKDAYS(A1,B1)>2,(NETWORKDAYS(A1,B1)-2)*8+(("17:00"-MOD(A1,1))+(MOD(B1,1)-"9:00"))*24,(("17:00"-MOD(A1,1))+(MOD(B1,1)-"9:00"))*24)

    do the trick?
    start time date is A1, end time date is B1.


    On 2002-02-23 07:42, Anonymous wrote:
    Sorry.....I knew what I meant.....8 working hours a day (9 till 5 is 8 hours)and in my example i quoted till 10am the next working day i.e. 8 hours plus 1 hour the next day. Basically, if I use networkdays function I get a result of 1, where as I want to know the number of hours, not days! I need the calculation to take weekends out of the result.
    [ This Message was edited by: IML on 2002-02-23 09:55 ]

  5. #5
    Guest

    Default

    Fantastic!! Many thanks for your help. Works a treat! (how come you know how to do this?)

  6. #6
    MrExcel MVP
    Join Date
    Feb 2002
    Location
    Denver, CO
    Posts
    1,743
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    I'm glad it works for you. As for why I know how, that's a good question. I think it all goes back to reading a Mark W. posting for probably the 100th time that he said excel stores time as a fraction of a day (1 = 24 hours). Once you understand that and the odd formats that sometime pop up, a farily simply formual can usually solve the problem. By the way, if you need this formula to show true time, just divide it by 24 with a [h]:mm format

Some videos you may like

User Tag List

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

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