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.

Identifying Merged Cells

Written by Allen Wyatt (last updated July 28, 2018)
This tip applies to Excel 97, 2000, 2002, and 2003


1

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.

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 (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.

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

Adding an Equation Editor Tool

If you use the Equation Editor a lot in creating your documents, you'll benefit by making sure it is accessible as ...

Discover More

Inserting the User's Address

If you enter your address into Word, you can insert that address anywhere you want in a document by using a single field. ...

Discover More

ISO Week Numbers in Excel

Work in an industry that uses ISO standards when it comes to working with dates? You'll love the formula in this tip ...

Discover More

Dive Deep into Macros! Make Excel do things you thought were impossible, discover techniques you won't find anywhere else, and create powerful automated reports. Bill Jelen and Tracy Syrstad help you instantly visualize information to make it actionable. You’ll find step-by-step instructions, real-world case studies, and 50 workbooks packed with examples and solutions. Check out Microsoft Excel 2019 VBA and Macros today!

More ExcelTips (menu)

Calculating Monthly Interest Charges

Trying to calculate how much people owe you? If you charge interest or service charges on past-due accounts, there are a ...

Discover More

Grabbing a User's Name from Excel

One of the settings you can make in Excel is to specify a user's name. This name is accessible through macros, and can ...

Discover More

Excel Won't Display Different Windows in the Taskbar

If you want individual Taskbar buttons for each open Excel workbook but cannot seem to get those buttons, the culprit ...

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 7 + 0?

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


This Site

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.

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.