Spread the number of employees proportionately across a range of cells depending on values in another cell

ElBB23

New Member
Joined
Feb 10, 2017
Messages
26
Hi guys,

I am looking for ideas from the wealth of knowledge within the forum
smile.gif
- I will try to explain as best I can but I apologise in advance if I haven't explained it well.

So, I have a worksheet with three columns (there can be more if needed) the first column shows the time period, split into 15 minute interval segments going top to bottom. The middle column is currently blank with the total amount of hours that need to be allocated at the bottom (in this case 12.5 hours), the third column shows me how many people I have available during each interval.

I need a formula, function or even VBA in the second column that will look at the number of people I have available within the third column (both at row and total level) and distribute how many people I will allocate at each time interval in a weighted fashion so that the sum of all the intervals in the second column (divided by 4 to convert it into hours) matches the number of hours required at the bottom. So for example I want the number of people allocated at 00:00 to be higher than it is at 01:00 and If possible I only want it to allocate agents if the staffing is over 5.

Time
Allocated
Available
00:00
25
00:15
24
00:30
24
00:45
22
01:00
7
01:15
7
01:30
7
01:45
12
02:00
12
02:15
12
02:30
12
02:45
-2
03:00
-2
03:15
-1
03:30
-1
03:45
7
04:00
7
04:15
7
Required
12.5 (hours)
46.25 hours available

<tbody>
</tbody>



<tbody>
</tbody>
 

Excel Facts

Best way to learn Power Query?
Read M is for (Data) Monkey book by Ken Puls and Miguel Escobar. It is the complete guide to Power Query.
Tricky. This might get you some of the way:


Book1
ABC
1TimeAllocatedAvailable
200:00725
300:15624
400:30624
500:45622
601:0027
701:1527
801:3027
901:45312
1002:00312
1102:15312
1202:30312
1302:450-2
1403:000-2
1503:150-1
1603:300-1
1703:4527
1804:0027
1904:1537
20Required12.546.25
Sheet3
Cell Formulas
RangeFormula
B2=IF($C2>0,ROUND(C2/($C$20/$B$20),0),0)
B19=$B$20*4-SUM($B$2:$B$18)
C20=SUMIF(C2:C19,">0")/4


WBD
 
Upvote 0
Hi,

I am having a slight issue with it showing minus on the last cell if the required is quite low but if I remove the round aspect of the formula it works perfectly (I know this will give fractional people but I'm ok with that if needs be for now).
 
Upvote 0
Sorry, just another one - I don't want it to allocate any staff in an interval if the available is lower than a certain number. Its easy to insert an if formula against the available staff but its causing issues on the last row as if the staffing is under the required amount it is defaulting to zero and not giving me enough hours for the day (if that makes sense?)
 
Upvote 0
OK. If you're happy with fractional people then you could do this:


Book1
ABCDEF
1TimeAllocatedAvailableMinimum Staff:8
200:008.7412587425
300:158.3916083924
400:308.3916083924
500:457.6923076922
601:0007
701:1507
801:3007
901:454.195804212
1002:004.195804212
1102:154.195804212
1202:304.195804212
1302:450-2
1403:000-2
1503:150-1
1603:300-1
1703:4507
1804:0007
1904:1507
20Required12.535.75
Sheet3
Cell Formulas
RangeFormula
B2=IF($C2>=$F$1,C2/($C$20/$B$20),0)
C20=SUMIF(C2:C19,">="&$F$1)/4


WBD
 
Upvote 0

Forum statistics

Threads
1,214,990
Messages
6,122,625
Members
449,093
Latest member
catterz66

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