Need To Get Elapsed Time Between 2 Dates During Working Hours ( All Days Included )

Ahmed101056

New Member
Joined
Nov 15, 2019
Messages
8
Hi

I need to get the elapsed hours between 2 dates considering that working hours is from 8 AM To 4 PM
all days included ( no week ends or holidays )

example :
A1 : 11/11/2019 09:31 AM
B1 : current time { now() } will be used
 

Excel Facts

Will the fill handle fill 1, 2, 3?
Yes! Type 1 in a cell. Hold down Ctrl while you drag the fill handle.
Welcome to the forum!

There are a lot of scenarios, and I haven't tested them all, but give this a try:


Book1
ABCDE
111/7/2019 11:3011/13/2019 9:1521.7511/11/2019
211/28/2019
312/25/2019
Sheet12
Cell Formulas
RangeFormula
C1=IF(INT(B1)-INT(A1)<2,0,NETWORKDAYS(A1+1,B1-1,E1:E3))*8+(1/3-MOD(A1,1)+MOD(B1,1))*24
 
Upvote 0
Welcome to the forum!

There are a lot of scenarios, and I haven't tested them all, but give this a try:

ABCDE
111/7/2019 11:3011/13/2019 9:1521.7511/11/2019
211/28/2019
312/25/2019

<colgroup><col style="width: 25pxpx"><col><col><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Sheet12

Worksheet Formulas
CellFormula
C1=IF(INT(B1)-INT(A1)<2,0,NETWORKDAYS(A1+1,B1-1,E1:E3))*8+(1/3-MOD(A1,1)+MOD(B1,1))*24

<thead>
</thead><tbody>
</tbody>

<tbody>
</tbody>

Thanks Eric for your response
i believe network day function exclude ween ends and i need to include all days in this calculation i dont want to exclude anything only the hours after 4 PM to 7:59 AM
 
Upvote 0
Your original post said "(no week ends or holidays )". If you want to include weekends, try:

=IF(INT(B1)-INT(A1)<2,0,NETWORKDAYS.INTL(A1+1,B1-1,"0000000",E1:E3))*8+(1/3-MOD(A1,1)+MOD(B1,1))*24

If you want to include holidays, remove the range in red.
 
Upvote 0
i may have not been clear enough i meant we have no weekend in this calculation working 365 day per year :LOL:

I've tried both equation and some how they gave me the same result which is far from the real total of working hours elapsed

1.png



2.png
 
Upvote 0
I'm not sure what to tell you - here's my results with the same data:


Book1
ABCD
1Start DateCurrent TimeAll Days CalculatedWeekend Excluded
211/14/19 3:01 PM11/16/2019 1:072.12.1
311/14/19 8:53 PM11/16/2019 1:07-3.76667-3.76667
411/15/19 5:00 AM11/16/2019 1:074.1166674.116667
511/14/19 4:48 PM11/16/2019 1:070.3166670.316667
611/14/19 7:11 PM11/16/2019 1:07-2.06667-2.06667
711/14/19 9:53 AM11/16/2019 1:077.2333337.233333
811/14/19 7:30 PM11/16/2019 1:07-2.38333-2.38333
Sheet12
Cell Formulas
RangeFormula
C2=IF(INT(B2)-INT(A2)<2,0,NETWORKDAYS.INTL(A2+1,B2-1,"0000000"))*8+(1/3-MOD(A2,1)+MOD(B2,1))*24
D2=IF(INT(B2)-INT(A2)<2,0,NETWORKDAYS(A2+1,B2-1))*8+(1/3-MOD(A2,1)+MOD(B2,1))*24


I suspect that there's a regional setting somewhere that's throwing things off, although I don't know what since our dates seem to be the same.

Also, in your examples, most of the start dates are outside of the 8:00 AM - 4:00 PM window. That will definitely throw off the logic I used to calculate the hours. Perhaps if you showed a few examples of times and expected results, it might help.
 
Upvote 0
I'm not sure what to tell you - here's my results with the same data:


I suspect that there's a regional setting somewhere that's throwing things off, although I don't know what since our dates seem to be the same.

Also, in your examples, most of the start dates are outside of the 8:00 AM - 4:00 PM window. That will definitely throw off the logic I used to calculate the hours. Perhaps if you showed a few examples of times and expected results, it might help.

well yea many of the tickets i will work on is already created outside the working hours thats why i need to exclude any time outside " 8:00 AM " to " 4:00 PM "

Example:

First Date
Current TimeShift StartShift End
Elapsed working hours
Comment
11/10/19 1:27 PM
11/16/2019 13:358:00
4:0047:08:00
At 10 nov from 1:27 to 4 PM 2:33 hour and from 11 nov to 15 nov full working hours " 8 hours " 40 hour and on 16 nov fromm 8 AM to 13:35 worth 4:35 hour so the total working hours is 47 hour and 8 minutes

<colgroup><col><col><col><col><col><col></colgroup><tbody>
</tbody>
 
Upvote 0
I've been busy lately and haven't had a chance to work on this much, but try this:

Book1
ABCDEF
1First DateCurrent TimeShift StartShift EndElapsed working hoursComment
211/10/2019 1:27:00 PM11/16/2019 1:35:00 PM8:0016:0047.86666667At 10 nov from 1:27 to 4 PM 2:33 hour and from 11 nov to 15 nov full working hours " 8 hours " 40 hour and on 16 nov fromm 8 AM to 13:35 worth 4:35 hour so the total working hours is 47 hour and 8 minutes
Sheet1
Cell Formulas
RangeFormula
E2E2=(INT(B2)-INT(A2)-1)*8+(D2-MEDIAN(MOD(B2,1),C2,D2)+MEDIAN(MOD(A2,1),C2,D2)-C2)*24


There's probably a better cell format for E2, but I believe the value is correct.
 
Upvote 0
Thank u bro the value is perfect although i cant find suitable formatting but its ok i can deal with the number of hours as it is ??.
 
Upvote 0

Forum statistics

Threads
1,214,516
Messages
6,119,980
Members
448,934
Latest member
audette89

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