Identifying work crew on shift by timestamp provided in productivity report.

MattyJimmy

New Member
Joined
Apr 20, 2018
Messages
5
I receive a report which details the time a truckload of material was dumped as a timestamp. I am wanting to write a formula which interrogates the timestamp and can then identify which work crew was on shift at the time the load was dumped. Shift details are as follows:

4 crews: A, B, C, D. Each works 7x12 hour shifts, then goes on break. If a crew is working day shift for 7 days, they go on break for 7 days but not 7*24 hours, as they come back in on night shift after their break, with their counterparts coming back in on day shift.

Whilst they were on break, the other two crews were working day shift/night shift. example below:

On 28 March at 07:00, A crew started their 7 day swing. Working from 07:00 until 18:59:59, at 19:00 B crew started shift, working through until 06:59:59 the following day.

These crews continued to rotate until B crew finished night shift at 06:59:59 on 05 April. Both A and B crew then went on break.

At 07:00 on 05 April, D crew started shift, they worked until 18:59:59, at 19:00, C crew started shift, working through until 06:59:59 the following day.

and so on. The trick bit is when C and D crew go on break, B crew comes in on Day shift, with A crew coming back in on night shift.

Wow, thanks for reading this far! I figure I should be able to divide the timestamp by a number, and then depending on if the result is between a range of values we should be able to see what two crews are working, i.e. A/B or C/D, but am not sure how to identify it down to the crew on day or night shift, especially seeing as they go from days to nights to days and so on.

Any help would be greatly appreciated.

Cheers,

Mat

P.S. This data is then sucked into a PowerQuery query, so if it is easier to sort out in PowerQuery please let me know! :)
 

Excel Facts

Difference between two dates
Secret function! Use =DATEDIF(A2,B2,"Y")&" years"&=DATEDIF(A2,B2,"YM")&" months"&=DATEDIF(A2,B2,"MD")&" days"
The tricky part in matching timestamps is the morning when the A-B crews are relieved by the C-D crews. Your dates are a little confusing: if A-crew starts at 28-Mar 07:00 and B-Crew at 28-Mar 19:00, C-crew should start at 07:00 on 04-Apr.

Anyhow, this seems to work, just correct the dates:


Book1
ABCDEF
1Week07:0019:00Timestamp04/19/2018 06:00
229-Mar-18ABCrewA
305-Apr-18CD
412-Apr-18BA
519-Apr-18DC
626-Apr-18AB
Sheet1
Cell Formulas
RangeFormula
F2=INDEX(B2:C5, MATCH(F1-(HOUR(F1)< 7), A2:A5), 1+OR(HOUR(F1)< 7, HOUR(F1)>19))
 
Last edited:
Upvote 0
Fantastic, this is working great. I have expanded the indexed cells to span the whole year (just by dragging down) as with the dates and have ran a few tests which seem to work perfectly. I like the idea of using index match to solve the problem. As you may have been able to tell, I was thinking of a mathematical answer to the question but this works great. (Yes I know this is still mathematical, but you know what I mean!). Thanks again for the help.
P.S. Hahaha, yes I had the dates out by 1 day, but oddly enough D crew really does start before C crew. The rotation goes A, B, D, C. I presume it is because we are Australian and that is the closest we could get to resemble AC/DC!! :P Thanks again.
 
Upvote 0
Found one issue, changed the final part of the formula to >18, as it seems to include anything up to 19.99999999999999999 repeater as 19, therefore the function was identifying all timestamps before 8pm as still on dayshift. (I hope that makes sense!)
 
Upvote 0
I'm happy the lookup table and formula work for you.

It's good that you found the formula error. I tested values on either side of midnight and at the morning shift change; I forgot to test the evening shift change. ">=19" would also correct my mistake and may be more self-explanatory when you look at the formula two weeks from now.
 
Upvote 0

Forum statistics

Threads
1,214,389
Messages
6,119,232
Members
448,879
Latest member
VanGirl

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