Can this even be done? Tracking Date / Time Elapsed

G

Guest

I'm trying to create a worksheet which records elapsed time between Date /
Time Received and Date / Time Delivered. So far, so good. Problem is, the
elapsed time I get really needs to use some form of Networkdays, excluding
Holidays, and (here's the really tricky part) non-work hours. I've tried
fiddling with various Ifs, but am not experienced enough at Excel to grasp
why my formulas don't work.

What I currently have is giving me total time elapsed, which is good:

Received (A1) - 12/30/05 16:08
Delivered (B1) - 1/3/06 9:20
Elapsed (C1) - =(A1-B1) 3:17:12 (formatted Custom - d:h:mm)

The result I actually want in this example is 0:2:12, based on 52 elapsed
minutes on 12/30/05 and 1:20 on 1/3/06 (clock stops between 5PM & 8AM),
excluding weekends, holiday (1/2/03) & overnight hours (17:00-08:00). Is
there any *possible* way to get there from here?

Any help greatly appreciated, but as I said, I'm not all that Excel savvy,
so type... real... slow...
 
R

Roger Govier

Hi

Set up a list of holiday dates somewhere on your sheet and use
Insert>Name>Define Holidays > Refers to your range of cells.

Then
=(TIME(17,0,0)-MOD(A1,1))+(MOD(B1,1)-TIME(8,0,0))+(NETWORKDAYS(A1,B1,holidays)-2)*9

Starting from the end of the formula, Networkdays returns the total
elapsed working days between the start and end dates, excluding any days
within the range of dates defined by holidays. Since we are dealing with
the start date and end date in the earlier part of the formula, then you
need to deduct 2 from the result, and multiply the result by 9 to cover
the hours for each full day elapsed.

The first part of the formula, uses MOD() to extract the time from the
day date value in the cell, and deducts this from 5 pm to calculate
elapsed hours on start day. The middle part does the same, but takes 8
am away from the time value to calculate elapsed hours on the final day.
 
G

Guest

Oh... my... God, what a beautiful thing!
I followed your instructions, c/p'ed the formula (i especially liked that
part!) and it worked perfectly.

Thank you SO much, Roger!
 
D

daddylonglegs

Hi Roger & scd

Roger's suggested formula will only work correctly when the delivery
date is the next working day after the received date as in the example
quoted - the 9at the end needs to be 9 hours, i.e.

=(TIME(17,0,0)-MOD(A1,1))+(MOD(B1,1)-TIME(8,0,0))+(NETWORKDAYS(A1,B1,holidays)-2)*TIME(9,0,0)

however you can simplify this to

=MOD(B1,1)-MOD(A1,1)+(NETWORKDAYS(A1,B1,holidays)-1)*"09:00"

or to return a blank if either A1 or B1 are blank

=IF(COUNTBLANK(A1:B1)=0,MOD(B1,1)-MOD(A1,1)+(NETWORKDAYS(A1,B1,holidays)-1)*"09:00","")

Finally, is it possible that the delivery date could be outside work
hours, e.g. on a Saturday, what result would be required then?
 
R

Roger Govier

Hi daddylonglegs

Nice catch of my error in not using * Time(9,0,0) at the end (or even
more simply * "09:00")!
Your simplification to just using the subtraction of the MOD of the
times, and using Netwokdays -1 rather than 2 is a masterly stroke.
Well done.

--
Regards

Roger Govier


"daddylonglegs"
message
news:[email protected]...
 
G

Guest

Thanks, both! I realized the same-day problem a few days ago and had
intended to check back in for clarification. Looks like you beat me to it.

Your "if" statement was an even bigger help, as much of our documentation
predates the use of time stamps, and just relies on dates.

And as for your question about what happens during off-times, we basically
told Mgmt that anything we don't get between 8-5 M-F is just stamped as of
8AM the next workday.

Again, thanks to both of you!
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top