VBA macro to Collapse/Expand all grouped rows/columns

imaguy77

New Member
Hi all,

I'd like to be able to run a macro which would collapse or expand all grouped rows and columns for all selected worksheets. When I say collapse or expand, i don't need any selection dialog box or anything...just the code which would accomplish it. Thanks!!
 

Jerry Sullivan

MrExcel MVP
The Outline.ShowLevels method allows you to show a specified number of
RowLevels and Column Levels.

To Collapse all Rows and Columns...
Code:
Sub Collapse_All()
    ActiveSheet.Outline.ShowLevels RowLevels:=1, ColumnLevels:=1
End Sub
To Expand all Rows and Columns...
Code:
Sub Expand_All()
    ActiveSheet.Outline.ShowLevels RowLevels:=8, ColumnLevels:=8
End Sub
And anything in between....
Code:
Sub Collapse_Rows_to_Level2_Expand_All_Columns()
    ActiveSheet.Outline.ShowLevels RowLevels:=2, ColumnLevels:=8
End Sub
 

Jerry Sullivan

MrExcel MVP
I just noticed you want to apply this to all on selected worksheets.

I'd like to be able to run a macro which would collapse or expand all grouped rows and columns for all selected worksheets.
You can merge the code I posted with the method of iterating through
selected worksheets that Domenic provided you in your recent post.

The result for Expand_All would look like this.

Code:
Sub Expand_All()
    Dim sh As Object
    For Each sh In ActiveWindow.SelectedSheets
        If TypeName(sh) = "Worksheet" Then
            sh.Outline.ShowLevels RowLevels:=8, ColumnLevels:=8
        End If
    Next sh
    Set sh = Nothing
End Sub
You can adapt the other variations the same way.
 

jbaccash

New Member
This works great for expanding all rows/columns. I'm having some trouble searching online to find code to expand only one group of columns. I'm running Excel 2010. Googling around, I'm finding code such as:

Range("B:C").Columns.ShowDetail = True

Range("B:C").Columns.ShowLevels ColumnLevels:=2

I'm also guessing with code such as:

Range("B:C").Outline.ShowLevels ColumnLevels:=2

Columns("B:C").Columns.ShowLevels ColumnLevels:=2

I keep getting a "Runtime error 438: Object doesn't support this property or method".

Forgive me but I'm almost a total novice when it comes to writing code in VBA. My experience to date is recording clunky macros and then messing with the resulting code. Clicking on a particular "+" for a group doesn't generate any code when recording.

Any help is appreciated.
 

jbaccash

New Member
I also find it strange that

Rows(9).ShowDetail = True

works to expand a particular group of rows but

Columns(C).ShowDetail = True

does not work for columns.
 

Jerry Sullivan

MrExcel MVP
Hi and Welcome to the Board,

You could use either of these...

Code:
Columns("C").ShowDetail = True

Columns(3).ShowDetail = True
 

Some videos you may like

This Week's Hot Topics

  • Importing multiple excel files into one spreadsheet
    Hi, I'm trying to import multiple excel files (with the same format into a single spreadsheet) so that each day's file is listed underneath the...
  • find many based on a certain criteria
    good evening, I hope someone can help me? I have a workbook sheet 2 contains lots of data.... I would like to be able to find anything on sheet...
  • How to copy multiple rows using If
    Hi all, I'm very new to VBA and have written this simple code to copy certain cells if a certain cell within that row contains any data. I need...
  • VBA If statement
    Dear All, I have two dates, where I'd like a message box to pop, if the dates are between this criteria. [CODE] sDate1 = #10/1/2019#...
  • Text Format
    I have a sheet for user to keyin the data. The format of the data can be 451 / 1903, 0012 / 9908 or 00287 / 0099. The number after the "/" is...
  • Macro to copy values across rows and transposing them and add the user id
    [FONT=Times New Roman][SIZE=3][COLOR=#000000][/COLOR][/SIZE][/FONT][FONT=Calibri][SIZE=3][COLOR=#000000]Hi,[/COLOR][/SIZE][/FONT] [FONT=Times New...
Top