Hefty IF Statemnets

sbrittain1988

New Member
Joined
Oct 27, 2017
Messages
1
Hi There,

I have an IF statement that currently has 10 IF statements within.

=IF(B4="F&B",IF(E4="License",(I4*1.22),IF(E4="Hardware",((I4*1.09)*0.4),IF(E4="SaaS",((I4/G4)*12*3.1),IF(E4="Consulting",I4,0)))),IF(E4="License",(I4*1.22),IF(E4="Hardware",((I4*1.12)*0.375),IF(E4="SaaS",((I4/G4)*12*3.1),IF(E4="Consulting",I4,if(E4="Hosting",I4,0))))))

I currently have within the "SaaS" IF statements a multiplier of 3.1 whereas I am trying to change that so that there are 6 different criteria within each SaaS IF.

If it is under 3, I want to multiply by 0.75, between 3-17 multiply by 3.1, 18-29 multiply by 3.35, 30-41 multiply by 3.6, 42-53 multiply by 3.7 and 54 or above multiply by 3.8.

I have tried the IF(AND( statements with no luck.

Any and all suggestions are GREATLY appreciated!

Thanks all!
 

Excel Facts

Who is Mr Spreadsheet?
Author John Walkenbach was Mr Spreadsheet until his retirement in June 2019.
Welcome to the board!

I would recommend using two lookup tables for this and replacing that formula with all of the nested IFs with something like this instead:

Code:
=I4*VLOOKUP(E4,L2:N7,IF(B4="F&B",2,3),0)*IF(E4="SaaS",VLOOKUP(I4,B3:C8,2))

This is both easier to follow and easier to update if, say, the License factor changes from 1.22 to 1.30 at a later time.

The first lookup table is in L2:N7 and has the categories, F&B values, and non-F&B values. In other words:
Cells L3:L7 contain License, Hardware, SaaS, Consulting, and Hosting
Cell M2 has the label "F&B", and cells M3:M7 have the multiplication factors for each corresponding F&B category in column L. Looks like 1.22, 1.09, 12/G4, 1, and 0
Cell N2 has the label "Non F&B" and cells N3:N7 have the multiplication factors for each corresponding non-F&B category in column L. Hardware looks like 1.12*0.375 and Hosting looks like 1. The rest look to be the same as column M.

Lastly, B3 to C8 have the SaaS multiplication factors. The left column is the lower bound for each range (0, 3, 18, 30, 42, and 54) and the right column has the corresponding multiplication factors (0.75, 3.1, 3.353, 3.6, 3.7, and 3.8).
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,882
Messages
6,175,164
Members
452,615
Latest member
bogeys2birdies

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