Formula for Sales Milestone Payments

james24812

New Member
Hi All,

I am trying to write a formula that pays a specific milestone when cumulative sales are greater than a certain number. There are multiple tiers where this applies, but each milestone can only be paid once. Below are the milestone thresholds and amount paid when each is passed. Does anyone know how I can accomplish this by referencing the cumulative sales cell in a given year?

Cumulative Sales Threshold Milestone Amount
500,000 10,000
1,000,000 15,000
2,000,000 40,000
4,000,000 80,000

So, since each milestone is only paid once, the maximum total number of milestone payments that can be received is 145,000 (the sum of all milestones)

Thanks,

James
 

james24812

New Member
Sorry about the formatting. The table I was trying to put in should be that at 500,000 in sales, a 10,000 milestones is paid, at 1,000,000 in sales, a 15,000 milestone is paid, and so on.
 

shg

MrExcel MVP
One way:

Row\Col
A​
B​
C​
D​
E​
1​
Month​
Sales​
Cumu​
Comm​
2​
Jan
359,000​
359,000​
-​
D2: =LOOKUP(C2/100000, {0,5,10,20,40}, {0,10,25,65,145}*1000) - SUM(D$1:D1)
3​
Feb
437,000​
796,000​
10,000​
4​
Mar
323,000​
1,119,000​
15,000​
5​
Apr
352,000​
1,471,000​
-​
6​
May
433,000​
1,904,000​
-​
7​
Jun
477,000​
2,381,000​
40,000​
8​
Jul
347,000​
2,728,000​
-​
9​
Aug
420,000​
3,148,000​
-​
10​
Sep
515,000​
3,663,000​
-​
11​
Oct
580,000​
4,243,000​
80,000​
12​
Nov
472,000​
4,715,000​
-​
13​
Dec
506,000​
5,221,000​
-​
 

james24812

New Member
Thanks. Your formula makes sense and clearly appears to be working in your spreadsheet, but for some reason I cannot get it to work in mine. I am going left to right across a row and not down a column, and changed the $ sign on the sum portion accordingly but I still cannot get it to work. Thoughts?
 

shg

MrExcel MVP
Row\Col
A​
B​
C​
D​
E​
F​
G​
H​
I​
J​
K​
L​
M​
N​
1​
Month​
Jan​
Feb​
Mar​
Apr​
May​
Jun​
Jul​
Aug​
Sep​
Oct​
Nov​
Dec​
2​
Sales​
510,000​
521,000​
533,000​
355,000​
504,000​
390,000​
311,000​
343,000​
479,000​
563,000​
315,000​
579,000​
3​
Cumu​
510,000​
1,031,000​
1,564,000​
1,919,000​
2,423,000​
2,813,000​
3,124,000​
3,467,000​
3,946,000​
4,509,000​
4,824,000​
5,403,000​
4​
Comm​
10,000​
15,000​
-​
-​
40,000​
-​
-​
-​
-​
80,000​
-​
-​
B4: =LOOKUP(B3/100000, {0,5,10,20,40}, {0,10,25,65,145}*1000) - SUM($A4:A4)
 

james24812

New Member
Just realized that I was making the beginning part of the sum range reference the beginning sales cell rather than the one preceding it. Thank you! One final question, will that equation work if I replace the hardcoded numbers to references to cells instead so that I can change the inputs/break points?

Thanks again.
 

james24812

New Member
It did not work. My understanding is that arrays must be hard coded, correct? Unless I just need quotations around the reference. The references I tried to use are on a separate input tab.
 

shg

MrExcel MVP
Maybe you could post what you tried.
 

shg

MrExcel MVP
Row\Col
A​
B​
C​
D​
E​
F​
G​
H​
I​
J​
K​
L​
M​
N​
1​
Cumu​
0​
500,000​
1,000,000​
2,000,000​
4,000,000​
2​
Comm​
0​
10,000​
25,000​
65,000​
145,000​
3​
4​
Month​
Jan​
Feb​
Mar​
Apr​
May​
Jun​
Jul​
Aug​
Sep​
Oct​
Nov​
Dec​
5​
Sales​
510,000​
521,000​
533,000​
355,000​
504,000​
390,000​
311,000​
343,000​
479,000​
563,000​
315,000​
579,000​
6​
Cumu​
510,000​
1,031,000​
1,564,000​
1,919,000​
2,423,000​
2,813,000​
3,124,000​
3,467,000​
3,946,000​
4,509,000​
4,824,000​
5,403,000​
7​
Comm​
10,000​
15,000​
0​
0​
40,000​
0​
0​
0​
0​
80,000​
0​
0​
B7: {=LOOKUP(B6, $B$1:$G$1, $B$2:$G$2) - SUM($A7:A7)}
 

Some videos you may like

This Week's Hot Topics

Top