Getting a List of Matching Cells

Written by Allen Wyatt (last updated May 18, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021


3

When Michael does a "Find All" operation in Excel, the program helpfully shows a list of all the cells containing whatever he is searching for. Michael would like to copy that list of cell addresses into another worksheet, so he wonders if there is a way to copy the list to the Clipboard so he can paste it into a worksheet.

There are a few ways you can accomplish this task, and most of them involve the use of macros. Before getting to the macro-based approaches, however, let's take a look at way you could access the addresses using named ranges and the Name Manager:

  1. Use FindAll as before, but don't close the Find and Replace dialog box.
  2. In the list of addresses you are shown, scroll to the bottom, hold down the Shift key, and click on the last match. Excel selects all the matching cells.
  3. Press Esc to close the Find and Replace dialog box. The matching cells are still all selected.
  4. Type a name in the Name Box (just to the left of the Formula bar and just above cell A1). This creates a named range that consists of all the selected cells.
  5. Display the Formulas tab of the ribbon.
  6. Click the Name Manger tool. Excel displays the Name Manager's dialog box. (See Figure 1.)
  7. Figure 1. The Name Manager dialog box.

  8. Click on the name you created in step 4.
  9. The list of cells will be in the Refers To box, at the bottom of the dialog box.

At this point you can copy the information in the Refers To box and paste it into whatever you want (including another worksheet). You'll need to massage the data a bit after you paste it, as the list is just that—a serial list of cell addresses.

Obviously, this affects your workbook, as it creates a named range. If you do it multiple times, you'll have multiple named ranges created. This can, of course, quickly get unwieldy if you need to perform the task quite often. This is where the macro solutions come into play. The following is an example of a macro that will search for a specific value and then place the address of every cell containing that value into another worksheet.

Sub CellAdressList()
    Dim c1 As String
    Dim nxt As String

    Sheets("Sheet1").Select
    Range("A1").Select
    Cells.Find(What:="qrs", After:=ActiveCell, _
      LookIn:=xlValues, LookAt:=xlWhole, _
      SearchOrder:=xlByRows, SearchDirection:=xlNext, _
      MatchCase:=False, SearchFormat:=False).Activate
    c1 = ActiveCell.Address
    Sheets("Sheet2").Select
    Range("A1").Select
    Range("A1").Value = c1
    Do Until nxt = c1
        Sheets("Sheet1").Select
        Cells.FindNext(After:=ActiveCell).Activate
        nxt = ActiveCell.Address
        Sheets("Sheet2").Select
        ActiveCell.Offset(1, 0).Select
        ActiveCell.Value = nxt
    Loop
    ActiveCell.Value = ""
End Sub

The macro makes a few assumptions. First, it assumes that you are searching for information on the worksheet named Sheet1. Second, it assumes you want the list of addresses placed in the worksheet named Sheet2. Finally, it assumes you are searching for the value "qrs" within Sheet1. All of these elements of the macro can be changed, if desired.

For something just a bit more flexible, consider the following macro. It assumes that you have already selected all the cells that contain the value you want. (In other words, you need to perform steps 1 through 3 of the steps near the beginning of this tip.) You can then run the macro.

Sub CopyFindAllSelection()
    Dim outcell As Range
    Dim c As Range

    Set outcell = Range("Sheet2!A1")
    For Each c In Selection
        outcell.Value = c.Address
        Set outcell = outcell.Offset(1, 0)
    Next
End Sub

The result is that the addresses of the selected cells are placed into the Sheet2 worksheet. This macro is a bit more flexible because it allows you to find anything in any worksheet. The only part "hard coded" is the worksheet (Sheet2) into which the addresses are placed.

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13581) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Getting Rid of Automatic Page-Break Lines

A little trick to get rid of pagination marks when you have background pagination turned off.

Discover More

Increasing Font Size In Worksheet Tabs

While Excel does not have an intrinsic way to change the font in on a worksheet tab, Windows does.

Discover More

Hiding Macros

Need to hide some macros in your workbook? There are three ways you can do it, as covered in this discussion.

Discover More

Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!

More ExcelTips (ribbon)

Replacing Tildes at the Beginning of a Cell

Replacing a specific character (such as a tilde) seems a simple task, until you need to replace it only in a certain ...

Discover More

Inconsistent Behavior of Find and Replace Dialog Box

The Find and Replace feature in Excel is one of the workhorse editing tools you can use. When the Find and Replace dialog ...

Discover More

Making All Occurrences Bold

Want to make instances of a given word or phrase bold throughout a worksheet? Here's a way you can make the change quickly.

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is 6 - 0?

2024-05-22 11:19:38

J. Woolley

The CopyFindAllResults macro in My Excel Toolbox will duplicate the 6 columns of the Find dialog's Find All results for the active worksheet's current selection and copy those results to the clipboard and/or a new worksheet in the active workbook. When results are added to a new worksheet, the macro can replace the Name column with a column of hyperlinks to each cell in the list.
See https://sites.google.com/view/MyExcelToolbox/


2024-05-20 11:28:47

J. Woolley

Re. the Tip's CopyFindAllSelection macro, here are two alternate versions that require the following procedure:
1. Press Ctrl+F to open the Find... dialog
2. Enter the Find criteria
3. Click the Find All button
4. Press Ctrl+A to select the active sheet's results
5. Immediately run the macro
Notice these macros copy only the active sheet's results. However, these macros will copy similar results for the current selection on any active sheet.

The following version copies the list of cell addresses to the clipboard for pasting into a worksheet or other document. In the Visual Basic Editor, pick Tools > References (Alt+T+R) and enable the Microsoft Forms...Library.

Sub CopyFindAllSelection2()
    Dim c As Range, FindAll As String
    Const Ex As Boolean = False
    'make Ex True for complete addresses like [Book1.xlsx]Sheet1!$A$1
    For Each c In Selection
        FindAll = FindAll & c.Address(External:=Ex) & vbLf
    Next
    'pick Tools > References (Alt+T+R) and enable Microsoft Forms...Library
    With New MSForms.DataObject
        .SetText Left(FindAll, (Len(FindAll) - 1))
        .PutInClipboard
    End With
End Sub

The following version copies all 6 columns of the Find All results and puts them in a new worksheet added after the workbook's last sheet.

Sub CopyFindAllSelection3()
    Dim nRows As Integer, n As Integer, k As Integer, cell As Range
    nRows = Selection.Cells.Count + 1
    ReDim FindAll(0 To nRows, 0 To 5) As String
    For n = 0 To 5
        FindAll(0, n) = Split("Book Sheet Name Cell Value Formula")(n)
    Next n
    n = 0
    For Each cell In Selection
        With cell
            n = n + 1
            FindAll(n, 0) = .Parent.Parent.Name
            FindAll(n, 1) = .Parent.Name
            On Error Resume Next
            FindAll(n, 2) = .Name.Name
            On Error GoTo 0
            k = InStrRev(FindAll(n, 2), "!") + 1
            If k > 1 Then FindAll(n, 2) = Mid(FindAll(n, 2), k)
            FindAll(n, 3) = .Address
            FindAll(n, 4) = CStr(.Value)
            If TypeName(.Value) = "Boolean" Then _
                FindAll(n, 4) = UCase(FindAll(n, 4))
            If .HasFormula Then FindAll(n, 5) = .Formula
        End With
    Next
    Worksheets.Add After:=Sheets(Sheets.Count)
    Cells(1).Resize(nRows, 6) = FindAll
    ActiveSheet.Columns.AutoFit
End Sub


2024-05-18 08:35:37

Alex Blakenburg

In using the initial manual Find method, Ctrl+A is an easier way to select all the matching records replacing -->
"2 In the list of addresses you are shown, scroll to the bottom, hold down the Shift key, and click on the last match. Excel selects all the matching cells."


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.