Calculating TAT

virgan

Board Regular
Joined
Jan 29, 2009
Messages
86
I have some activities that needs to be done ina specified time

Like for example

<TABLE style="WIDTH: 96pt; BORDER-COLLAPSE: collapse" cellSpacing=0 cellPadding=0 width=128 border=0 x:str><COLGROUP><COL style="WIDTH: 48pt" span=2 width=64><TBODY><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; WIDTH: 48pt; BORDER-BOTTOM: #ece9d8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent" width=64 height=17>TAT HRS</TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; WIDTH: 48pt; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent" width=64>hrs</TD></TR><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent" height=17>ACT 1</TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent" align=right x:num>4</TD></TR><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent" height=17>ACT 2</TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent" align=right x:num>8</TD></TR><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent" height=17>ACT 3</TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent" align=right x:num>24</TD></TR><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent" height=17>ACT 4</TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent" align=right x:num>2</TD></TR><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent" height=17>ACT 5</TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent" align=right x:num>4</TD></TR></TBODY></TABLE>

And i have a sheet where in i need to calculate turn around time

<TABLE style="WIDTH: 192pt; BORDER-COLLAPSE: collapse" cellSpacing=0 cellPadding=0 width=256 border=0 x:str><COLGROUP><COL style="WIDTH: 48pt" span=4 width=64><TBODY><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; WIDTH: 48pt; BORDER-BOTTOM: #ece9d8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent" width=64 height=17>Activity</TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; WIDTH: 48pt; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent" width=64>Start time</TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; WIDTH: 48pt; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent" width=64>End time</TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; WIDTH: 48pt; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent" width=64>TAT</TD></TR><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent" height=17>ACT 1</TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent"></TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent"></TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent"></TD></TR><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent" height=17>ACT 2</TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent"></TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent"></TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent"></TD></TR><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent" height=17>ACT 3</TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent"></TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent"></TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent"></TD></TR><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent" height=17>ACT 4</TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent"></TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent"></TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent"></TD></TR><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent" height=17>ACT 5</TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent"></TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent"></TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent"></TD></TR></TBODY></TABLE>


Based on time entered in start time and end time the TAT column should calculate the TAT based on the above standards.

I also would liuke to exclude weekends(Saturday, sunday). Also the TAT should only be calculated during working hrs between 7:30 PM to 4:30 AM.

Can any one help me with this..
 

Excel Facts

Spell Check in Excel
Press F7 to start spell check in Excel. Be careful, by default, Excel does not check Capitalized Werds (whoops)
Presumably start time and end time will also include dates? Do you really mean 7:30 PM to 04:30 AM, so on Friday that would take you in to Saturday morning?

Assuming that the start and end times are always within working hours try this formula in C2 to get TAT

=NETWORKDAYS(A2-0.25,B2-0.25)*9-9+(MOD(B2-0.25,1)-MOD(A2-0.25,1))*24

Format C2 as number

where A2 is start time/date and B2 is end time/date
 
Upvote 0
The start time and end time will also have date along with time. Will this work in this case as well..
 
Upvote 0
Yes, the version I posted assumes time and date in one cell. You can do it also with time and date in separate cells but you'd need to alter the formula a little then.......
 
Upvote 0
Also i checked this formula. Would be able to explain a bit more as how you are including the actual TAT which i have mentioned in table 1 in calculating the TAT in table 2.

like say for example

Table 1 in sheet 1

<TABLE style="WIDTH: 96pt; BORDER-COLLAPSE: collapse" cellSpacing=0 cellPadding=0 width=128 border=0 x:str><TBODY><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; WIDTH: 48pt; BORDER-TOP-COLOR: #ece9d8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8" width=64 height=17>TAT </TD><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; WIDTH: 48pt; BORDER-TOP-COLOR: #ece9d8; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8" width=64> hrs</TD></TR><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8" height=17>ACT 1</TD><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8" align=right x:num>4</TD></TR><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8" height=17>ACT 2</TD><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8" align=right x:num>8</TD></TR><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8" height=17>ACT 3</TD><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8" align=right x:num>24</TD></TR><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8" height=17>ACT 4</TD><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8" align=right x:num>2</TD></TR><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8" height=17>ACT 5</TD><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8" align=right x:num>4</TD></TR></TBODY></TABLE>

Table 2 in sheet 2

A B C D
<TABLE style="WIDTH: 192pt; BORDER-COLLAPSE: collapse" cellSpacing=0 cellPadding=0 width=256 border=0 x:str><TBODY><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; WIDTH: 48pt; BORDER-TOP-COLOR: #ece9d8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8" width=64 height=17>Activity</TD><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; WIDTH: 48pt; BORDER-TOP-COLOR: #ece9d8; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8" width=64>Start time</TD><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; WIDTH: 48pt; BORDER-TOP-COLOR: #ece9d8; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8" width=64>End time</TD><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; WIDTH: 48pt; BORDER-TOP-COLOR: #ece9d8; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8" width=64>TAT</TD></TR><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8" height=17>ACT 1</TD><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8"></TD><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8"></TD><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8"></TD></TR><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8" height=17>ACT 2</TD><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8"></TD><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8"></TD><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8"></TD></TR><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8" height=17>ACT 3</TD><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8"></TD><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8"></TD><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8"></TD></TR><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8" height=17>ACT 4</TD><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8"></TD><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8"></TD><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8"></TD></TR><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-LEFT-COLOR: #ece9d8; BORDER-BOTTOM-COLOR: #ece9d8; BORDER-TOP-COLOR: #ece9d8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent; BORDER-RIGHT-COLOR: #ece9d8" height=17>ACT 5</TD></TR></TBODY></TABLE>


The entries in B and C will look like the below

<TABLE style="WIDTH: 226pt; BORDER-COLLAPSE: collapse" cellSpacing=0 cellPadding=0 width=300 border=0 x:str><COLGROUP><COL style="WIDTH: 48pt" width=64><COL style="WIDTH: 65pt; mso-width-source: userset; mso-width-alt: 3145" span=2 width=86><COL style="WIDTH: 48pt" width=64><TBODY><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; WIDTH: 48pt; BORDER-BOTTOM: #ece9d8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent" width=64 height=17>Activity</TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; WIDTH: 65pt; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent" width=86>Start Time</TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; WIDTH: 65pt; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent" width=86>End time</TD><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; WIDTH: 48pt; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent" width=64>TAT</TD></TR><TR style="HEIGHT: 12.75pt" height=17><TD style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent" height=17>ACT 1</TD><TD class=xl25 style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent" align=right x:num="39890.875">3/18/09 21:00</TD><TD class=xl25 style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent" align=right x:num="39891.916666666664">3/19/09 22:00</TD><TD class=xl24 style="BORDER-RIGHT: #ece9d8; BORDER-TOP: #ece9d8; BORDER-LEFT: #ece9d8; BORDER-BOTTOM: #ece9d8; BACKGROUND-COLOR: transparent"></TD></TR></TBODY></TABLE>
 
Upvote 0
The formula I posted just calculates the hours. I assume you want to look up the hours for ACT 1 (4) and see whether the actual hours are inside that figure or not?

If your "TAT" table is in sheet 1 A2:B6 then you can use a VLOOKUP to find whether TAT is met or not, see below

Formula in D2 copied down

=NETWORKDAYS(B2-0.25,C2-0.25)*9-9+(MOD(C2-0.25,1)-MOD(B2-0.25,1))*24

Formula in E2 copied down

=IF(D2>VLOOKUP(A2,Sheet1!A$2:B$6,2,0),"Failed","Met")
Book1
ABCDEF
1ActivityStarttimeEndtimeHoursTAT
2ACT13/18/200921:003/19/200922:0010.00Failed
3ACT23/18/200921:003/19/200919:007.00Met
4ACT33/18/200921:003/19/200922:0010.00Met
5
Sheet2
 
Upvote 0
Wil this exclude"Saturday's and sunday's" and will it only take the shift timings.

For example the TAT should only be calculated for time between

5:30 PM till 5:30 AM in weeddays!!!!

And no weekends at all....
 
Upvote 0
You said in your first post that the hours were 7:30 PM to 4:30 AM, are they variable?

The formula I posted will calculate hours between those times, assuming your start and end times are always within those hours. Because your "day" goes through midnight I assumed that you would want to count Friday as 7:30 PM on Friday to 4:30 AM on Saturday, which is on a weekend, do you want to include those hours or not?

If you now want to change to count hours between 5:30 PM and 05:30 AM then you need to change the formula to this:

=NETWORKDAYS(B2-0.25,C2-0.25)*12-12+(MOD(C2-0.25,1)-MOD(B2-0.25,1))*24

This will count hours up until 5:30 AM on Saturdays as explained above but no other hours until 5:30 PM on Monday, is that the requirement?

If so I suggest you test the formula above with some sample times and dates to see if it calculates the way you think it should........
 
Upvote 0
Hi

Im sorry for the late responce. I tried using the above formula but it do not seem to work.

The cell where i use the formula returns the value #NAME?

Please hlp...
 
Upvote 0
Are you using the exact formula I posted?

Make sure you have Analysis ToolPak installed [Tools > add-ins > tick "Analysis ToolPak"]

If you have a non-English version of Excel you may need to translate NETWORKDAYS function into the correct language, because Excel won't translate Analysis ToolPak functions automatically
 
Upvote 0

Forum statistics

Threads
1,214,833
Messages
6,121,865
Members
449,052
Latest member
Fuddy_Duddy

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