Jesse has a large worksheet that may contain hidden rows. He wonders if there is a way to find out if there are hidden rows in the worksheet other than by looking down the many rows to see what's missing. If he unhides all the hidden rows, he still won't be able to tell what, if any, rows may have been hidden.
One way you can identify hidden rows is to follow these general steps:
Unhide all the rows, and you'll be able to easily see which cells in that column don't have the character (X) in them. These are the rows that were previously hidden. You could also, if desired, use the same general approach, but after step 2 (instead of step 3) you could apply some pattern or color to the cells. Once you unhide all the rows, those cells without any pattern or color are the ones that were previously in hidden rows.
If you don't want to unhide rows at all, perhaps the best way to find out the information is to use a macro. The following simple macro steps through the first 1,000 rows of a worksheet and then lists, in a message box, the rows that are hidden.
Sub ShowRows() Dim rng As Range Dim c As Range Dim sTemp As String Set rng = Range("A1:A1000") sTemp = "" For Each c in rng If c.EntireRow.Hidden Then sTemp = sTemp & "Row " & c.Row & vbCrLf End If Next c If sTemp > "" Then sTemp = "The following rows are hidden:" & vbCrLf & _ vbCrLf & sTemp MsgBox sTemp Else MsgBox "There are no hidden rows" End If End Sub
Note that the heart of the macro—where it determines whether a row is hidden or not—is in checking the Hidden property of the EntireRow object. If this property is True, then the row is hidden.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12217) 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: Detecting Hidden Rows.
Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!
Excel automatically formats subtotals for you. But what if you want to change the default to something more suitable for ...
Discover MoreWant to set the width and height of a row and column by specifying a number of inches? It's not quite as straightforward ...
Discover MoreWhen building a worksheet, you may need to hide some of the rows or unhide other, previously hidden, rows. It's easy to ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2020-07-31 12:47:07
J. Woolley
@Joe Schuster
Try this:
Sub HiddenRowsCols()
Dim R As Range, S As String, Msg As String
For Each R In Range(Rows(1), Rows(1000))
If R.Hidden Then ' consider 1000 rows
Msg = Msg & "Row " & R.Row & vbNewLine
End If
Next R
For Each R In Range(Columns(1), Columns(100))
If R.Hidden Then ' consider 100 columns
S = Split(R.Address(, False), ":")(0)
Msg = Msg & "Col " & S & vbNewLine
End If
Next R
If Msg = "" Then
Msg = "There are no hidden rows/cols"
Else
S = "The following rows/cols are hidden:"
Msg = S & vbNewLine & vbNewLine & Msg
End If
MsgBox Msg, vbInformation, "HiddenRowsCols"
End Sub
See the Code window screenshot (see Figure 1 below)
You might also be interested in My Excel Toolbox at https://sites.google.com/view/MyExcelToolbox/
Figure 1.
2020-07-30 18:25:13
Joe Schuster
Is it possible for you to change that macro so that it shows hidden rows and columns? I thank you for your help.
2016-12-14 16:10:41
Don
In the first method, you can skip step 2. Step 3 will only affect the unhidden cells anyway.
2016-11-14 09:21:59
Ken G
Sharon, I hope your suggestion that hiding rows and columns is dangerous was for specific scenario. There certainly are times when hiding them can be very useful...and SAFE.
2016-11-13 09:08:21
Selwyn
Depending on what you want to do with the Revealed Hidden Rows, an alternative would be to change the Hidden State of all rows so that just the Hidden Rows are now visible and can be dealt with. Run the Sub again to set back to original state.
For Each c in rng
c.EntireRow.Hidden = Not
c.EntireRow.Hidden
Next c
2016-11-12 12:15:54
David Gray
This is one of those "why didn't I already think of that?" tips, and it could be easily adapted to find hidden columns, which occur fare more often in my worksheets than do hidden columns, with the exception of filtered worksheets, which provide their own mechanism for identifying hidden rows.
2016-11-12 11:47:15
Sharon Pickthorne
Thanks for this. Funny - I was teaching just the other day about the dangers of HIDING rows or columns. I suggest using GROUP instead - then you have those nice + and - signs and the ability to use the levels. Much safer than hiding.
2016-11-12 08:02:36
Frank Panipinto
If you want to have a quick visual indicator as to which rows are hidden, just add the following line after "sTemp = sTemp & "Row " & c.Row & vbCrLf"
c.EntireRow.Interior.ColorIndex = 28
This will apply a background color to instantly see all the hidden rows once you unhide them. Just change the color number to suit your taste.
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 © 2021 Sharon Parq Associates, Inc.
Comments