Finding MIN text value from array excluding certain specified values

logonwheeler

New Member
Joined
Feb 1, 2014
Messages
17
I am looking to return the MIN alphabetical text value from a list, with certain values excluded.

I am currently using an array formula like this one to return the MIN alphabetical value in array A1:A9:

=INDEX($A$1:$A$9,MATCH(0,COUNTIF($A$1:$A$9,">"&$A$1:$A$9),)) (+ CSE)
Returns the value A

However, I would like to return the MIN alphabetical value in the array EXCLUDING all A & D values. This result should return the value B.

Can anyone suggest a nice way to achieve this? :confused:

Data Set:
1 A
2 D
3 A
4 C
5 B
6 D
7 C
8 B
9 A
 
Apologies. Noticed an error in my formula. Should be:

=IFERROR(INDEX($A$1:$A$9,MATCH(SMALL(IF(MMULT(--(ISNUMBER(FIND({"A","D"},$A$1:$A$9))),{1;1})=0,COUNTIF($A$1:$A$9,"<"&$A$1:$A$9)),ROWS($1:1)),COUNTIF($A$1:$A$9,"<"&$A$1:$A$9),0)),"")

Regards

This formula works really well. Thanks for providing this solution.

Now - let's add to it. What if I want to find any value in a range, let's say from $C$1:$C$5. I tried to change

Code:
...FIND({"A","D"},...

to

Code:
...FIND({"A","B","D"},...

(this produced an error)

to

Code:
...FIND($C$1:$C$5,...

without any luck.

Any chance we can enhance the functionality of the formula to exclude any elements in a range? To make things even easier, we can name the range $C$1:$C$5 as "EXCLUDELIST" or something similar.
 
Upvote 0

Excel Facts

When they said...
When they said you are going to "Excel at life", they meant you "will be doing Excel your whole life".
No worries. Just change to:

=IFERROR(INDEX($A$1:$A$9,MATCH(SMALL(IF(MMULT(--(ISNUMBER(FIND(TRANSPOSE(
$C$1:$C$5),$A$1:$A$9))),ROW($C$1:$C$5)^0)=0,COUNTIF($A$1:$A$9,"<"&$A$1:$A$9)),ROWS($1:1)),COUNTIF($A$1:$A$9,"<"&$A$1:$A$9),0)),"")

Change the ranges in red as required.

Regards
 
Upvote 0
P.S. You never answered my question about whether we were looking for matches with entire cell contents, e.g. "A", "D", etc., or with locating those letters anywhere within the string, e.g. if the string is "Add" or "O' Driscoll" then it is not to be considered.

Although the solution I gave you should work in the former case as well, in that case it would be unnecessarily complicated, and so a solution such as Aladin's would be far more efficient.

Could you please clarify this (important) point?

Regards
 
Upvote 0
P.S. You never answered my question about whether we were looking for matches with entire cell contents, e.g. "A", "D", etc., or with locating those letters anywhere within the string, e.g. if the string is "Add" or "O' Driscoll" then it is not to be considered.

Although the solution I gave you should work in the former case as well, in that case it would be unnecessarily complicated, and so a solution such as Aladin's would be far more efficient.

Could you please clarify this (important) point?

Regards

XOR - Sorry, I should have replied sooner.

I am looking to exclude the entire cell contents, not just any letter or number contained within the cell's contents. IOW I need EXACT match for an exclusion.

Does that clarify?
 
Upvote 0
No worries. Just change to:

=IFERROR(INDEX($A$1:$A$9,MATCH(SMALL(IF(MMULT(--(ISNUMBER(FIND(TRANSPOSE(
$C$1:$C$5),$A$1:$A$9))),ROW($C$1:$C$5)^0)=0,COUNTIF($A$1:$A$9,"<"&$A$1:$A$9)),ROWS($1:1)),COUNTIF($A$1:$A$9,"<"&$A$1:$A$9),0)),"")

Change the ranges in red as required.

Regards

Just tried this solution and it works out well - however only if my list contains alphanumeric or alpha characters only.

Here is an example that does not return the correct result:
Code:
=IFERROR(INDEX($A$1:$A$9,MATCH(SMALL(IF(MMULT(--(ISNUMBER(FIND(TRANSPOSE($C$1:$C$4),$A$1:$A$9))),ROW($C$1:$C$4)^0)=0,COUNTIF($A$1:$A$9,"<"&$A$1:$A$9)),ROWS($1:1)),COUNTIF($A$1:$A$9,"<"&$A$1:$A$9),0)),"")

Data Set:
VALUESRESULTEXCLUSION LIST
COMP EVALCOMP EVALP5
COMP EVALCOMP EVAL
P5P2
P4P1
1
P3-2
P2
P1
PROTOTYPE

<tbody>
</tbody>

Any ideas?
 
Upvote 0
"XOR - Sorry, I should have replied sooner.

I am looking to exclude the entire cell contents, not just any letter or number contained within the cell's contents. IOW I need EXACT match for an exclusion.

Does that clarify?
"

Ah, then it will be a solution along the lines of Aladin's. And I apologise for having misinterpreted your original question.

Regards
 
Upvote 0
Assuming that A2:A10 contains the data, and C2:C5 contains the exclusion list, try the following formula that needs to be confirmed with CONTROL+SHIFT+ENTER...

=IF(SUM(IF((A2:A10<>"")*(ISNA(MATCH(A2:A10,C2:C5,0))),1))>0,INDEX(A2:A10,MATCH(MAX(MMULT(IF(A2:A10<>"",IF(ISNA(MATCH(A2:A10,C2:C5,0)),(A2:A10<=TRANSPOSE(A2:A10))+0,0),0),ROW(A2:A10)^0)),MMULT(IF(A2:A10<>"",IF(ISNA(MATCH(A2:A10,C2:C5,0)),(A2:A10<=TRANSPOSE(A2:A10))+0,0),0),ROW(A2:A10)^0),0)),"N/A")

Hope this helps!
 
Upvote 0
Maybe...



A

B

C

1

VALUES​

RESULT​

EXCLUSION LIST​

2

COMP EVAL​

1​

P5​

3

COMP EVAL​

COMP EVAL​

4

P5​

P2​

5

P4​

P1​

6

1​

7

P3-2​

8

P2​

9

P1​

10

PROTOTYPE​

<TBODY>
</TBODY>


B2
=INDEX($A$2:$A$10,MATCH(MIN(IF(ISNA(MATCH($A$2:$A$10,$C$2:$C$5,0)),COUNTIF($A$2:$A$10,"<"&$A$2:$A$10&" "))),COUNTIF($A$2:$A$10,"<"&$A$2:$A$10&" "),0))

Ctrl+Shift+Enter

M.
 
Upvote 0

Forum statistics

Threads
1,215,972
Messages
6,128,029
Members
449,414
Latest member
sameri

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