Turnaround Time between date & time needed in hours excluding weekends and holidays

dawwni

New Member
Joined
Feb 10, 2023
Messages
19
Office Version
  1. 365
I need to calculate total turn around time between a start date and time and an end start and time. The turnaround time would be reported in total hours between the two and need to exclude weekends and holidays.
Example:
Date ReceivedTime ReceivedDate CompletedTime CompletedTurnaround Time in Hours
1/3/238:261/4/238:26
1/3/2313:151/4/2216:33

Please also clarify the cell formats in order for it to work. Thanks,
 
Okay, the NetWorkDays.INTL function is an inclusive calcuation and not a difference of days. So, it includes the first day in the function So, Tuesday to Wednesday is 2 days, so, I subtracted 1 in the following updated mini worksheet. Toinclude weekends as Fri Sat, Sat instead of doing a enum code you need to use a text string where a 0 counts as a workday and 1 counts as a non workday. So for Fri, Sat, Sun the argument is "0000111".

mr excel questions 12.xlsm
BCDEFGHIJKLM
27Date ReceivedTime ReceivedDate CompletedTime Completedwhole days w adjWhole days in hours w adjhrs decimal w adjcombined w ajdwhole days w no adjwhole days in hrs w no adjhours decimal w no adjTurnaround Time in Hours no adj
28Tue 2023-01-0308:262023-01-0408:26124.000000.000024.00000124.000000.000024.00000
29Tue 2023-01-0313:152023-01-0416:33124.000003.300027.30000124.000003.300027.30000
30Wed 2023-01-0409:302023-01-0514:07124.000004.616728.61667124.000004.616728.61667
31Wed 2023-01-04na2023-01-0809:00124.00000#VALUE!#VALUE!248.00000#VALUE!#VALUE!
32Wed 2023-01-0410:002023-01-0507:0000.0000021.000021.00000124.00000-3.000021.00000
33Wed 2023-01-0420:002023-01-0509:0000.0000013.000013.00000124.00000-11.000013.00000
34Wed 2023-01-0409:002023-01-0413:0000.000004.00004.0000000.000004.00004.00000
35Wed 2023-01-0407:002023-01-0410:0000.000003.00003.0000000.000003.00003.00000
36
37Tue 2023-01-033C37: =NETWORKDAYS.INTL(B37,B40,"0000111")
38Wed 2023-01-042C38: =NETWORKDAYS.INTL(B38,B41,"0000111")
39Thu 2023-01-051C39: =NETWORKDAYS.INTL(B39,B42,"0000111")
40Fri 2023-01-061C40: =NETWORKDAYS.INTL(B40,B43,"0000111")
41Sat 2023-01-072C41: =NETWORKDAYS.INTL(B41,B44,"0000111")
42Sun 2023-01-083C42: =NETWORKDAYS.INTL(B42,B45,"0000111")
43Mon 2023-01-094C43: =NETWORKDAYS.INTL(B43,B46,"0000111")
44Tue 2023-01-103C44: =NETWORKDAYS.INTL(B44,B47,"0000111")
45Wed 2023-01-112C45: =NETWORKDAYS.INTL(B45,B48,"0000111")
46Thu 2023-01-121C46: =NETWORKDAYS.INTL(B46,B49,"0000111")
47Fri 2023-01-131C47: =NETWORKDAYS.INTL(B47,B50,"0000111")
48Sat 2023-01-14
49Sun 2023-01-15
50Mon 2023-01-16
Sheet17
Cell Formulas
RangeFormula
F28:F35F28=NETWORKDAYS.INTL(B28,D28,1,$N$4)-1+IF(C28>E28,-1,0)
G28:G35G28=24*(NETWORKDAYS.INTL(B28,D28,1,$N$4)-1+IF(C28>E28,-1,0))
H28:H35H28=(IF(C28>E28,1,0)+E28-C28)*24
I28:I35I28=24*(NETWORKDAYS.INTL(B28,D28,1,$N$4)-1+IF(C28>E28,-1,0))+(IF(C28>E28,1,0)+E28-C28)*24
J28:J35J28=NETWORKDAYS.INTL(B28,D28,1,$N$4)-1
K28:K35K28=24*(NETWORKDAYS.INTL(B28,D28,1,$N$4)-1)
L28:L35L28=((E28-C28)*24)
M28:M35M28=24*(NETWORKDAYS.INTL(B28,D28,1,$N$4)-1)+((E28-C28)*24)
C37:C47C37=NETWORKDAYS.INTL(B37,B40,"0000111")
D37:D47D37=SUBSTITUTE(CELL("address",C37),"$","")&": "&FORMULATEXT(C37)
B38:B50B38=B37+1
 
Upvote 0

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.
The only delay is the completion time. We dont want to be negatively affected due to the delay when it is out of our control. We can set them up on the same row if that is easier.
 
Upvote 0
The only delay is the completion time. We dont want to be negatively affected due to the delay when it is out of our control. We can set them up on the same row if that is easier.
I'm still not sure on what that means regarding a calculation. Does partial mean that you will not start any work until all the information is ready to be processed?
 
Upvote 0
Yes, that is correct so partials will always have an extended turn around time. Which we want to calculate separately so it doesn't skew the normal turn around times. For example, we get in 50 samples but 5 are partials. We enter two rows for that lot. One normal (45 samples) and one partial (5 samples). We want to calculate the normal turnaround time for the ones we can process right away and the partial's turnaround time using the date/time received for all 50 samples, not when we start the partials. Currently there are two separate rows to distinguish the different processing times but if we need to place them on one row with columns to denote the partial info we can.
 
Upvote 0
Any luck on why it is calculating the extra 24 hours with the first formula? I still haven't figured it out.
 
Upvote 0
I think I figured it out. I removed the 24 at the very begining and with the decimal for hours it works now.
 
Upvote 0
What am I doing wrong? Formula is not calculating correctly.
1679086064606.png
 
Upvote 0
Your image is really tiny. And i can't see your formulas as well, which is what we need to review. Can you post it using the xl2bb add in?
 
Upvote 0
Date ReceivedTime ReceivedDate CompletedTime Completedwhole dayswhole days in hrsTAT HrscombinedHolidays
2023-03-1306:202023-03-1408:2000:0000:0000:0000:00Should be 26 hrs
1/1/2023​
2023-03-1306:202023-03-1408:2200:0000:0000:4800:48Should be 26 hr 2 min
5/29/2023​
2023-03-1306:202023-03-1408:4900:0000:0011:3611:36
7/4/2023​
2023-03-1306:202023-03-1408:2200:0000:0000:4800:48
9/4/2023​
2023-03-1306:202023-03-1408:5000:0000:0012:0012:00
11/23/2023​
2023-03-1306:202023-03-1408:5100:0000:0012:2412:24
11/24/2023​
2023-03-1310:002023-03-1410:1800:0000:0007:1207:12
12/24/2023​
2023-03-1306:202023-03-1408:5100:0000:0012:2412:24
12/25/2023​
2023-03-1310:052023-03-1409:2300:0000:0007:1207:12Formulas
2023-03-1310:052023-03-1409:2300:0000:0007:1207:12Whole Days=NETWORKDAYS.INTL(A2,C2,1,N2:$N9)+IF(B2>D2,-1,0)
2023-03-1309:502023-03-1408:5100:0000:0000:2400:24Whole Days inHrs=24*(NETWORKDAYS.INTL(A2,C2,1,P2:$V9)+IF(B2>D2,-1,0))
2023-03-1414:412023-03-1507:3500:0000:0021:3621:36TAT in Hrs=(IF(B2>D2,1,0)+D2-B2)*24
2023-03-1413:302023-03-1511:2400:0000:0021:3621:36Combined=24*(NETWORKDAYS.INTL(A2,C2,1,P2:$V9)+IF(B2>D2,-1,0))+(IF(B2>D2,1,0)+D2-B2)*24
2023-03-1413:302023-03-1511:2300:0000:0021:1221:12
2023-03-0316:002023-03-0608:0000:0000:0000:0000:00not working at all over a weekend
 
Upvote 0
Try this formula in cell I2. I did not do anything else with the other formulas in the worksheet:

Book1
ABCDEFGHIJKLMN
1Date ReceivedTime ReceivedDate CompletedTime Completedwhole dayswhole days in hrsTAT Hrs (Turn Around Time)combinedCalculated HoursHolidays
2Mon, 2023-03-1306:20Tue, 2023-03-1408:2000:0000:0000:0000:0026:00Should be 26 hrs2023-01-01
3Mon, 2023-03-1306:20Tue, 2023-03-1408:2200:0000:0000:4800:4826:02Should be 26 hr 2 min2023-05-29
4Mon, 2023-03-1306:20Tue, 2023-03-1408:4900:0000:0011:3611:3626:292023-07-04
5Mon, 2023-03-1306:20Tue, 2023-03-1408:2200:0000:0000:4800:4826:022023-09-04
6Mon, 2023-03-1306:20Tue, 2023-03-1408:5000:0000:0012:0012:0026:302023-11-23
7Mon, 2023-03-1306:20Tue, 2023-03-1408:5100:0000:0012:2412:2426:312023-11-24
8Mon, 2023-03-1310:00Tue, 2023-03-1410:1800:0000:0007:1207:1224:182023-12-24
9Mon, 2023-03-1306:20Tue, 2023-03-1408:5100:0000:0012:2412:2426:312023-12-25
10Mon, 2023-03-1310:05Tue, 2023-03-1409:2300:0000:0007:1207:1223:18Formulas
11Mon, 2023-03-1310:05Tue, 2023-03-1409:2300:0000:0007:1207:1223:18Whole Days2
12Mon, 2023-03-1309:50Tue, 2023-03-1408:5100:0000:0000:2400:2423:01Whole Days inHrs48
13Tue, 2023-03-1414:41Wed, 2023-03-1507:3500:0000:0021:3621:3616:54TAT in Hrs2
14Tue, 2023-03-1413:30Wed, 2023-03-1511:2400:0000:0021:3621:3621:54Combined50
15Tue, 2023-03-1413:30Wed, 2023-03-1511:2300:0000:0021:1221:1221:53
16Fri, 2023-03-0316:00Mon, 2023-03-0608:0000:0000:0000:0000:0016:00not working at all over a weekend
Sheet1
Cell Formulas
RangeFormula
L11L11=NETWORKDAYS.INTL(A2,C2,1,N2:$N9)+IF(B2>D2,-1,0)
L12L12=24*(NETWORKDAYS.INTL(A2,C2,1,O2:$U9)+IF(B2>D2,-1,0))
L13L13=(IF(B2>D2,1,0)+D2-B2)*24
L14L14=24*(NETWORKDAYS.INTL(A2,C2,1,O2:$U9)+IF(B2>D2,-1,0))+(IF(B2>D2,1,0)+D2-B2)*24
I2:I16I2=IF(NETWORKDAYS.INTL(A2,C2,1,$N$2:$N$9)-1=0,D2-B2,(NETWORKDAYS.INTL(A2,C2,1,$N$2:$N$9)-1)) +(D2-B2)
 
Upvote 0

Forum statistics

Threads
1,224,827
Messages
6,181,200
Members
453,022
Latest member
RobertV1609

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