Excel advanced formula

mcoll

New Member
Joined
Sep 12, 2014
Messages
2
Here's the thing:
I'm making a list of all threatened species found in Conservation Units of Sao Paulo (Brazil). There are a few categories that species can be included when we talk about their conservation status:
- EX (Extinct);
- EW (Extinct in the Wild);
- CR (Critically Endangered);
- EN (Endangered);
- VU (Vulnerable);

There are 11 criteria. Every threatened specie has one or more criteria that defines its conservation status. For example: Habenaria schwackei (Barb. Rodr.) has criteria 3, 4 and 9. Thus it is an EN (Endangered) specie.

To define which category the specie belongs, we consider the following criteria:
- If it presents Criterion 1 = EX
- If it presents Criterion 2 = EW
- If it presents Criteria 3 AND 4 AND X AND Y other criterias (both between 6 and 11) = CR
- If it presents (a) Criteria 3 AND 4 AND X other criterion (between 6 and 11) OR (b) Criteria 3 OR 4 AND X AND Y other criterias (both between 6 and 11) = EN
- If none of those = VU.


Is there a formula that can represent this idea on Excel?


Thanks a lot!
 
Last edited:

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.

BiocideJ

Well-known Member
Joined
Jan 23, 2012
Messages
1,733
It certainly should be possible with some IF statements, however, more information is needed.
How is your criteria stored in Excel now?
Are there 11 columns with some sort of marker in them:
i.e.
Specie</SPAN>Status</SPAN>Criteria1</SPAN>Criteria2</SPAN>…</SPAN>Criteria11</SPAN>
A</SPAN>??</SPAN>YES</SPAN>NO</SPAN>NO</SPAN>

<TBODY>
</TBODY><COLGROUP><COL><COL><COL span=4></COLGROUP>


or is the Criteria data stored in a single cell as text
i.e.
Specie</SPAN>Status</SPAN>Critiera</SPAN>
B</SPAN>??</SPAN>3,4,9</SPAN>

<TBODY>
</TBODY><COLGROUP><COL><COL><COL></COLGROUP>



This information is necessary to develop a solution without wasting time.
 

mcoll

New Member
Joined
Sep 12, 2014
Messages
2
The criteria data is stored like this:


SpecieCRCRCRCRCRstatus
A349??
B1??
C349...11??

<tbody>
</tbody>

All those "CR" are, actually, merged in one cell, called "Criteria"

I can arrange cells in your first arrangement suggested, if necessary. i.e.

SpecieStatusCriteria1Criteria2Criteria11
A??YESNONO

<tbody>
</tbody>
 
Last edited:

BiocideJ

Well-known Member
Joined
Jan 23, 2012
Messages
1,733
OK, given you can adjust the data in columns A:L as I outline below, the following formula should work.
Formula pasted in cell M2 and dragged down
=IF(B2,"EX",IF(C2,"EW",IF(AND(D2,E2,SUMPRODUCT(--(G2:L2))>=2),"CR",IF(OR(AND(D2,E2,SUMPRODUCT(--(G2:L2))>=1),AND(OR(D2,E2),SUMPRODUCT(--(G2:L2))>=2)),"EN","VU"))))


A</SPAN>
B</SPAN>
C</SPAN>
D</SPAN>
E</SPAN>
F</SPAN>
G</SPAN>
H</SPAN>
I</SPAN>
J</SPAN>
K</SPAN>
L</SPAN>
M</SPAN>
1</SPAN>
Specie</SPAN>
Criteria1</SPAN>
Criteria2</SPAN>
Criteria3</SPAN>
Criteria4</SPAN>
Criteria5</SPAN>
Criteria6</SPAN>
Criteria7</SPAN>
Criteria8</SPAN>
Criteria9</SPAN>
Criteria10</SPAN>
Criteria11</SPAN>
Status</SPAN>
2</SPAN>
A</SPAN>
TRUE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
EX</SPAN>
3</SPAN>
B</SPAN>
FALSE</SPAN>
TRUE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
EW</SPAN>
4</SPAN>
C</SPAN>
FALSE</SPAN>
FALSE</SPAN>
TRUE</SPAN>
TRUE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
TRUE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
TRUE</SPAN>
CR</SPAN>
5</SPAN>
D</SPAN>
FALSE</SPAN>
FALSE</SPAN>
TRUE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
TRUE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
TRUE</SPAN>
EN</SPAN>
6</SPAN>
E</SPAN>
FALSE</SPAN>
FALSE</SPAN>
TRUE</SPAN>
TRUE</SPAN>
FALSE</SPAN>
TRUE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
EN</SPAN>
7</SPAN>
F</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
VU</SPAN>
8</SPAN>
G</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
VU</SPAN>
9</SPAN>
H</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
FALSE</SPAN>
VU</SPAN>

<TBODY>
</TBODY>

Note: The FALSE values are unnecessary and for ease of reading, can be replaced with "", but the TRUE values must be the logical result of some formula and not a TEXT value of 'TRUE
 
Last edited:
Master Excel Bundle

Excel contains over 450 functions, with more added every year. That’s a huge number, so where should you start? Right here with this bundle.

Forum statistics

Threads
1,164,382
Messages
5,836,931
Members
430,463
Latest member
mikmob

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
Top