SOLVED

Calculate number of 8 hour days a date range

Copper Contributor

Hi, I'm looking to calculate how many days 8 hour days (08:00 - 16:00) there are in a defined period i.e. 20.01.2023, 06:30 to 29.01.2023, 13:30. This is a relativly small period so I can manually 

9 Replies

@B-unit 

Do you want to include or exclude weekend days?

 

And how do you want to count partial days, such as 29.01.2023 in your example (up to 13:30 instead of 16:00)?

@Hans Vogelaar 

 

Thank you for your reply.

 

R.e. weekends I want to include these.

 

R.e. partial days I'd like to count these as a part of a day e.g. 08:00 to 13:30 would be 0.6875 days.

best response confirmed by B-unit (Copper Contributor)
Solution

@B-unit 

With the start date/time in A1 and the end date/time in B1:

 

=LET(startdate, A1, enddate, B1, wholedays, INT(enddate-startdate), newstart, startdate+wholedays, starttime, MIN(MAX(MOD(newstart, 1), TIME(8, 0, 0)), TIME(16, 0, 0)), endtime, MAX(MIN(MOD(enddate, 1), TIME(16, 0, 0)), TIME(8, 0, 0)), partday, MOD(endtime-starttime, TIME(8, 0, 0))/TIME(8,0,0), wholedays+partday)

@Hans Vogelaar 

 

Thank you very much

@Hans Vogelaar I've had to move some cells and the start date is now in cell X1 and the end date in cell Y1. I've tried changing A1 for X1, and B1 for Y1 in the formula but the error "#NAME?" comes up.  Do you know why this may be?

@B-unit 

This doesn't work?

 

=LET(startdate, X1, enddate, Y1, wholedays, INT(enddate-startdate), newstart, startdate+wholedays, starttime, MIN(MAX(MOD(newstart, 1), TIME(8, 0, 0)), TIME(16, 0, 0)), endtime, MAX(MIN(MOD(enddate, 1), TIME(16, 0, 0)), TIME(8, 0, 0)), partday, MOD(endtime-starttime, TIME(8, 0, 0))/TIME(8,0,0), wholedays+partday)

 

Are you using a different version of Excel than before?

Ah maybe. I save the document on my one drive and open it on different machines. one is Excel 2016 and one is Excel for Microsoft 365 MSO. Will this make a differance?

@B-unit 

Yes: the LET function is only available in Excel in Microsoft 365 and Office 2021, not in Office 2019 or earlier versions.

Try this instead:

 

=INT(Y1-X1)+MOD(MAX(MIN(MOD(Y1, 1), TIME(16, 0, 0)), TIME(8, 0, 0))-MIN(MAX(MOD(X1+INT(Y1-X1), 1), TIME(8, 0, 0)), TIME(16, 0, 0)), TIME(8, 0, 0))/TIME(8,0,0)

That's brilliant - it works fine. Thank you very much.
1 best response

Accepted Solutions
best response confirmed by B-unit (Copper Contributor)
Solution

@B-unit 

With the start date/time in A1 and the end date/time in B1:

 

=LET(startdate, A1, enddate, B1, wholedays, INT(enddate-startdate), newstart, startdate+wholedays, starttime, MIN(MAX(MOD(newstart, 1), TIME(8, 0, 0)), TIME(16, 0, 0)), endtime, MAX(MIN(MOD(enddate, 1), TIME(16, 0, 0)), TIME(8, 0, 0)), partday, MOD(endtime-starttime, TIME(8, 0, 0))/TIME(8,0,0), wholedays+partday)

View solution in original post