Search for multiple text within a cell and return text

baggers719

Board Regular
Joined
Sep 18, 2009
Messages
104
I'm trying to do multiple text searches in a cell and return text if true. If not true then I want the cell to be blank.

For example

Column A is PaymentNotFound12345 and I want the formula in column B to search for "PaymentNot" and return "PaymentNot". However I need to also search for other text examples such as PaymentDone12345 and it to return "Payment" if true and again blank if false. Column A has built items I want to search for and return if true.

Any ideas. I'm trying to use IFS and FIND functions, it only returns the first search.

Thanks,

Sean.
 

Excel Facts

Best way to learn Power Query?
Read M is for (Data) Monkey book by Ken Puls and Miguel Escobar. It is the complete guide to Power Query.
So what happens in column B when it finds more than one of the search terms?
do you have a list of these search terms?
does it have to be a formula or does VBA work?
 
Upvote 0
So column B has a list of terms. Could either have "PaymentNotFound12345, PaymentNotFound23456, PaymentDone12345. These are just examples. I want to search for all of these and return text I mentioned above. There is a large list of searches that I can keep adding to. I am just trying to set up so it will work for more than one.

This is kind of where I was going..

=IFS(FIND("Carton",N23),"Carton",FIND("Shortpay",N23),"Shortpay","")

The above has different searches but should give an idea.

Would like it in a formula.
 
Upvote 0
The formula above is obviously searching for shortpay and carton instead and trying to return that if either is present in the cell N23.
 
Upvote 0
Try this:


Book1
ABCDE
1TextLook forReturn
2PaymentNotFound12345PaymentNotPaymentNotPaymentNot
3PaymentDone12345PaymentPaymentDonePayment
4The big carton is redCartonShortPayNot enough
5AShortPay9999Not enoughCartonCarton
6Something elsexxx
7CartonPaymentDoneCartonxxx
8xxx
Sheet8
Cell Formulas
RangeFormula
B2=IFERROR(LOOKUP(2^16,SEARCH($D$2:$D$8,A2),$E$2:$E$8),"")


If you want to make the table in D2:E8 bigger so that you can just add some new terms later, you need to put XXX in the empty rows, otherwise it doesn't work right. Also look at row 7. As Blake mentioned, what do you want to do if there's more than 1 match? Here you get the last match from the list. If you want all of the matches, via a formula, you'd need TEXTJOIN.
 
Upvote 0

Forum statistics

Threads
1,223,881
Messages
6,175,161
Members
452,615
Latest member
bogeys2birdies

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