Forum Discussion

bagudd's avatar
bagudd
Copper Contributor
Jun 06, 2019
Solved

Pricing sheet using ranges of quantity discounts

I'm building a pricing sheet and need the below table to show the cumulative pricing based on the ranges.  Anybody any idea to do this without a bunch of nested IF's?

 

Range StartRange EndStandard discountList PriceDiscounted price
0490,00%€ 30,00€ 30,000
50995,00%€ 30,00€ 28,500
10049910,00%€ 30,00€ 27,000
5002.49915,00%€ 30,00€ 25,500
2.5004.99920,00%€ 30,00€ 24,000
5.0009.99925,00%€ 30,00€ 22,500
10.00014.99930,00%€ 30,00€ 21,000
15.00019.99935,00%€ 30,00€ 19,500
20.000100.00040,00%€ 30,00€ 18,000

 

 QuantityTotalUnit
Example1:75€ 2.211,000€ 29,480
Example2:2550€ 65.919,000€ 25,851

 

The first example is the first 49 licenses @30€, the next 75 - 49 = 26 @ 28,5€

The second example uses same logic, within each range the number of license at their rate + last 50 @24€

 

I'm looking for a magic formula in the Total cell in bold to perform the calculation based on the quantity cell.

 

Thanks!

 
 
  • bagudd , please check this

    =SUMPRODUCT((  ($C$3:$C$11-$B$3:$B$11+1)*(B14>$C$3:$C$11)+
                    (B14-$B$3:$B$11+1)*(B14<=$C$3:$C$11)*(B14>=$B$3:$B$11))*
                 $E$3:$E$11*(1-$D$3:$D$11)  )

    "more" is changed on "more or equal to", in red above

7 Replies

  • bagudd ,

    If change the start of the first range on 1

    when the formula could be

    =SUMPRODUCT((  ($C$3:$C$11-$B$3:$B$11+1)*($B14>$C$3:$C$11)+
                   ($B14-$B$3:$B$11+1)*($B14<=$C$3:$C$11)*($B14>$B$3:$B$11))*
                 $E$3:$E$11*(1-$D$3:$D$11)  )

     

    • bagudd's avatar
      bagudd
      Copper Contributor

      Hi SergeiBaklan ,

       

      Big thanks for the feedback. 

      I do see an error when entering the tilting values, like 50, that shows the same value as for 49.  Same goes for 100, 500 etc.

      Any idea what the fix could be?

       

      Thanks

       
       
       
       
       
       
       
       
       
      • bagudd , please check this

        =SUMPRODUCT((  ($C$3:$C$11-$B$3:$B$11+1)*(B14>$C$3:$C$11)+
                        (B14-$B$3:$B$11+1)*(B14<=$C$3:$C$11)*(B14>=$B$3:$B$11))*
                     $E$3:$E$11*(1-$D$3:$D$11)  )

        "more" is changed on "more or equal to", in red above

Resources