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
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:
Figure 1. The Name Manager 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:
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.
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 doing searches in Excel, you can use wildcard characters in the specification of what you are searching. However, ...
Discover MoreIf you use a worksheet that contains dates, you might want to search for those dates at some point. This isn't as simple ...
Discover MoreExcel worksheets can contain all sorts of data. One thing you might store in a worksheet is a range of Boolean (TRUE or ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
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."
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