• Hi All

    Please note that at the Chandoo.org Forums there is Zero Tolerance to Spam

    Post Spam and you Will Be Deleted as a User

    Hui...

  • When starting a new post, to receive a quicker and more targeted answer, Please include a sample file in the initial post.

Finding a string from a cell and resulting the matched string

navi1620

New Member
Hello All,

Need help with below situation

I've data available in a cell (say A1) as below:
abc|bcd|xyz|prq|uvw

Iam looking for a logic where I can search list of strings (say bcd or pqr) from A1 and get the matched string (say bcd) as a result in B1 cell (formula to be entered B1).
 
@navi1620

Here is one formula that returns the first matching text by looking up A1 against a range of cells in E1:E3. This will return #N/A if no matches found. So you may want to wrap it in IFERROR

=INDEX($E$1:$E$3,MATCH(FALSE, ISERROR(FIND($E$1:$E$3,A1)),0))
(Array formula, Press Ctrl+Shift+Enter to get result)

I am pretty sure there will be few other ways to solve this. So watch out for replies and pick the one that you are most comfortable with.
 
Hi:

May be something like this?

=LOOKUP(2^15,SEARCH($D$1,A1),$D$1)

Thanks
 

Attachments

  • Book1.xlsx
    8.2 KB · Views: 5
@navi1620

Here is one formula that returns the first matching text by looking up A1 against a range of cells in E1:E3. This will return #N/A if no matches found. So you may want to wrap it in IFERROR

=INDEX($E$1:$E$3,MATCH(FALSE, ISERROR(FIND($E$1:$E$3,A1)),0))
(Array formula, Press Ctrl+Shift+Enter to get result)

I am pretty sure there will be few other ways to solve this. So watch out for replies and pick the one that you are most comfortable with.
Thank you
 
@navi1620
This formula works based on the maximum character a cell can hold in excel and search function.

SEARCH searches for the value D1 in f the cell A1. It returns the position number of the start of that value if found. The largest number of characters allowed in a cell is 32767 or 2^15-1

Having a lookup value of 2^15 therefore guarantees that the value will be larger than anything that SEARCH returns, this means that you get a match with the last cell that contains D1.

Thanks
 
An alternative VBA solution would be:
Code:
Option Explicit

Sub findString()
Dim x As String, y As Long
x = InputBox("What String to find")
y = InStr(1, ActiveCell, x)
ActiveCell.Offset(0, 1) = y
End Sub
 
Back
Top