Pricing Table Predicament Please Help:

bobby1987

New Member
Joined
Nov 8, 2012
Messages
1
Hi Guys,

I am new to both this forum and excel and in need of some help. I have created a pricing table (Please see below and you are charged per unit in a tier structure.

For example if I purchased 13,500 units, I would be charged 0.21 per unit for the first 10,000 units and for the other 3,500 i will be charged at 0.19.

FIRST 0-10,0000.21
NEXT 10,001-20,0000.19
NEXT 20,001-40,0000.16
THEN 40,001+0.12

<colgroup><col><col span="4"></colgroup><tbody>
</tbody>

My question is can I put a number of any amount of units below this table and excel can provide me with that exact price?

Seems very complicated but if you can help that would be great.

Many thanks,

Bobby1987
 

Excel Facts

Excel Can Read to You
Customize Quick Access Toolbar. From All Commands, add Speak Cells or Speak Cells on Enter to QAT. Select cells. Press Speak Cells.
Assuming your first column are in cells A1 through A4 and the next is B1 through B4. Put the number of units into Cell A6 and put the following formula into Cell B6
=If(A6<10000,A6*B1,if(A6<20000, 10000*B1+(A6-10000)*B2,if(A6<40000, 10000*B1+10000*B2+(A6-20000)*B3,10000*B1+10000*B2+20000*B3+(A6-40000)*B4)))

There might be a better way to do it, but that should work
 
Upvote 0
Hi Bobby,

In cells as follows:
A1=10000, B1=0.21
A2=20000, B2=0.19
A3=40000, B3=0.16
A4=">40000", B4=0.12

Assuming your amount of units is in A5 then use this formula: =IF(A5<=A1,A5*B1,(A1*B1)+IF(A5<=A2,(A5-A1)*B2,(A2-A1)*B2+IF(A5<A3,(A5-A2)*B3,(A3-A2)*B3+(A5-A3)*B4)))

It certainly isn't any easier to understand than Justwitt's, but it does allow you to change the cut-offs between the bands. And like Justwitt I think there is a better solution, probably based on SUMPRODUCT, but I couldn't make it work!

Not sure my solution is significantly better than Justwitt's but having worked on it thought I share it.

Regards to all
 
Upvote 0
Another way:

Code:
      --A-- --B-- --C-- ---D---
  1    Qty  Price  Qty   Price 
  2               10000 2100.00
  3       0  0.21 10001 2100.19
  4   10000  0.19              
  5   20000  0.16              
  6   40000  0.12

In D2 and copied down,

=SUMPRODUCT((C2>$A$3:$A$6) *(C2-$A$3:$A$6) * ($B$3:$B$6-$B$2:$B$5))
 
Upvote 0
Morning shg,

I knew there was a way to use sumproduct, but I dont think I'd have worked it out anytime soon!

Many thanks, much appreciated.

Regards
 
Upvote 0

Forum statistics

Threads
1,215,338
Messages
6,124,358
Members
449,155
Latest member
ravioli44

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