Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, and 2016. 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: Identifying Merged Cells.

Identifying Merged Cells

by Allen Wyatt
(last updated May 6, 2017)

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:

  1. Press Ctrl+F. Excel displays the Find tab of the Find and Replace dialog box.
  2. If necessary, click the Options button to make sure the Find and Replace dialog box is expanded to show all options. (See Figure 1.)
  3. Figure 1. The Find tab of the Find and Replace dialog box.

  4. Make sure the Find What box is empty.
  5. With the insertion point in the Find What box, click the Format button. Excel displays the Find Format dialog box.
  6. Make sure the Alignment tab is displayed. (See Figure 2.)
  7. Figure 2. The Alignment tab of the Find Format dialog box.

  8. Make sure the Merge Cells check box is selected (there should be a check in the check box).
  9. Click OK to close the Find Format dialog box.
  10. Click Find All.

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.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12385) applies to Microsoft Excel 2007, 2010, 2013, and 2016. You can find a version of this tip for the older menu interface of Excel here: Identifying Merged Cells.

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

Using InputBox to Get Data

Need your macro to get some input from a user? The standard way to do this is with the InputBox function, described in this ...

Discover More

Searching Comments

Need to find that misplaced comment in your worksheet? It's easy to do using the Find and Replace capabilities of Excel.

Discover More

Self-Adjusting Column Widths

It is important to understand how column widths relate to the margins you may have set in your document. The reason is ...

Discover More

Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!

More ExcelTips (ribbon)

Indenting Cell Contents

Excel allows you to apply several types of alignments to cells. One type of alignment allows you to indent cell contents from ...

Discover More

Cycling through Colors

If you need to easily change the font colors in a group of cells, one of the esoteric commands Excel provides is the Cycle ...

Discover More

Using Fractional Number Formats

If you want information to display on the screen using fractions instead of decimals, you're in luck. Excel provides ...

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}] in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 8Mpixels. 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 7 - 0?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


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.