Written by Allen Wyatt (last updated September 3, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365
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, 2016, 2019, 2021, and Excel in Microsoft 365.
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!
There are two ways to create macros: recording them or writing them from scratch. Some things cannot be done in a macro ...
Discover MoreWhat would you do if you had a macro-enabled workbook that refused to work properly on computers using later versions of ...
Discover MoreMake your macros too long, and Excel may just refuse to run them at all. This tip explains what the limit is for macros ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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.
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