calculating time over several days

lopezid1

New Member
Joined
May 30, 2021
Messages
2
Office Version
  1. 2019
Platform
  1. Windows
Hello, so I need help with a task that I am trying to set up. Im trying to calculate elapsed time on projects.

Example: I have start date 4/29/21 @ 12:22 pm END DATE 5/1/21 @ 9:21 AM

WORK HOURS MON- FRI ( EVERY OTHER SATURDAY) 7:00 AM - 3:45 PM

The formula I am using which I was able to get from here is:

=(networkdays(s,e)-1)*("15:45"-"7:00")+if(networkdays(e,e),median(mod(e,1),"15:45","7:00"),"15:45")-median(networkdays(s,s)*mod(s,1),"15:45","7:00")

but I would like to include every other Saturday . So how can I do that? Your help is greatly appreciated. thank you.
 

Excel Facts

Highlight Duplicates
Home, Conditional Formatting, Highlight Cells, Duplicate records, OK to add pink formatting to any duplicates in selected range.
I would personally use NETWORKDAYS.INTL with a Sunday only weekend (option 11), then list the Saturdays that shouldn't be included as holidays.
 
Upvote 0
I would personally use NETWORKDAYS.INTL with a Sunday only weekend (option 11), then list the Saturdays that shouldn't be included as holidays.
OK thank you, would you please be so kind as to give me an example using the networkdays.intl formula? Thank you so much for your help.
 
Upvote 0
Using your formula as a reference it would be something like this, where h refers to a list of holidays, i.e. the Saturdays to be excluded.

=(networkdays.intl(s,e,11,h)-1)*("15:45"-"7:00")+if(networkdays.intl(e,e,11,h),median(mod(e,1),"15:45","7:00"),"15:45")-median(networkdays.intl(s,s,11,h)*mod(s,1),"15:45","7:00")

How you create the list of excluded Saturdays is down to preference. Personally, (with your version of excel) I would list them in a hidden sheet by entering the date of the earliest Saturday to exclude in A1, then entering =A1+14 into A2 and filling that down as far as A52 (enough to cover 2 years).
Others may do it with named ranges, or additional functions within the formula (less efficient, more complicated, and potential for errors if not done properly).
 
Upvote 0

Forum statistics

Threads
1,214,788
Messages
6,121,582
Members
449,039
Latest member
Arbind kumar

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top