if or functions

benwork

Board Regular
Joined
Oct 8, 2010
Messages
69
Hi

Im looking for a if or function to help me with some data.

I receive element grades for a product and would like it to auto assign depending on the values.

These are the grade ranges for each product

good grade Cu - 99-50 N -10-5 Al - 0-2
medium grade Cu 49-25 N - 4.9-2.5 Al - 2.1-5
poor grade Cu - 24-0 N - 2.4-0 Al - 5.1 - 10

If any of the elements falls into a lower category then the whole item becomes downgraded.

For example if a grade comes back as Cu - 85, N - 7 and Al - 7.5 then the product quality is poor grade.

Another example is Cu - 45, N - 9, Al 5.2, because the Al is classed as the poor grade, the whole item is classed as poor.

The spreadsheet will be set up like

A1 Sample Ident A2 Cu A3 N A4 AL A5 Product quality

If anyone could help me with this, it would be greatly appreciated.

Cheers

Ben
 

Excel Facts

Back into an answer in Excel
Use Data, What-If Analysis, Goal Seek to find the correct input cell value to reach a desired result
Two methods: the first one is broken into simple steps but involves the use of three 'helper'columns which flag the quality of each element before combining them to generate the overall quality:-
Code:
In E1: [B]=IF(AND(B1[COLOR=blue]<=[/COLOR][COLOR=blue]99[/COLOR],B1[COLOR=blue]>=50[/COLOR]),3,IF(AND(B1[COLOR=blue]<[/COLOR][COLOR=blue]50[/COLOR],B1[COLOR=blue]>=25[/COLOR]),2,1))[/B]
In F1: [B]=IF(AND(C1[COLOR=blue]<=10[/COLOR],C1[COLOR=blue]>=5[/COLOR]),3,IF(AND(C1[COLOR=blue]<5[/COLOR],C1[COLOR=blue]>=2.5[/COLOR]),2,1))[/B]
In G1: [B]=IF(AND(D1[COLOR=blue]>=0[/COLOR],D1[COLOR=blue]<=2[/COLOR]),3,IF(AND(D1[COLOR=blue]>2[/COLOR],D1[COLOR=blue]<=5[/COLOR]),2,1))[/B]
In H1: [B]=CHOOSE(MIN(E1:G1),"Poor","Medium","Good")[/B]
Or if you want to save the extra columns at the expense of making the formula less readable;-
Code:
In E1: [B]=CHOOSE(MIN(IF(AND(B1<=99,B1>=50),3,IF(AND(B1<50,B1>=25),2,1)),IF(AND(C1<=10,C1>=5),3,IF(AND(C1<5,C1>=2.5),2,1)),IF(AND(D1>=0,D1<=2),3,IF(AND(D1>2,D1<=5),2,1))),"Poor","Medium","Good")[/B]
I've highlighted the bits of the formulae where the ranges are tested: you may need to tweak these if the results aren't exactly as you require. For example, what if Cu is 24.5, 49.5 or over 99? There are equal gaps in the ranges for N and Al - what if their value is 11, for example? My formulae assume this would be "Poor".
 
Upvote 0
<br /><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style="font-weight: bold;text-align: right;;">Ident</td><td style="text-align: center;;">Product 1</td><td style="text-align: center;;">Product 2</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style="font-weight: bold;text-align: right;;">Cu</td><td style="text-align: center;;">85</td><td style="text-align: center;;">45</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="font-weight: bold;text-align: right;;">N</td><td style="text-align: center;;">7</td><td style="text-align: center;;">9</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style="font-weight: bold;text-align: right;;">Al</td><td style="text-align: center;;">7.5</td><td style="text-align: center;;">5.2</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="font-weight: bold;text-align: right;;">Quality</td><td style="text-align: center;;">POOR</td><td style="text-align: center;;">POOR</td></tr></tbody></table><br /><br /><table cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">B5</th><td style="text-align:left">=IF(<font color="Blue">OR(<font color="Red">B2<25,B3<2.5,B4>5</font>),"POOR",IF(<font color="Red">OR(<font color="Green">B2<50,B3<5,B4>2</font>),"MEDIUM","GOOD"</font>)</font>)</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">C5</th><td style="text-align:left">=IF(<font color="Blue">OR(<font color="Red">C2<25,C3<2.5,C4>5</font>),"POOR",IF(<font color="Red">OR(<font color="Green">C2<50,C3<5,C4>2</font>),"MEDIUM","GOOD"</font>)</font>)</td></tr></tbody></table></td></tr></table><br />
 
Upvote 0
Or try this:

<b>Excel 2007</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /><col /><col /><col /><col /><col /><col /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th><th>D</th><th>E</th><th>F</th><th>G</th><th>H</th><th>I</th><th>J</th><th>K</th><th>L</th><th>M</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style="font-weight: bold;text-align: center;;">Cu</td><td style="font-weight: bold;text-align: center;;">N</td><td style="font-weight: bold;text-align: center;;">Al</td><td style="font-weight: bold;text-align: center;;">Grade</td><td style="text-align: right;;"></td><td style="font-weight: bold;text-align: center;;">Grade Cu</td><td style="font-weight: bold;text-align: center;;">Grade N</td><td style="font-weight: bold;text-align: center;;">Grade Al</td><td style="text-align: right;;"></td><td style="font-weight: bold;text-align: center;;">Cu</td><td style="font-weight: bold;text-align: center;;">N</td><td style="font-weight: bold;text-align: center;;">Al</td><td style="font-weight: bold;text-align: center;;">Grade</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style="text-align: center;;">22.0</td><td style="text-align: center;;">0.3</td><td style="text-align: center;;">5.5</td><td style="text-align: center;;">Poor</td><td style="text-align: right;;"></td><td style="text-align: center;;">2</td><td style="text-align: center;;">2</td><td style="text-align: center;;">2</td><td style="text-align: right;;"></td><td style="text-align: center;;">-1E+301</td><td style="text-align: center;;">-1E+301</td><td style="text-align: center;;">1E+301</td><td style="text-align: center;;">Invalid</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="text-align: center;;">72.0</td><td style="text-align: center;;">9.1</td><td style="text-align: center;;">10.0</td><td style="text-align: center;;"></td><td style="text-align: right;;"></td><td style="text-align: center;;">4</td><td style="text-align: center;;">4</td><td style="text-align: center;;">2</td><td style="text-align: right;;"></td><td style="text-align: center;;">0.0</td><td style="text-align: center;;">0.0</td><td style="text-align: center;;">10.0</td><td style="text-align: center;;">Poor</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style="text-align: center;;">83.0</td><td style="text-align: center;;">4.6</td><td style="text-align: center;;">9.5</td><td style="text-align: center;;"></td><td style="text-align: right;;"></td><td style="text-align: center;;">4</td><td style="text-align: center;;">3</td><td style="text-align: center;;">2</td><td style="text-align: right;;"></td><td style="text-align: center;;">25.0</td><td style="text-align: center;;">2.5</td><td style="text-align: center;;">5.0</td><td style="text-align: center;;">Medium</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="text-align: center;;">12.0</td><td style="text-align: center;;">6.3</td><td style="text-align: center;;">9.2</td><td style="text-align: center;;"></td><td style="text-align: right;;"></td><td style="text-align: center;;">2</td><td style="text-align: center;;">4</td><td style="text-align: center;;">2</td><td style="text-align: right;;"></td><td style="text-align: center;;">50.0</td><td style="text-align: center;;">5.0</td><td style="text-align: center;;">2.0</td><td style="text-align: center;;">Good</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: center;;">61.0</td><td style="text-align: center;;">5.4</td><td style="text-align: center;;">2.4</td><td style="text-align: center;;"></td><td style="text-align: right;;"></td><td style="text-align: center;;">4</td><td style="text-align: center;;">4</td><td style="text-align: center;;">3</td><td style="text-align: right;;"></td><td style="text-align: center;;">100.0</td><td style="text-align: center;;">10.1</td><td style="text-align: center;;">-0.1</td><td style="text-align: center;;">Invalid</td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style="text-align: center;;">4.0</td><td style="text-align: center;;">2.3</td><td style="text-align: center;;">0.8</td><td style="text-align: center;;"></td><td style="text-align: right;;"></td><td style="text-align: center;;">2</td><td style="text-align: center;;">2</td><td style="text-align: center;;">4</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">8</td><td style="text-align: center;;">60.0</td><td style="text-align: center;;">10.9</td><td style="text-align: center;;">5.5</td><td style="text-align: center;;"></td><td style="text-align: right;;"></td><td style="text-align: center;;">4</td><td style="text-align: center;;">5</td><td style="text-align: center;;">2</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">9</td><td style="text-align: center;;">78.0</td><td style="text-align: center;;">1.9</td><td style="text-align: center;;">6.8</td><td style="text-align: center;;"></td><td style="text-align: right;;"></td><td style="text-align: center;;">4</td><td style="text-align: center;;">2</td><td style="text-align: center;;">2</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">10</td><td style="text-align: center;;">98.0</td><td style="text-align: center;;">5.6</td><td style="text-align: center;;">2.0</td><td style="text-align: center;;">Good</td><td style="text-align: right;;"></td><td style="text-align: center;;">4</td><td style="text-align: center;;">4</td><td style="text-align: center;;">4</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">11</td><td style="text-align: center;;">20.0</td><td style="text-align: center;;">8.6</td><td style="text-align: center;;">11.0</td><td style="text-align: center;;"></td><td style="text-align: right;;"></td><td style="text-align: center;;">2</td><td style="text-align: center;;">4</td><td style="text-align: center;;">1</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">12</td><td style="text-align: center;;">35.0</td><td style="text-align: center;;">5.3</td><td style="text-align: center;;">2.8</td><td style="text-align: center;;"></td><td style="text-align: right;;"></td><td style="text-align: center;;">3</td><td style="text-align: center;;">4</td><td style="text-align: center;;">3</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">13</td><td style="text-align: center;;">29.0</td><td style="text-align: center;;">6.2</td><td style="text-align: center;;">4.0</td><td style="text-align: center;;"></td><td style="text-align: right;;"></td><td style="text-align: center;;">3</td><td style="text-align: center;;">4</td><td style="text-align: center;;">3</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">14</td><td style="text-align: center;;">69.0</td><td style="text-align: center;;">2.4</td><td style="text-align: center;;">7.1</td><td style="text-align: center;;"></td><td style="text-align: right;;"></td><td style="text-align: center;;">4</td><td style="text-align: center;;">2</td><td style="text-align: center;;">2</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">15</td><td style="text-align: center;;">45.0</td><td style="text-align: center;;">10.3</td><td style="text-align: center;;">3.9</td><td style="text-align: center;;"></td><td style="text-align: right;;"></td><td style="text-align: center;;">3</td><td style="text-align: center;;">5</td><td style="text-align: center;;">3</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">16</td><td style="text-align: center;;">25.0</td><td style="text-align: center;;">3.0</td><td style="text-align: center;;">2.3</td><td style="text-align: center;;">Medium</td><td style="text-align: right;;"></td><td style="text-align: center;;">3</td><td style="text-align: center;;">3</td><td style="text-align: center;;">3</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">17</td><td style="text-align: center;;">88.0</td><td style="text-align: center;;">1.1</td><td style="text-align: center;;">5.7</td><td style="text-align: center;;"></td><td style="text-align: right;;"></td><td style="text-align: center;;">4</td><td style="text-align: center;;">2</td><td style="text-align: center;;">2</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">18</td><td style="text-align: center;;">94.0</td><td style="text-align: center;;">6.0</td><td style="text-align: center;;">0.9</td><td style="text-align: center;;">Good</td><td style="text-align: right;;"></td><td style="text-align: center;;">4</td><td style="text-align: center;;">4</td><td style="text-align: center;;">4</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">19</td><td style="text-align: center;;">70.0</td><td style="text-align: center;;">8.8</td><td style="text-align: center;;">1.2</td><td style="text-align: center;;">Good</td><td style="text-align: right;;"></td><td style="text-align: center;;">4</td><td style="text-align: center;;">4</td><td style="text-align: center;;">4</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">20</td><td style="text-align: center;;">84.0</td><td style="text-align: center;;">10.4</td><td style="text-align: center;;">7.0</td><td style="text-align: center;;"></td><td style="text-align: right;;"></td><td style="text-align: center;;">4</td><td style="text-align: center;;">5</td><td style="text-align: center;;">2</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">21</td><td style="text-align: center;;">100.0</td><td style="text-align: center;;">3.0</td><td style="text-align: center;;">0.9</td><td style="text-align: center;;"></td><td style="text-align: right;;"></td><td style="text-align: center;;">5</td><td style="text-align: center;;">3</td><td style="text-align: center;;">4</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">22</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">23</td><td style="text-align: center;;">****</td><td style="text-align: center;;">****</td><td style="text-align: center;;">****</td><td style="text-align: center;;">****</td><td style="text-align: center;;">****</td><td style="text-align: center;;">****</td><td style="text-align: center;;">****</td><td style="text-align: center;;">****</td><td style="text-align: center;;">****</td><td style="text-align: center;;">****</td><td style="text-align: center;;">****</td><td style="text-align: center;;">****</td><td style="text-align: center;;">****</td></tr></tbody></table><p style="width:3.6em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #A6AAB6;border-top:none;text-align: center;background-color: #E0E0F0;color: #161120">Sheet4</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">F2</th><td style="text-align:left">=MATCH(<font color="Blue">A2,J$2:J$6,1</font>)</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">G2</th><td style="text-align:left">=MATCH(<font color="Blue">B2,K$2:K$6,1</font>)</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">H2</th><td style="text-align:left">=MATCH(<font color="Blue">C2,L$2:L$6,-1</font>)</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">D2</th><td style="text-align:left">=IF(<font color="Blue">SQRT(<font color="Red">MATCH(<font color="Green">A2,J$2:J$6,1</font>)*MATCH(<font color="Green">B2,K$2:K$6,1</font>)</font>)=MATCH(<font color="Red">C2,L$2:L$6,-1</font>),INDEX(<font color="Red">$M$2:$M$6,MATCH(<font color="Green">A2,J$2:J$6,1</font>)</font>),""</font>)</td></tr></tbody></table></td></tr></table><br />
Markmzz
 
Last edited:
Upvote 0

Forum statistics

Threads
1,224,544
Messages
6,179,430
Members
452,915
Latest member
hannnahheileen

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