Multiple Criteria Search Array Formula - Not Working!

jonsharman

New Member
Joined
Jan 4, 2014
Messages
28
Hi,

I have an array formula that I am trying to use to find specific order numbers based on a free-text search across a three-column table. The formula I am using is:

=IFERROR(INDEX($A$2:$D$14, SMALL(IF(ISERROR(SEARCH($F$4,$B$2:$D$14)*SEARCH($F$3,$B$2:$D$14)*SEARCH($F$2,$B$2:$D$14)), "", ROW(A2:A14)-MIN(ROW(A2:A14))+1), ROW(A1)), COLUMN(A1)),"")

And the data is laid out like so:

ORDERFIRSTSECONDTHIRDSEARCHRESULTS
3604955Media Pack XLChili Pack Criteria 1chili3604955
3685809John Cooper Works Chili Pack Criteria 2 3685809
3686844John Cooper Works Chili PackMedia Pack XL Criteria 3 3686844
3725450Chili Pack 3725450
3727043John Cooper Works Chili PackMedia Pack XL 3727043
3755662John Cooper Works Chili PackMedia Pack XLMINI Tech Pack3755662
3725404Chili Pack 3725404
3738095Chili Pack 3738095
3761426MINI Sport PackMINI JCW Sport Pack 3762543
3762543Chili Pack 3785108
3767979Pepper Pack
3773225Pepper Pack
3785108Chili Pack

<colgroup><col><col><col><col><col span="2"><col></colgroup><tbody>
</tbody>

This fills down to give the results. With one criteria (chili, john, pepper etc.) it is showing the correct order numbers. The issue when I start free-typing into the second criteria box there are no results returned e.g if I type in 'XL' into cell F3 the results column goes blank when in fact I want it to show all order numbers that have the instances of 'chili' and 'xl' within them. I've have tried an AND statement but that doesn't seem to help because the cells may be blank that I am searching ... ?

Can anyone see where I am going wrong?

Thanks
 

Excel Facts

Lock one reference in a formula
Need 1 part of a formula to always point to the same range? use $ signs: $V$2:$Z$99 will always point to V2:Z99, even after copying
Try changing ISERROR to ISNUMBER.

Edit: Never mind, that does not produce the result that I was expecting. Working on it.
 
Last edited:
Upvote 0
Hi,

Your Array Formula is using the sign * (multiply) which within an array formula means AND ...

So for example ... just add XL to one Chili pack ... and you will get a result ...

In my opinion, it is only a confusion with what you are looking for ... which is OR ...

Within array formulas ... to mean OR, you need to use the + sign ...

Hope this explanation clarifies the matter ...
 
Upvote 0
I tried with the '+' originally but that just gives the same output ... ??? As soon as I enter a second criteria everything disappears as if it giving a false result but I can't spot it.

What effect does the ISNUMBER have?
 
Last edited:
Upvote 0
You can test

Code:
=IFERROR(INDEX($A$2:$D$14, SMALL(IF(ISERROR(SEARCH($F$2,$B$2:$D$14)), "", ROW(A2:A14)-MIN(ROW(A2:A14))+1), ROW(A1)), COLUMN(A1)),0)+IFERROR(INDEX($A$2:$D$14, SMALL(IF(SEARCH($F$3,$B$2:$D$14)), "", ROW(A2:A14)-MIN(ROW(A2:A14))+1), ROW(A1)), COLUMN(A1)),0)+IFERROR(INDEX($A$2:$D$14, SMALL(IF(ISERROR(SEARCH($F$4,$B$2:$D$14)), "", ROW(A2:A14)-MIN(ROW(A2:A14))+1), ROW(A1)), COLUMN(A1)),0)
 
Upvote 0
Here is one option using a helper column:


Excel 2010
ABCDEFGHI
1ORDERFIRSTSECONDTHIRDHelperSEARCHRESULTS
23604955Media Pack XLChili PackTRUECriteria 1chili3604955
33685809John Cooper Works Chili PackFALSECriteria 2XL3686844
43686844John Cooper Works Chili PackMedia Pack XLTRUECriteria 33727043
53725450Chili PackFALSE3755662
63727043John Cooper Works Chili PackMedia Pack XLTRUE
73755662John Cooper Works Chili PackMedia Pack XLMINI Tech PackTRUE
83725404Chili PackFALSE
93738095Chili PackFALSE
103761426MINI Sport PackMINI JCW Sport PackFALSE
113762543Chili PackFALSE
123767979Pepper PackFALSE
133773225Pepper PackFALSE
143785108Chili PackFALSE
Sheet2
Cell Formulas
RangeFormula
E2=AND(COUNTIF(B2:D2,"*"&$H$2&"*"),COUNTIF(B2:D2,"*"&$H$3&"*"),COUNTIF(B2:D2,"*"&$H$4&"*"))
I2{=IFERROR(INDEX($A$2:$A$14,SMALL(IF($E$2:$E$14=TRUE,ROW($A$2:$A$14)-1),ROWS(A$1:A1))),"")}
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Upvote 0
63falcondude,

Excellent - works a charm! Would there be any disadvantage to using a Helper column over trying to get the formula into one movement? I guess with the Helper column it is easier to add more search criteria?
 
Upvote 0
63falcondude,

Excellent - works a charm! Would there be any disadvantage to using a Helper column over trying to get the formula into one movement? I guess with the Helper column it is easier to add more search criteria?

The only disadvantage of using a helper column in this case is that you have an extra column in your worksheet. You can always hide the column if you want to.

The use of the helper column simplifies things greatly and makes it easier to add more search criteria (you would only have to change the helper column formula).
 
Upvote 0

Forum statistics

Threads
1,215,491
Messages
6,125,107
Members
449,205
Latest member
ralemanygarcia

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