Help Calculating Difference Between Dates But only Counting times within certain hours

Tlund

New Member
Joined
Sep 22, 2008
Messages
8
Hello,

I need to calculate the hours and minutes we respond to something but only counting the hours and minutes that fall within 08:00 to 17:00 Monday through Friday.

Example - if we received a call at 09:00 06/01/11 but did not arrive until 10:00 6/2/11 hour 'covered' hours are only from 08:00 to 17:00 so our response would be 11 hours.

Is there a way to put this into a formula? Also, there is no coverage on Saturday or Sunday so they would need to excluded completely.

the information is in 2 different cells

<TABLE style="WIDTH: 193pt; BORDER-COLLAPSE: collapse" border=0 cellSpacing=0 cellPadding=0 width=257 x:str><COLGROUP><COL style="WIDTH: 97pt; mso-width-source: userset; mso-width-alt: 4717" width=129><COL style="WIDTH: 96pt; mso-width-source: userset; mso-width-alt: 4681" width=128><TBODY><TR style="HEIGHT: 39pt; mso-height-source: userset" height=52><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; WIDTH: 97pt; HEIGHT: 39pt; BORDER-TOP: windowtext 0.5pt solid; BORDER-RIGHT: windowtext 0.5pt solid" class=xl26 height=52 width=129>Created</TD><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; WIDTH: 96pt; BORDER-TOP: windowtext 0.5pt solid; BORDER-RIGHT: windowtext 0.5pt solid" class=xl26 width=128>Onsite Arrival</TD></TR><TR style="HEIGHT: 25.5pt; mso-height-source: userset" height=34><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; HEIGHT: 25.5pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" class=xl27 height=34 x:num="40632.707638888889">30-Mar-11 16:59</TD><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" class=xl27 x:num="40633.423611111109">31-Mar-11 10:10</TD></TR></TBODY></TABLE>
 

Excel Facts

Last used cell?
Press Ctrl+End to move to what Excel thinks is the last used cell.
I'm sure one of our formula wizards will eventually show up and put me to shame. But this appears to work in testing.

<!-- Please do not remove this header --><!-- Table easily created from Excel with ASAP Utilities (http://www.asap-utilities.com) --><TABLE border=1 cellSpacing=0 borderColor=#c0c0c0 borderColorDark=#ffffff><TBODY><TR><TD style="WHITE-SPACE: nowrap" bgColor=#4f81bd height=25 vAlign=bottom width=148>Created</TD><TD style="WHITE-SPACE: nowrap" bgColor=#4f81bd height=25 vAlign=bottom width=146>Arrived</TD><TD style="WHITE-SPACE: nowrap" bgColor=#4f81bd height=25 vAlign=bottom width=121>Elapsed</TD></TR><TR><TD style="WHITE-SPACE: nowrap" bgColor=#dbe5f1 height=25 vAlign=bottom width=148 align=middle>Sat 26-Mar-11 13:00</TD><TD style="WHITE-SPACE: nowrap" bgColor=#dbe5f1 height=25 vAlign=bottom width=146 align=middle>Mon 28-Mar-11 10:00</TD><TD style="WHITE-SPACE: nowrap" bgColor=#dbe5f1 height=25 vAlign=bottom width=121 align=right>02:00</TD></TR><TR><TD style="WHITE-SPACE: nowrap" bgColor=#ffffff height=25 vAlign=bottom width=148 align=middle>Wed 01-Jun-11 09:00</TD><TD style="WHITE-SPACE: nowrap" bgColor=#ffffff height=25 vAlign=bottom width=146 align=middle>Thu 02-Jun-11 10:00</TD><TD style="WHITE-SPACE: nowrap" bgColor=#ffffff height=25 vAlign=bottom width=121 align=right>10:00</TD></TR><TR><TD style="WHITE-SPACE: nowrap" bgColor=#dbe5f1 height=25 vAlign=bottom width=148 align=middle>Wed 01-Jun-11 08:00</TD><TD style="WHITE-SPACE: nowrap" bgColor=#dbe5f1 height=25 vAlign=bottom width=146 align=middle>Wed 01-Jun-11 17:00</TD><TD style="WHITE-SPACE: nowrap" bgColor=#dbe5f1 height=25 vAlign=bottom width=121 align=right>09:00</TD></TR><TR><TD style="WHITE-SPACE: nowrap" bgColor=#ffffff height=25 vAlign=bottom width=148 align=middle>Wed 01-Jun-11 06:00</TD><TD style="WHITE-SPACE: nowrap" bgColor=#ffffff height=25 vAlign=bottom width=146 align=middle>Wed 01-Jun-11 10:00</TD><TD style="WHITE-SPACE: nowrap" bgColor=#ffffff height=25 vAlign=bottom width=121 align=right>02:00</TD></TR><TR><TD style="WHITE-SPACE: nowrap" bgColor=#dbe5f1 height=25 vAlign=bottom width=148 align=middle>Fri 01-Jul-11 08:00</TD><TD style="WHITE-SPACE: nowrap" bgColor=#dbe5f1 height=25 vAlign=bottom width=146 align=middle>Tue 05-Jul-11 10:00</TD><TD style="WHITE-SPACE: nowrap" bgColor=#dbe5f1 height=25 vAlign=bottom width=121 align=right>11:00</TD></TR><TR><TD style="WHITE-SPACE: nowrap" bgColor=#ffffff height=25 vAlign=bottom width=148 align=middle>Wed 01-Jun-11 20:00</TD><TD style="WHITE-SPACE: nowrap" bgColor=#ffffff height=25 vAlign=bottom width=146 align=middle>Thu 02-Jun-11 13:00</TD><TD style="WHITE-SPACE: nowrap" bgColor=#ffffff height=25 vAlign=bottom width=121 align=right>05:00</TD></TR><TR><TD style="WHITE-SPACE: nowrap" bgColor=#dbe5f1 height=25 vAlign=bottom width=148 align=middle>Wed 01-Jun-11 20:00</TD><TD style="WHITE-SPACE: nowrap" bgColor=#dbe5f1 height=25 vAlign=bottom width=146 align=middle>Thu 02-Jun-11 13:00</TD><TD style="WHITE-SPACE: nowrap" bgColor=#dbe5f1 height=25 vAlign=bottom width=121 align=right>05:00</TD></TR><TR><TD style="WHITE-SPACE: nowrap" bgColor=#ffffff height=25 vAlign=bottom width=148 align=middle>Sat 02-Jul-11 02:00</TD><TD style="WHITE-SPACE: nowrap" bgColor=#ffffff height=25 vAlign=bottom width=146 align=middle>Tue 05-Jul-11 10:00</TD><TD style="WHITE-SPACE: nowrap" bgColor=#ffffff height=25 vAlign=bottom width=121 align=right>02:00</TD></TR></TBODY></TABLE>

Formula in C2 & copied down is:<?xml:namespace prefix = o ns = "urn:schemas-microsoft-com:office:office" /><o:p></o:p>
<o:p></o:p>
=(NETWORKDAYS(A2,B2)-2+(WEEKDAY(A2,2)>5))*TIME(9,0,0)+(TIME(17,0,0)-MIN(MAX((A2-INT(A2)),TIME(8,0,0)),TIME(17,0,0)))*(WEEKDAY(A2,2)<6)+B2-INT(B2)-TIME(8,0,0)<o:p></o:p>
<o:p></o:p>
 
Last edited:
Upvote 0
Greg,

I think you forgot to add the formula view!!!!! :biggrin:

I'm interested to see how this is solved as well, I couldn't get it to work without creating 100000+ if statements!
 
Upvote 0
Sorry, as I was editing to put in the formula, my ISP decided to have one of its frequent little hissy fits and I couldn't post for about five minutes. :rolleyes:
 
Upvote 0
Meant to add - by using the Networkdays function, one should be able to define a range of holidays to exclude, but I didn't take the testing that far.

<SUP>edit</SUP> I just tried it with a holiday and it appears to handle it well, though I'd test it a bit more were I going to try and using the holidays functionality in NETWORKDAYS(). <SUB>/edit</SUB>
 
Last edited:
Upvote 0
Need a little more info to go on than "can't make it work"...

Did you edit all of the cell references to point to the appropriate cells on your worksheet?
 
Upvote 0
Greg,

I copied my date information into columns A and B on a new sheet and then pasted your formula into column C.


this is my results
<TABLE style="WIDTH: 728pt; BORDER-COLLAPSE: collapse" border=0 cellSpacing=0 cellPadding=0 width=970 x:str><COLGROUP><COL style="WIDTH: 97pt; mso-width-source: userset; mso-width-alt: 4717" width=129><COL style="WIDTH: 96pt; mso-width-source: userset; mso-width-alt: 4681" width=128><COL style="WIDTH: 535pt; mso-width-source: userset; mso-width-alt: 26075" width=713><TBODY><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; WIDTH: 97pt; HEIGHT: 12.75pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" id=td_post_2777409 class=xl22 height=17 width=129 x:num="40639.430555555555"><TABLE style="WIDTH: 321pt; BORDER-COLLAPSE: collapse" border=0 cellSpacing=0 cellPadding=0 width=427 x:str><COLGROUP><COL style="WIDTH: 97pt; mso-width-source: userset; mso-width-alt: 4717" width=129><COL style="WIDTH: 96pt; mso-width-source: userset; mso-width-alt: 4681" width=128><COL style="WIDTH: 128pt; mso-width-source: userset; mso-width-alt: 6217" width=170><TBODY><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; WIDTH: 97pt; HEIGHT: 12.75pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" id=td_post_2777409 class=xl24 height=17 width=129 x:num="40639.430555555555">06-Apr-11 10:20</TD><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; WIDTH: 96pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" class=xl24 width=128 x:num="40647.451388888891">14-Apr-11 10:50</TD><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; WIDTH: 128pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" width=170 align=middle x:err="#NAME?">#NAME?</TD></TR></TBODY></TABLE></TD><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; WIDTH: 96pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" class=xl22 width=128 x:num="40647.451388888891"></TD><TD style="BORDER-BOTTOM: #f0f0f0; BORDER-LEFT: #f0f0f0; BACKGROUND-COLOR: transparent; WIDTH: 535pt; BORDER-TOP: #f0f0f0; BORDER-RIGHT: #f0f0f0" width=713 align=middle x:err="#NAME?"></TD></TR></TBODY></TABLE>
Terri
 
Upvote 0
What version of Excel are you using? Around here we pretty much assume Excel 2010 or 2007 unless otherwise specified.
 
Upvote 0
Greg,

I did not think of that. My company uses 2003. Would that make a difference?

thanks

Terri
 
Upvote 0

Forum statistics

Threads
1,223,228
Messages
6,170,875
Members
452,363
Latest member
merico17

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