Determining the Number of Visible Columns

by Allen Wyatt
(last updated August 6, 2016)

Dave needs a way, in a macro, to determine how many columns are visible in the current window or pane.

This is actually quite easy to accomplish. The trick is to remember that you need to work with the VisibleRange object, which belongs to the ActiveSheet object. You can use the .Columns collection for the VisibleRange object, and then utilize the .Count method for that collection. What you end up with is the number of columns, in this manner:

Sub VisibleColCount()
    Dim sTemp As String

    sTemp = "There are "
    sTemp = sTemp & ActiveWindow.VisibleRange.Columns.Count
    sTemp = sTemp & " columns visible."
    MsgBox sTemp
End Sub

Seems simple, right? The problem is that the .Count method returns the number of columns in the collection whether they are hidden or not. For instance, let's say that you look at the screen and you see that it shows columns C through H. That means that 6 columns are displayed, and that is what the .Count method returns in the above macro. If you then hide column F, now columns C through I are displayed. Instead of .Count still returning 6 (representing columns C, D, E, G, H, and I), it now returns 7, which includes the hidden column, even though it is not visible.

The solution to this situation is to check the .Hidden property of each column in the .Columns collection. Only if the .Hidden property is False should the column be counted as visible, in this manner:

Sub VisibleColCount()
    Dim c As Range
    Dim iCount As Integer
    Dim sTemp As String

    iCount = 0
    For Each c In ActiveWindow.VisibleRange.Columns
        If Not c.Hidden Then iCount = iCount + 1
    Next c

    sTemp = "The active window includes "
    sTemp = sTemp & ActiveWindow.VisibleRange.Columns.Count
    sTemp = sTemp & " columns. Of those columns, "
    If iCount = ActiveWindow.VisibleRange.Columns.Count Then
        sTemp = sTemp & "all "
    Else
        sTemp = sTemp & "only "
    End If
    sTemp = sTemp & iCount & " are visible."
    MsgBox sTemp
End Sub

There is one other gotcha with this approach: As far as VBA is concerned, a column is counted as visible as long as just a sliver of that column is showing. Also, if you anticipate using panes in your Excel display, you may want to consider adding the ActivePane object into the mix. Basically, it takes a simple change in the above macros: Anyplace you see the ActiveWindow object, follow it with ActivePane, similar to this:

    For Each c In ActiveWindow.ActivePane.VisibleRange.Columns

This ensures that your macro is looking at only the current pane in the window when doing its counting.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (617) applies to Microsoft Excel 2007, 2010, 2013, and 2016.

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

Selecting Fonts for a Chart

Microsoft Chart uses text to label items in a chart. Here's how to change the font used for that text.

Discover More

Printing the Active Document from a Macro

When you process a document in a macro, you may also want to print that document from within the same macro. Here's how to do ...

Discover More

Setting Your Default Directory

You may want to have all your Excel workbooks stored in a specific location on your system. Here's how to set the default ...

Discover More

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!

MORE EXCELTIPS (RIBBON)

Understanding Variables in VBA Macros

You can create and use all sorts of variables in your macros. This tip examines all the different data types you can specify.

Discover More

Jumping to the Start of the Next Data Entry Row

Want a quick way to jump to the end of your data entry area in a worksheet? The macro in this tip makes quick work of the ...

Discover More

Forcing a Macro to Run when a Worksheet is Recalculated

Normally a macro is only calculated when you specifically tell Excel to calculate it. Some macros need to be calculated ...

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 for this tip:

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. 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 9 - 7?

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.

Links and Sharing