Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. 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: Selecting Columns in VBA when Cells are Merged.

Selecting Columns in VBA when Cells are Merged

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


Say you have a blank worksheet and the range A1:F1 has the "merge and center" format applied to it. If you select column B by clicking the column heading, Excel dutifully selects column B and makes cell B2 the active cell. This behavior was modified in either Excel 2000 or Excel 2002; in previous versions of Excel you get the merged cell (A1:F1) included in the selection.

Apparently VBA trails somewhat behind the behavior of the user interface, as selecting the entire column B also ends up selecting all the columns, A through F:

Sub TestMacro1()
    Range("B3").EntireColumn.Select
End Sub

There seems to be no way around this behavior. Even if you eliminate the EntireColumn method and simply select column B, you still get all the columns, A through F:

Sub TestMacro2()
    Range("B:B").Select
End Sub

It is probably a better programming approach to not select the column preparatory to doing some action upon that column, but to do the action directly. For instance, let's assume that you want to make all of the cells in column B bold. You can do so in this manner:

Sub TestMacro3()
    Range("B3").EntireColumn.Font.Bold = True
End Sub

This affects only the cells in column B, and nothing in A or C through F. You could similarly use an iterative approach to processing the cells in the desired column:

Sub TestMacro4()
    Dim rCell As Range
    Dim X As Long

    X = 1
    For Each rCell In Range("B:B")
        rCell.Value = X
        X = X + 1
    Next
End Sub

This stuffs a value into each cell in column B, and conveniently ignores any merges that include a cell in column B.

If it is mandatory that you be able to select an entire column, without any columns added because of merged cells, then you may be tempted to use the MergeCells property to check for the merged cells. According to the VBA online help, the following should detect the merged cells in the selection and then dump out of the macro:

Sub TestMacro5()
    Range("B3").EntireColumn.Select
    If Selection.MergeCells Then
        Exit Sub
    End If
'
' Perform rest of macro
'
End Sub

Unfortunately, testing shows that this code will not work. The MergeCells property apparently only returns True if the entire selection is made up of merged cells, not if the selection only contains a few merged cells. That means that you are left to some other way to determine if merged cells have modified the intended selection, such as the following:

Sub TestMacro6()
    Range("B3").EntireColumn.Select
    If Selection.Columns.Count > 1 Then
        Exit Sub
    End If
'
' Perform rest of macro
'
End Sub

This approach examines the number of columns in the selection, and then dumps out if Excel reports that there is more than one.

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 (12218) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Selecting Columns in VBA when Cells are Merged.

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

Speeding Up Cursor Movement

If you use the arrow keys to move the insertion point through the document, you may have noticed that it can be slow ...

Discover More

Nifty Zooming

If you are using a mouse that has a center wheel, you can use the wheel to zoom in and out of your work. This tip shows ...

Discover More

Underlining Quoted Text

Do you have a document in which you need to convert all the quoted text (text surrounded by quotes) to underlined text? ...

Discover More

Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!

More ExcelTips (ribbon)

Running a Macro while in Edit Mode

Excel doesn't allow you to run a macro while editing the contents of a cell. The only solution is to get out of Edit ...

Discover More

Determining the Current Directory

When you use a macro to do file operations, it works (by default) within the current directory. If you want to know which ...

Discover More

Using the Status Bar

When developing a macro, you may want to display on the status bar what the macro is doing. Here's how to use this ...

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 one less than 9?

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.