Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Searching for a Value Using a Function.
Written by Allen Wyatt (last updated January 1, 2020)
This tip applies to Excel 97, 2000, 2002, and 2003
Thor wonders if there is a way to perform a lookup without having to specify a specific column or row and having the result be the address of the cell at which the value is found. For instance, he wants to look up a value (such as 345 or "my text") and have the function search all the cells in all the worksheets in the workbook and return the full address of the cell in which the value was found.
The approach you use will be dictated by the range you want to search. If you want to search on the same worksheet on which you want the answer displayed, then you can use a formula, such as the following:
=ADDRESS(MAX(ROW(1:5)*(A1:E5="my text")), MAX(COLUMN(A1:E1)*(A1:E5="my text")),4)
This should be entered as an array formula (press Ctrl+Shift+Enter), and it only searches in the range A1:E5. You can, if desired, change the range by adjusting the formula appropriately.
A larger search area would be to look at an entire worksheet. This can still be done using an array formula, such as the following:
=ADDRESS(MAX(ROW(Sheet1!1:65000)*(IF(Sheet1!1:65000=$A$1,1,0))), MAX(COLUMN(Sheet1!$1:$65000)*IF(Sheet1!1:65000=$A$1,1,0)))
The formula assumes that what you are looking for is stored in cell A1. You should change the Sheet1 designation to the name of whatever worksheet you want searched.
If you want to search a wider range, such as all the worksheets in a workbook, then the best solution is to use a macro that calls upon the Find function within Excel.
Function FindAddr(vValue As Variant) Dim wks As Worksheet Dim rCell As Range Dim bFound As Boolean bFound = False For Each wks In ActiveWorkbook.Worksheets With wks Set rCell = .Cells.Find _ (What:=vValue, After:=.Cells(1), _ LookIn:=xlValues, LookAt:=xlWhole, _ SearchOrder:=xlByRows, _ SearchDirection:=xlNext, _ MatchCase:=False) If Not rCell Is Nothing Then bFound = True Exit For End If End With Next If bFound Then FindAddr = wks.Name & "!" & _ rCell.Address(False, False) Else FindAddr = "Not Found" End If Set wks = Nothing Set rCell = Nothing End Function
This function is designed to be called from another macro, which passes it whatever should be searched for in the vValue parameter. The function returns either the full address (including worksheet name) of the first match, or it returns "Not Found" if there was no match.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3807) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Searching for a Value Using a Function.
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!
When compiling statistics on a collection of data points, you may want to know whether a particular value is the "highest ...
Discover MoreIf you have a bunch of ZIP Codes or part numbers in a list, you may want to "condense" the list so that sequential series ...
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 MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon 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