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: Identifying Merged Cells.
Written by Allen Wyatt (last updated July 28, 2018)
This tip applies to Excel 97, 2000, 2002, and 2003
Alan asked if there is a way to quickly and easily identify which cells are merged in a workbook created by someone else. There are, in reality, several different ways you can go about identifying these cells.
One method for identifying the cells is to use Excel's searching capabilities. Follow these steps:

Figure 1. The Find tab of the Find and Replace dialog box.

Figure 2. The Alignment tab of the Find Format dialog box.
Excel searches for any merged cells and if they are located, the cells are displayed in the bottom of the Find and Replace dialog box. You can then select one of the found ranges and the corresponding range is selected in the worksheet.
If you prefer, you can a macro to find the various merged cells in the worksheet. The following macro shows perhaps the simplest method of doing this:
Sub FindMerged1()
Dim c As Range
For Each c In ActiveSheet.UsedRange
If c.MergeCells Then
MsgBox c.Address & " is merged"
End If
Next
End Sub
This particular macro steps through all the cells in the worksheet (well, at least those that are in the UsedRange) and, if the cell is part of a merged cell, a message box is displayed. Note that the pertinent property being checked is the MergeCells property. This is set to True if the cell is merged with another cell.
Of course, a macro such as this can take quite a long time to run if the worksheet has lots of cells and even longer if a good number of those cells are merged. Your macro would run faster if it didn't stop at each merged cell and display a dialog box. The following version takes a different approach, filling each merged cell with a yellow color:
Sub FindMerged2()
Dim c As Range
For Each c In ActiveSheet.UsedRange
If c.MergeCells Then
c.Interior.ColorIndex = 36
End If
Next
End Sub
A variation on this approach could be to create a user-defined function that simply returns True or False if the cell is merged:
Function FindMerged3(rCell As Range)
FindMerged3 = rCell.MergeCells
End Function
With this simple function you could then use conditional formatting to somehow highlight cells if they are merged. (If the function returns True, then conditional formatting applies whatever formatting you specify to the cell.)
Finally, if you want a list of cells that are merged in the worksheet, you can simply have your macro put together the list instead of coloring the cells:
Sub FindMerged4()
Dim c As Range
Dim sMsg As String
sMsg = ""
For Each c In ActiveSheet.UsedRange
If c.MergeCells Then
If sMsg = "" Then
sMsg = "Merged worksheet cells:" & vbCr
End If
sMsg = sMsg & c.Address & vbCr
End If
Next
If sMsg = "" Then
sMsg = "No merged worksheet cells."
End If
MsgBox sMsg
End Sub
This variation displays a single message box at the end of the macro, indicating the addresses of any merged cells located in the worksheet.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3905) 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: Identifying Merged Cells.
Best-Selling VBA Tutorial for Beginners Take your Excel knowledge to the next level. With a little background in VBA programming, you can go well beyond basic spreadsheets and functions. Use macros to reduce errors, save time, and integrate with other Microsoft applications. Fully updated for the latest version of Office 365. Check out Microsoft 365 Excel VBA Programming For Dummies today!
If you have some legacy data stored in very old spreadsheet files, you may be wondering how to get that data into an ...
Discover MoreWant to easily see the location of named ranges in your worksheet? It's easy; all you need to do is use the familiar Zoom ...
Discover MoreWhile editing, you may need to select everything in a worksheet. Excel provides three easy ways you can accomplish this.
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2018-07-28 14:28:53
Rick Rothstein
Here is a method to color the merged cells (like your FindMerged2 macro) without using a loop...
Sub FindMerged2a()
Application.FindFormat.Clear
Application.ReplaceFormat.Clear
Application.FindFormat.MergeCells = True
Application.ReplaceFormat.Interior.ColorIndex = 36
ActiveSheet.UsedRange.Replace "", "", SearchFormat:=True, ReplaceFormat:=True
Application.FindFormat.Clear
Application.ReplaceFormat.Clear
End Sub
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 © 2025 Sharon Parq Associates, Inc.
Comments