Forum Discussion
Calculate number of 8 hour days a date range
- Feb 18, 2023
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)
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)
HansVogelaar 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?
- HansVogelaarMar 03, 2023MVP
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?
- B-unitMar 03, 2023Copper ContributorAh 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?
- HansVogelaarMar 03, 2023MVP
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)