Royalty Fees: Changes depending on level of sales. How to put this in Excel

mrooks

New Member
Joined
Jun 26, 2009
Messages
9
Hi

I wanted to make a formula in excel which will make a royalty fixed fee calculation based on the level of sales performed by a customer. For example if I have the following scenario.


Assumptions
Monthly Fixed Fee Royalty
$0 to $100,000 Sales $10,000
$100,000 to $200,000 Sales $ 7,500
$100,000 above Sales $ 5,000

If for example, the customer had sales of $150,000, what formula could I do to perform this calculation in order for it to realise it needs put $7,500 in the correct cell.

I have tried multiple if statements in one cell but that doesn't seem to be effective.

Can you please help?

Thanks
 

Excel Facts

How to create a cell-sized chart?
Tiny charts, called Sparklines, were added to Excel 2010. Look for Sparklines on the Insert tab.
What cell do you want your formula in?

Can you confirm details below:

<$100,00 sales (or is it <=$100,000 ?) = $10,000
$100,000-$200,000 = $7,500
>$200,000 (or is it >=$200,000 ?) = $5,000

I assume below you made a mistake in your 3rd line? And why does the royalty decrease as sales increase? Anyway, based on your info, I would use the following:
<TABLE style="PADDING-RIGHT: 2pt; PADDING-LEFT: 2pt; FONT-SIZE: 8pt; FONT-FAMILY: Arial,Arial; BACKGROUND-COLOR: #ffffff" cellSpacing=0 cellPadding=0 border=1><COLGROUP><COL style="FONT-WEIGHT: bold; WIDTH: 30px"><COL style="WIDTH: 85px"><COL style="WIDTH: 48px"><COL style="WIDTH: 56px"><COL style="WIDTH: 56px"></COLGROUP><TBODY><TR style="FONT-WEIGHT: bold; FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center"><TD> </TD><TD>A</TD><TD>B</TD><TD>C</TD><TD>D</TD></TR><TR style="HEIGHT: 19px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">1</TD><TD style="FONT-WEIGHT: bold">Sales Amount</TD><TD style="FONT-WEIGHT: bold">Royalty</TD><TD> </TD><TD> </TD></TR><TR style="HEIGHT: 19px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">2</TD><TD style="TEXT-ALIGN: right">$0</TD><TD style="TEXT-ALIGN: right">$10,000</TD><TD> </TD><TD> </TD></TR><TR style="HEIGHT: 19px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">3</TD><TD style="TEXT-ALIGN: right">$100,000</TD><TD style="TEXT-ALIGN: right">$7,500</TD><TD> </TD><TD> </TD></TR><TR style="HEIGHT: 19px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">4</TD><TD style="TEXT-ALIGN: right">$200,000</TD><TD style="TEXT-ALIGN: right">$5,000</TD><TD> </TD><TD> </TD></TR><TR style="HEIGHT: 19px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">5</TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD></TR><TR style="HEIGHT: 19px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">6</TD><TD style="BACKGROUND-COLOR: #ccffff; TEXT-ALIGN: right">150000</TD><TD> </TD><TD> </TD><TD style="BACKGROUND-COLOR: #ffff99; TEXT-ALIGN: right">7500</TD></TR></TBODY></TABLE>
<TABLE style="FONT-SIZE: 10pt; BORDER-LEFT-COLOR: #00ff00; BORDER-BOTTOM-COLOR: #00ff00; COLOR: #000000; BORDER-TOP-STYLE: groove; BORDER-TOP-COLOR: #00ff00; FONT-FAMILY: Arial; BORDER-RIGHT-STYLE: groove; BORDER-LEFT-STYLE: groove; BACKGROUND-COLOR: #fffcf9; BORDER-RIGHT-COLOR: #00ff00; BORDER-BOTTOM-STYLE: groove"><TBODY><TR><TD>Spreadsheet Formulas</TD></TR><TR><TD><TABLE style="FONT-SIZE: 9pt; FONT-FAMILY: Arial" cellSpacing=0 cellPadding=2 border=1><TBODY><TR style="FONT-SIZE: 10pt; BACKGROUND-COLOR: #cacaca"><TD>Cell</TD><TD>Formula</TD></TR><TR><TD>D6</TD><TD>=INDEX($A$2:$B$4,MATCH(A6,$A$2:$A$4,1),2)</TD></TR></TBODY></TABLE></TD></TR></TBODY></TABLE>

Where in range A2:A4, the number is the lower bound of each range and A6 is your input cell and D6 your ouput cell
 
Upvote 0

Forum statistics

Threads
1,224,507
Messages
6,179,181
Members
452,893
Latest member
denay

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