Spreading amounts across colums

Bowraven

New Member
Joined
Feb 7, 2017
Messages
30
What I'm trying to achieve is to spread amounts across columns. In the columns C to M below, this represents future months income, i.e. what is actually received from customers in the month. However, the income received is prepaid, so it is for future months. Column B represents the number of months the income is in advance for (e.g. prepaid insurance or software support etc.).

So what I'd like to end up with is what I've shown in Row 6. In Jan 17 (Column C) you have 1/10 of £1,000; Feb 17 (Column D) you have 1/10 of £1,000 + 1/10 1,050; Mar 17 (Column E) 1/10 £1,000 + 1/10 £1,050 + 1/10 £1,100, etc. until you get to the eleventh row when Jan 17 drops off and Nov 17 gets added, and so on.

I'd like to do this with a formula somehow please. Row 7 would represent the numbers in row 3, but spread over 8 months and row 8 would represent row 4, but spread over 5 months.

I have chosen randomly 10, 8 and 5 months, but the period could be other periods too, it's the formula I'd like to then use for all periods of spreading the amounts.

There is one more option to add into the formula, whereby the first month could be offset by one month. So in the example below in Row 6, the first £100 would appear in column D, or Feb 17, as it has been offset by 1 month.

ABCDEFGHIJKLMIJKLMNOPQRS
1Months
Advanced
Jan-17Feb-17Mar-17April-17May-17June-17July-17Aug-17Sept-17Oct-17Nov-17Dec-17Jan-18Feb-18Mar-18April-18
2101000105011001150120012501300130013001300130014001450140015001600
382050210024002400250025502500210020502300210023502500250025002600
455000510045005900600065006000578055006000610059004500500051005250
5
61010020531543055067580593510651195122512601295132013501385
78
85
9

<tbody>
</tbody>

Thank you in advance of help on this one. If what I've said does not make sense, please ask. :)
 

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)
Welcome to the forum.

I'm not sure how you use this, but I think the explanation of how you want it calculated is clear enough.

Excel 2012
A
B
C
D
E
F
G
H
I
J
K
L
M
N
O
P
Q
1
Months
17-Jan
17-Feb
17-Mar
17-Apr
17-May
17-Jun
17-Jul
17-Aug
17-Sep
17-Oct
17-Nov
17-Dec
18-Jan
18-Feb
18-Mar
18-Apr
2
Advanced
3
10
1000
1050
1100
1150
1200
1250
1300
1300
1300
1300
1300
1400
1450
1400
1500
1600
4
8
2050
2100
2400
2400
2500
2550
2500
2100
2050
2300
2100
2350
2500
2500
2500
2600
5
5
5000
5100
4500
5900
6000
6500
6000
5780
5500
6000
6100
5900
4500
5000
5100
5250
6
7
10
100
205
315
430
550
675
805
935
1065
1195
1225
1260
1295
1320
1350
1385
8
8
256.25
518.75
818.75
1118.75
1431.25
1750
2062.5
2325
2325
2350
2312.5
2306.25
2306.25
2300
2300
2362.5
9
5
1000
2020
2920
4100
5300
5600
5780
6036
5956
5956
5876
5856
5600
5500
5320
5150

<tbody>
</tbody>
Sheet1


Worksheet Formulas
Cell
Formula
B7
=SUM(OFFSET(B3,0,MAX(COLUMN($B1)-COLUMN(B1),1-$A3),1,MIN($A3,COLUMNS($B3:B3))))/$A3

<tbody>
</tbody>

<tbody>
</tbody>



Put the formula in B7, and copy down and across.

Hope this helps.
 
Last edited:
Upvote 0

Forum statistics

Threads
1,213,497
Messages
6,113,999
Members
448,543
Latest member
MartinLarkin

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