determine Shift by week number

salahmost

Board Regular
Joined
Feb 19, 2007
Messages
68
We've turned to 3 shifts instead of two.

I have 3 groups of people who change shifts regularly, Group A - Group B - Group C , groups swap shifts with each other So they will go forward 1 shift.
week1: A B C
Week2: C A B
week3: B C A ... then again A B C....etc.
.I would like something that gives me a visible display in Excel when I change a week number box, so it shows me what shift they are on for that week number or for any data.
I use the next formula to calculates the week number of the Date base on Week 1 beginning on the first Saturday of the year as week start day is Saturday and week end data is Thursday and Friday is our off day:
Code:
=TRUNC(((B2-DATE(YEAR(B2),1,1)+MOD(7-WEEKDAY(DATE(YEAR(B2),1,1)),7))+6)/7)
Where B2 contains the date.
Thanks in advanced.

ـــــــــــــــــــــــــــــــــــــــــ
ٍSalah
 

Excel Facts

Back into an answer in Excel
Use Data, What-If Analysis, Goal Seek to find the correct input cell value to reach a desired result
I'm not totally sure I follow but if we say A1 holds Group and B1 the Week Number then

C1: =3-MOD(-G1-(MATCH(F1,{"A","B","C"})-1),3)

would give you the shift for that combination be it 1, 2 or 3.

(I'm sure there's a much more succinct formula)
 
Upvote 0
I think the below would perhaps be more logical... ?

C1: =1+MOD($B1-1+MATCH($A1,{"A","B","C"})-1,3)

the prior example has incorrect references - oversight on my part when testing - F1 would be A1 (the Group letter) and G1 would be B1 (ie the week number)
 
Upvote 0
Worked like a charm!
Thank you so much.

ــــــــــــــــــــــــــــــــــــــــــــــــــــ
Salah
 
Upvote 0
For expected new group that will work 2 shifts A and C ... How can we modify the MOD function?
 
Upvote 0

Forum statistics

Threads
1,215,444
Messages
6,124,891
Members
449,194
Latest member
JayEggleton

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