SLA Calculator - Difference between 2 dates, incorporating work hours

inshesweet

New Member
Joined
Aug 23, 2018
Messages
2
Hi all. I'm attempting to work out the difference between two date and times.
Scenario: I work in IT and 'm an SLA manager. I've been tasked with finding SLA compliance between incidents raised and initial incident response. Normally this would be fairly simple, however the SLA 'clock' only applies when the service desk are in operation, and this is what's throwing me. Could I kindly ask if someone could assist me with the correct formula.

Problem statement is;
What is the difference in hours and minutes between two dates, incorporating
NETWORK DAYS (Mon-Fri)
NETWORK HOURS (7:30am-5:30pm)

Sample data
Issue TypeKeySummaryIncident createdIncident Initial
Response
SD Start TimeSD End TimeDifference
IncidentITSD-1234Issue withLicense ServerFri 3/08/2018Mon 6/08/20187:3017:30
IncidentITSD-5678Issue with desktop outlook accessMon 6/08/2018Mon 6/08/20187:3017:30
IncidentITSD-4561Unable to reach SAPThu 2/08/2018Wed 8/08/20187:3017:30
IncidentITSD-3213Replace Waste toner SDSThu 2/08/2018Thu 2/08/20187:3017:30
IncidentITSD-7898Account LockedTue 31/07/2018Thu 9/08/20187:3017:30
IncidentITSD-9512Unable to fully access G: foldersFri 22/06/2018Sat 18/08/20187:3017:30
IncidentITSD-5465Network/Power OutageFri 4/05/2018Sun 19/08/20187:3017:30

<tbody>
</tbody>

<tbody>
</tbody>
 

Excel Facts

What is =ROMAN(40) in Excel?
The Roman numeral for 40 is XL. Bill "MrExcel" Jelen's 40th book was called MrExcel XL.
Hi,

I spent many hours on this myself. As you don't have varying start & end times based on days you can do it with a formula.

Points to note

rHols is a list of holiday dates and that list give the range name rHols.

0.7292 and 0.3125 are the decimal values for 5:30pm and 7:30am

Code:
=IF(B3="","",IF(A3=B3,0.0007,(NETWORKDAYS(A3,B3,[B]rHols[/B])-1)+MOD(B3,1)-MOD(A3,1)-((MOD(A3,1)>=MOD(B3,1))*(1-[B]0.7292[/B]+[B]0.3125[/B]))))

StartEndDuration
01/08/2018 17:0002/08/2018 09:4500 02:45
20/08/2018 09:4528/08/2018 12:0005 02:15

<colgroup><col span="2"><col></colgroup><tbody>
</tbody>


rHols sample list
01/01/2018
27/08/2018
25/12/2018
26/12/2018

<colgroup><col></colgroup><tbody>
</tbody>


Feel free to shout if you need more help as I know your pain.
 
Last edited:
Upvote 0
Thanks Ray, every time I think i'm getting better with excel, I get slung a problem like this and I realise how little I know. Your formula worked a treat!!!!! I'm floored/wowed/awed.

Thank you very much

Hi,

I spent many hours on this myself. As you don't have varying start & end times based on days you can do it with a formula.

Points to note

rHols is a list of holiday dates and that list give the range name rHols.

0.7292 and 0.3125 are the decimal values for 5:30pm and 7:30am

Code:
=IF(B3="","",IF(A3=B3,0.0007,(NETWORKDAYS(A3,B3,[B]rHols[/B])-1)+MOD(B3,1)-MOD(A3,1)-((MOD(A3,1)>=MOD(B3,1))*(1-[B]0.7292[/B]+[B]0.3125[/B]))))

StartEndDuration
01/08/2018 17:0002/08/2018 09:4500 02:45
20/08/2018 09:4528/08/2018 12:0005 02:15

<tbody>
</tbody>


rHols sample list
01/01/2018
27/08/2018
25/12/2018
26/12/2018

<tbody>
</tbody>


Feel free to shout if you need more help as I know your pain.
 
Upvote 0
Not a problem, glad I could help. Been at this programming lark over 30 years and still learning.

Cheers

Ray
 
Upvote 0

Forum statistics

Threads
1,215,336
Messages
6,124,330
Members
449,155
Latest member
ravioli44

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