Tiered bonus structure

bsutherland

New Member
Joined
Oct 23, 2019
Messages
2
Trying to setup a spreadsheet to do this but here's the grid below. Bonuses are ONLY given on the amount between the threshold.

For instance, if you do 500K of commission and fee's, you get a bonus on tier 1 on 99,999 of production, then you also get a bonus on the 299,999 of production.

You get 999.99 on tier 1 + 5,999.98 on tier 2 comming to a sum of 6999.97.


A bonus of 1% of Gross Commissions and Fees between $100,000 and $199,999.*
A bonus of 2% of Gross Commissions and Fees between $200,000 and $499,999.*
A bonus of 3% of Gross Commissions and Fees between $500,000 and $749,999.*
A bonus of 4% of Gross Commissions and Fees between $750,000 and $999,999.*
A bonus of 5% of Gross Commissions and Fees between $1,000,000 and $1,999,999.*
A bonus of 6% of Gross Commissions and Fees between $2,000,000 and $2,999,999.*
A bonus of 7% of Gross Commissions and Fees between $3,000,000 and $3,999,999.*
A bonus of 8% of Gross Commissions and Fees in excess of $4,000,000.*

If someone could build this out or help me with the formula's that would be great.
 

Excel Facts

How to change case of text in Excel?
Use =UPPER() for upper case, =LOWER() for lower case, and =PROPER() for proper case. PROPER won't capitalize second c in Mccartney
This was a real puzzle. The requirements were a little strange in that the lower and upper limits of the tiers were NOT inclusive which is assumed by the links provided by others. Below is the worksheet I put together and the formulas are listed below that. You can see in your $500,000 example that the sum of the cells G3 and G4 total your example bonus. Cell F11 would accept the input of the total commissions and fees and is a named range "Comm" in the formulas.


ABCDEFG
1TiersTier RangePctComm & FeesBonus
2 - 100,000 100,000.00 0% $ 100,000.00 $ -
31 100,000 199,999 100,000.00 1% 99,999.00 999.99
42 200,000 499,999 300,000.00 2% 299,999.00 5,999.98
53 500,000 749,999 250,000.00 3% 249,999.00 7,499.97
64 750,000 1,000,000 250,000.00 4% 250,000.00 10,000.00
75 1,000,001 2,000,000 1,000,000.00 5% 999,999.00 49,999.95
86 2,000,001 3,000,000 1,000,000.00 6% 999,999.00 59,999.94
97 3,000,001 4,000,000 1,000,000.00 7% 999,999.00 69,999.93
108 4,000,000 100,000,000 8% 6,000,000.00 480,000.00
11#A9D08E ;;"> $10,000,000.00 #A9D08E ;;"> $ 684,499.76

<colgroup><col style="width: 25pxpx"><col><col><col><col><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Sheet1

Worksheet Formulas
CellFormula
D2=F2
F2=IF(Comm>=C2,C2,Comm)
G2=E2*F2
F3=IF(Comm>C3,C3-B3,IF((Comm-SUM($D$2:D2))<0,0,(Comm-SUM($D$2:D2))))
G3=E3*F3
F4=IF(Comm>C4,C4-B4,IF((Comm-SUM($D$2:D3))<0,0,(Comm-SUM($D$2:D3))))
G4=E4*F4
F5=IF(Comm>C5,C5-B5,IF((Comm-SUM($D$2:D4))<0,0,(Comm-SUM($D$2:D4))))
G5=E5*F5
F6=IF(Comm>C6,C6-B6,IF((Comm-SUM($D$2:D5))<0,0,(Comm-SUM($D$2:D5))))
G6=E6*F6
F7=IF(Comm>C7,C7-B7,IF((Comm-SUM($D$2:D6))<0,0,(Comm-SUM($D$2:D6))))
G7=E7*F7
F8=IF(Comm>C8,C8-B8,IF((Comm-SUM($D$2:D7))<0,0,(Comm-SUM($D$2:D7))))
G8=E8*F8
F9=IF(Comm>C9,C9-B9,IF((Comm-SUM($D$2:D8))<0,0,(Comm-SUM($D$2:D8))))
G9=E9*F9
F10=IF(Comm>C10,C10-B10,IF((Comm-SUM($D$2:D9))<0,0,(Comm-SUM($D$2:D9))))
G10=E10*F10
G11=SUM(G2:G10)

<thead>
</thead><tbody>
</tbody>

<tbody>
</tbody>

Workbook Defined Names
NameRefers To
Comm=Sheet1!$F$11

<thead>
</thead><tbody>
</tbody>

<tbody>
</tbody>
 
Last edited:
Upvote 0
Care to explain which parts are not inclusive? or exactly what you mean by inclusive?
 
Last edited:
Upvote 0
You get 999.99 on tier 1 + 5,999.98 on tier 2 comming to a sum of 6999.97.


A bonus of 1% of Gross Commissions and Fees between $100,000 and $199,999.*
A bonus of 2% of Gross Commissions and Fees between $200,000 and $499,999.*
A bonus of 3% of Gross Commissions and Fees between $500,000 and $749,999.*


  1. The first $100,000 of Commissions and Fees pay 0% bonus
  2. Your example of $500,000 resulting in a bonus of $6,999.97 is calculated as (100,000 * 0.00) + (99,999 * .01) + (299,999 * .02) = 6,999.97
    1. The total Commissions and Fees in that calculation is $100,000 + 99,999 + 299,999 = 499,998 and not 500,000
    2. As you progress down the tiers you lose $1 for each tier.
 
Upvote 0
Please check the actual definition of the brackets and confirm the expected results with say 10,000,000.


Excel 2010
ABC
1BracketsRateRate Diff
200%0%
3100,0001%1%
4200,0002%1%
5500,0003%1%
6750,0004%1%
71,000,0005%1%
82,000,0006%1%
93,000,0007%1%
104,000,0008%1%
11
1210,000,000684,500
3bb
Cell Formulas
RangeFormula
C2=B2-N(B1)
B12=SUMPRODUCT(--(A12>A2:A10),A12-A2:A10,C2:C10)
 
Upvote 0
[*]As you progress down the tiers you lose $1 for each tier.
I see what you mean, someone who doesn't know how to set up a commission, wait for the salesmen to put in a claim at a later date when they realise :ROFLMAO:
 
Last edited:
Upvote 0

Forum statistics

Threads
1,214,584
Messages
6,120,387
Members
448,957
Latest member
Hat4Life

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