Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Where Is that Text?.
Written by Allen Wyatt (last updated October 16, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Jay needs to determine the cell in which a particular text value occurs. He knows he can use Excel's Find and Replace capabilities to manually determine the address of cells containing a text value, but he is looking for a formula to determine the address of the cells. He wonders if there is a way to search for piece of text within a range and have Excel return the address of the cell in which the text is found.
There are two things you can try. First, if you are looking for an exact match for cell contents, then you can use a formula. The basic formula is this:
=ADDRESS(MATCH(C2,A:A,0),1)
In this example, cell C2 contains the value you are looking for and column A is the range of cells being searched. The formula returns a result regardless of the capitalization of C2 or the values in column A. Thus, if C2 contains "apple", then the formula will match positively to cells that contain "apple," "Apple," or "APPLE." Indeed, any mix of capitalization will match.
This formula will not return an address for a cell that contains what you are searching for amidst other text. So if you are searching for "apple" (cell C2), it won't return the address of a cell that contains the phrase "apple crisp." You can modify this behavior, a bit, by adding wild card characters to the search cell. For instance, if you search for "*apple*" then the formula returns the address of a cell that contains "apple", even if it is preceded or followed by other characters.
It should be pointed out that this formula only returns the address of the first cell in the range which meets the criteria. If you actually want the addresses of all cells that meet the criteria, then you'll need to rely on a macro. The following is a good example:
Function FindMe(x As Range, y As String) As String Dim r As Range Dim sResults As String Dim sSearch As String Application.Volatile sSearch = LCase(y) For Each r In x If InStr(1, LCase(CStr(r.Value)), sSearch) > 0 Then sResults = sResults & r.Address & ", " End If Next r If Len(sResults) > 2 Then FindMe = Left(sResults, Len(sResults) - 2) Else FindMe = "" End If End Function
You use the function by simply providing the range you want to search along with what you want to search for:
=FindMe(A:A, "apple")
If you use a large range (as in this example—all of column A), then don't be surprised if the function takes a noticeable amount of time to return a result. This makes sense, as it has to search through every cell in the range, regardless of whether there is anything in the cell or not.
You also don't need to use any wildcards with this function; it assumes that a match occurs if what you are looking for is located anywhere within the cell. It also doesn't pay attention to the capitalization of what you are looking for or the capitalization of anything in the search range.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10083) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Where Is that Text?.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!
If you need to generate a random sequence of characters, of a fixed length, then you'll appreciate the discussion in this ...
Discover MoreIn a series of values, you may need to know the smallest value that isn't a zero. There is no built-in function to do ...
Discover MoreDo you want Excel to take the case of your text into account when it does comparisons in a formula? The IF statement ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2020-02-06 10:10:42
Gary
That is great Peter- thanks a lot!!
Gary
2020-02-05 14:55:11
Peter Atherton
Gary,
If you insert the second line above the first the function will return a zero length string (Not a Blank)
sSearch = LCase(y)
If Len(y) = 0 Then Exit Function
Peter
2020-02-05 10:20:25
Gary
Thank you Peter! That worked. I would definitely add this bit of information to the instructions above. Also, if the cell containing the text I want to find is blank, it just returns the addresses of every cell in the range. It would better if the function gave you an option for an alternate value if the cell is blank.
Gary
2020-02-04 13:58:37
Peter Atherton
Gary,
You need to include the full path to the Personal workbook. Click the Function Insert button at the left of the formula Bar and drill down to User Defined category and insert the function from there and Excel will include the full path for you.
2020-02-03 18:51:51
Gary
I tried adding this code to a module in my Personal workbook, however, when I attempt to use the function I get a #NAME? error. What might be the problem?
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments