Problem with nested statements.

sam3d

New Member
Joined
Apr 4, 2013
Messages
2
Hello,

I wonder if some one can help me solve the folowing...

I keep getting this error message "The specified formula connot be entered because it uses more levels of nesting than are allowed"



=IF(AB5="","",IF((AB5=0),0,IF((AB5<=8000),0.28,IF((AB5<=9000),0.26,IF((AB5<=10000),0.255,IF((AB5<=11000),0.24,IF((AB5<=12000),0.2375,IF((AB5<=13000),0.235,IF((AB5<=14000),0.23,IF((AB5<=15000),0.2275,IF((AB5<=16000),0.225,IF((AB5<=17000),0.2225,IF((AB5<=18000),0.22,IF((AB5<=19000),0.2175,IF((AB5<=25000),0.215,IF((AB5<=30000),0.21,IF((AB5<=50000),0.205)))))))))))))))))


It's basically a labor cost expected total based on sales.

any advise would be appreciated.


-Sam.
 

Some videos you may like

Excel Facts

How can you turn a range sideways?
Copy the range. Select a blank cell. Right-click, Paste Special, then choose Transpose.

Scott Huish

MrExcel MVP
Joined
Mar 17, 2004
Messages
19,935
Office Version
365, 2010
Platform
Windows
Instead of nested IFs have a look at the VLOOKUP function.
 

circledchicken

Well-known Member
Joined
Aug 13, 2011
Messages
2,932
Hi,

Another alternative might be INDEX / MATCH with a match type of -1 (finding the smallest value that is greater than or equal to lookup value), like this:

Code:
=IF(
   AB5 = "", "",
   INDEX(
     {0.205;0.21;0.215;0.2175;0.22;0.2225;0.225;0.2275;0.23;0.235;0.2375;0.24;0.255;0.26;0.28;0},
     MATCH(
      AB5,
      {50000;30000;25000;19000;18000;17000;16000;15000;14000;13000;12000;11000;10000;9000;8000;0},
      -1))
  )
You might want to move the hardcoded values to ranges on your worksheet or named ranges. For more on the MATCH function and INDEX/MATCH see:
MS Excel: MATCH Function (WS)
MATCH - Excel - Office.com
Excel Index Function and Match Function
 
Last edited:

Forum statistics

Threads
1,089,503
Messages
5,408,679
Members
403,224
Latest member
rholmesa

This Week's Hot Topics

  • help please
    SORRY NOT ANY GOOD AT EXCEL SO HELP WOULD BE MUCH APPRECIATED this formula is in a sheet called ignore...
  • two formulas needed
    Hello, I'll try my best to explain this: First formula needed in Sheet1 cell A2: If Sheet1 cell B2 = Sheet2 cell B2 then return a 1. If not then...
  • Dynamic Counts
    Good afternoon, we are tidying up some data & the data seems to be growing quicker than we are tidying it up! What we confirm (by reviewing it...
  • Help Excel formula eliminate duplicate values and keep only 2 identical rows.
    as picture below column A has a duplicate value. but the values are not the same as the rule. sometimes 4 rows, sometimes 10 rows or 7 or 9...
  • Macro Compile Error Sub or Function not defined
    Hello, I am trying to run macros from a validation list, all macros have been created and run perfectly on there own but I'm getting a compile...
  • Last row combined with Current Region VBA
    I'm generally happy finding the last row of data through something like Lastrow = Cells(Rows.Count, "D").End(xlUp) but I don't always receive data...
Top