Excel: Low, Medium, High IF, AND???

Jon5

New Member
Joined
Aug 18, 2010
Messages
6
Hi Guys,

I was hoping someone could help me (it's Probably really easy but I've tried for a while and can't work it out).

I have 2 columns next to each other where the answer in the cell can be either high, low or medium. I'm trying to come up with a formula for the 3rd column where it can bascally say if column 1 is high and colum 2 is low the answer for column 3 must be medium etc.

i.e.

Low + Low = Low
Low + Medium = Low
Low + High = Medium
Medium + Low = Low
Medium + Medium = Medium
Medium + High = High
High + Low = Medium
High + Medium = High
High + high = High

Can someone at least put me on the right track by letting me know if it is an IF formula or AND or both please.

Thanks,


Jon
 

Excel Facts

Save Often
If you start asking yourself if now is a good time to save your Excel workbook, the answer is Yes
I'm sure a formula can be worked out, but it night get kind of messy. Would a VBA solution work for you?? What version of Excel are you using??
lenze
 
Upvote 0
If you have a lookup table like this:
Excel Workbook
EF
2LowLowLow
3LowMediumLow
4LowHighMedium
5MediumLowLow
6MediumMediumMedium
7MediumHighHigh
8HighLowMedium
9HighMediumHigh
10HighHighHigh
...




A VLOOKUP in column 3 might work (formula in green cells):
Excel Workbook
ABC
1Column1Column2Column3
2LowLowLow
3LowMediumLow
4LowHighMedium
5MediumLowLow
6MediumMediumMedium
7MediumHighHigh
8HighLowMedium
9HighMediumHigh
10HighHighHigh
...




In cell C2 enter this formula, and copy down:
Excel Workbook
C
2Low
...
Cell Formulas
RangeFormula
C2=VLOOKUP(A2&B2,$E$2:$F$10,2,0)
 
Upvote 0
If you don't want the VLOOKUP table to use up space in the spreadsheet, after you create the table in the spreadsheet and create this formula in cell C2:<?xml:namespace prefix = o ns = "urn:schemas-microsoft-com:office:office" /><o:p></o:p>
<o:p></o:p>
=VLOOKUP(A2&B2,$E$2:$F$10,2,0)<o:p></o:p>
<o:p></o:p>
While still in edit mode (not entered formula yet), highlight the range for the lookup table like this:<o:p></o:p>
<o:p></o:p>
=VLOOKUP(A2&B2,$E$2:$F$10,2,0)<o:p></o:p>
<o:p></o:p>
Then hit the evaluate key:<o:p></o:p>
<o:p></o:p>
F9<o:p></o:p>
<o:p></o:p>
To get this:<o:p></o:p>
<o:p></o:p>
=VLOOKUP(A2&B2,{"LowLow","Low";"LowMedium","Low";"LowHigh","Medium";"MediumLow","Low";"MediumMedium","Medium";"MediumHigh","High";"HighLow","Medium";"HighMedium","High";"HighHigh","High"},2,0)<o:p></o:p>
<o:p></o:p>
<o:p></o:p>
This process “hard codes” the table into the formula.<o:p></o:p>
<o:p></o:p>
Then enter and copy down.<o:p></o:p>
 
Upvote 0
Here's a formula approach
Code:
=IF(A1="Low",LOOKUP(B1,{"High","Low","Medium"},{"Medium","Low","Low"}),IF(A1="Medium",LOOKUP(B1,{"High","Low","Medium"},{"High","Low","Medium"}),IF(A1="High",LOOKUP(B1,{"High","Low","Medium"},{"High","Medium","High"}),"")))

lenze

Edit: I'm having trouble displaying formulas in code tags, so here is the formula
=IF(A1="Low",LOOKUP(B1,{"High","Low","Medium"},{"Medium","Low","Low"}),IF(A1="Medium",LOOKUP(B1,{"High","Low","Medium"},{"High","Low","Medium"}),IF(A1="High",LOOKUP(B1,{"High","Low","Medium"},{"High","Medium","High"}),"")))
 
Last edited:
Upvote 0
A bit messy but yet another way:
=CHOOSE(ROUNDUP(((LOOKUP(A1,{"high","low","medium"},{3,1,2})+LOOKUP(B1,{"high","low","medium"},{3,1,2}))/2),0),"Low","Medium","High")
 
Upvote 0
How about
=CHOOSE(2 + SIGN(SIGN(MATCH(A1,{"LOW","MED","HIGH"},0)) + SIGN(MATCH(B1,{"LOW","MED","HIGH"},0))),"LOW","MED","HIGH")


(These formulas would be shorter if you used numbers 0,1, or 2 and formatted the cells with the custom format [=1]"Low";[=2]"Med";"High"

Then one woudn't have to swap back and forth between text and numbers.)
 
Last edited:
Upvote 0
Perhaps

=LOOKUP(SUMPRODUCT(LOOKUP(A1:B1,{"High",3;"Low",1;"Medium",2})),{2,"Low";4,"Medium";5,"High"})
 
Upvote 0
Thanks all, you've been a great help. I ended up using Lenze's formula in the end and it works perfectly (not to say that any of the others would be any less effective!).

Thanks again for your quick responses, much appreciated! :)

Jon
 
Upvote 0

Forum statistics

Threads
1,224,616
Messages
6,179,912
Members
452,949
Latest member
beartooth91

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