SHOW/HIDE an Array of Rows?

jvanbonn

Board Regular
Joined
Mar 11, 2011
Messages
71
I'm trying to write a subroutine to SHOW/HIDE multiple lines triggered by changing cell A1 and based on the column A row (i) set to TRUE or FALSE. I'm trying to figure out an elegant way to create an array of cell addresses in column A that have the value TRUE, and then hide all rows in that array. I was attempting this without looping the code for efficiency & speed.

The below code is what I would like to work, but I'm not having any luck yet.

Code:
Private Sub Worksheet_Change(ByVal Target As Range)
Dim rowlist(2) As String

If Target.Column = 1 And Target.row = 1 Then

'sample array
rowlist(1) = "A6"
rowlist(2) = "A9"

With ActiveSheet
.Range(Array(rowlist)).EntireRow.Hidden = True
End With

End If

End Sub
 

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple
One way might be to loop through each element of the array...

Code:
[font=Verdana][color=darkblue]Private[/color] [color=darkblue]Sub[/color] Worksheet_Change([color=darkblue]ByVal[/color] Target [color=darkblue]As[/color] Range)

    [color=darkblue]Dim[/color] rowlist(1) [color=darkblue]As[/color] [color=darkblue]String[/color]
    
    [color=darkblue]If[/color] Target.Column = 1 And Target.Row = 1 [color=darkblue]Then[/color]
    
    [color=green]'sample array[/color]
    rowlist(0) = "A6"
    rowlist(1) = "A9"
    
    [color=darkblue]For[/color] i = [color=darkblue]LBound[/color](rowlist) [color=darkblue]To[/color] [color=darkblue]UBound[/color](rowlist)
        Range(rowlist(i)).EntireRow.Hidden = [color=darkblue]True[/color]
    [color=darkblue]Next[/color] i
    
    [color=darkblue]End[/color] [color=darkblue]If[/color]

End [color=darkblue]Sub[/color]
[/font]

Notice that since the default base for arrays is 0, I declared the array with the number 1 as the upper index for a two element array. Another way might be to use the Union method of the Application...

Code:
[font=Verdana][color=darkblue]Private[/color] [color=darkblue]Sub[/color] Worksheet_Change([color=darkblue]ByVal[/color] Target [color=darkblue]As[/color] Range)

    [color=darkblue]Dim[/color] Rng [color=darkblue]As[/color] Range

    [color=darkblue]If[/color] Target.Address = "$A$1" [color=darkblue]Then[/color]
    
        [color=darkblue]Set[/color] Rng = Union(Range("A6"), Range("A9"))
        
        Rng.EntireRow.Hidden = [color=darkblue]True[/color]
    
    [color=darkblue]End[/color] [color=darkblue]If[/color]

End [color=darkblue]Sub[/color]
[/font]

In either case, you might want to test to make sure that the target cell is not blank before proceeding to hide the desired rows.
 
Upvote 0
Beautiful!

Great examples; you gave me just what I needed!

Sample Worksheet:
<table class="excel1" border="1" cellpadding="0" cellspacing="0"><tbody><tr style="height: 12pt;" valign="bottom" bgcolor="#999999" height="16"><td style="height: 12pt; width: 10pt;" align="center">
</td><td style="height: 12pt; width: 48pt;" align="center" height="16">A</td><td style="width: 48pt;" align="center">B</td><td style="width: 48pt;" align="center">C</td><td style="width: 48pt;" align="center">D</td><td style="width: 48pt;" align="center">E</td><td style="width: 48pt;" align="center">F</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt; width: 15pt;" width="64" align="center" bgcolor="#999999">1</td><td style="height: 12pt; width: 48pt;" width="64" align="center" height="16">FALSE</td><td style="width: 48pt;" width="64">
</td><td style="width: 48pt;" width="64">
</td><td style="width: 48pt;" width="64">
</td><td style="width: 48pt;" width="64">
</td><td style="width: 48pt;" width="64">
</td></tr><tr style="height: 12pt;" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">2</td><td style="height: 12pt;" height="16">
</td><td>
</td><td>
</td><td>
</td><td>
</td><td>
</td></tr><tr style="height: 12pt;" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">3</td><td style="height: 12pt;" height="16">
</td><td>
</td><td>
</td><td>
</td><td>
</td><td>
</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">4</td><td class="excel2" style="height: 12pt;" bgcolor="#dbe5f1" height="16">
</td><td class="excel2" bgcolor="#dbe5f1">Header</td><td class="excel2" bgcolor="#dbe5f1">A</td><td class="excel2" bgcolor="#dbe5f1">B</td><td class="excel2" bgcolor="#dbe5f1">C</td><td class="excel2" bgcolor="#dbe5f1">D</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">5</td><td style="height: 12pt;" align="center" height="16">FALSE</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">6</td><td style="height: 12pt;" align="center" height="16">TRUE</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">7</td><td style="height: 12pt;" align="center" height="16">FALSE</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">8</td><td style="height: 12pt;" align="center" height="16">FALSE</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">9</td><td style="height: 12pt;" align="center" height="16">TRUE</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">10</td><td style="height: 12pt;" align="center" height="16">FALSE</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">11</td><td style="height: 12pt;" align="center" height="16">FALSE</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">12</td><td style="height: 12pt;" align="center" height="16">FALSE</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td></tr></tbody></table>


Code:
Private Sub Worksheet_Change(ByVal Target As Range)
Application.EnableEvents = False

Dim w As Worksheet, t As Worksheet
Dim h As Long, i As Long, j As Long, k As Long
Dim Rng As Range

''''''''''''''''''''''''''''''''''''''''''''''''''''''''''
'  h is the row index of the selected range (looping)
'  i is the row index of first non-header row of selected range
'  j is the row index of the last row of the selected range
'  k is the kth member of the Range Rng
'
'  Rng is the union of rows in the selected range where
'       column A has the value "TRUE" <= to be hidden
'
'''''''''''''''''''''''''''''''''''''''''''''''''''''''''


If Target.Address = "$A$1" And Target.Value = True Then
  With ActiveSheet.Cells(4, 2).CurrentRegion
  i = .Item(2, 1).row       'FIRST ROW OF DATA
  j = .Item(.Rows.Count, .Columns.Count).row    'LAST ROW OF DATA
  End With

  k = 0
    
    For h = i To j Step 1
      If ActiveSheet.Cells(h, 1) = True Then
        k = k + 1
          If k = 1 Then
            Set Rng = ActiveSheet.Cells(h, 1)
            Debug.Print Rng.Address
          Else
            Set Rng = Union(Rng, ActiveSheet.Cells(h, 1))
            Debug.Print Rng.Address
          End If
      End If
    Next h
    
  Rng.EntireRow.Hidden = True

ElseIf Target.Address = "$A$1" And Target.Value = False Then
 
  ActiveSheet.Range(Cells(1, 1), Cells(Rows.Count, Columns.Count)).EntireRow.Hidden = False

End If
Application.EnableEvents = True
End Sub
My actual sheets have checkboxes in cells A1 and A5 through A(k) to set the corresponding cell in Column A as TRUE or FALSE. That way there are four conditions with three outcomes.
1. A1 TRUE & A(k) TRUE : Row A(k) Hidden
2. A1 TRUE & A(k) FALSE : Row A(k) Visible & Black Text
3. A1 FALSE & A(k) TRUE : Row A(k) Conditionally Formatted to Strike, Italic, & Grey
4 A1 FALSE & A(k) FALSE : Row A(k) Visible & Black Text

<table class="excel1" border="1" cellpadding="0" cellspacing="0"><tbody><tr style="height: 12pt;" valign="bottom" bgcolor="#999999" height="16"><td style="height: 12pt; width: 10pt;" align="center">
</td><td style="height: 12pt; width: 48pt;" align="center" height="16">A</td><td style="width: 48pt;" align="center">B</td><td style="width: 48pt;" align="center">C</td><td style="width: 48pt;" align="center">D</td><td style="width: 48pt;" align="center">E</td><td style="width: 48pt;" align="center">F</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt; width: 15pt;" width="64" align="center" bgcolor="#999999">1</td><td style="height: 12pt; width: 48pt;" width="64" align="center" height="16">FALSE</td><td style="width: 48pt;" width="64">
</td><td style="width: 48pt;" width="64">
</td><td style="width: 48pt;" width="64">
</td><td style="width: 48pt;" width="64">
</td><td style="width: 48pt;" width="64">
</td></tr><tr style="height: 12pt;" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">2</td><td style="height: 12pt;" height="16">
</td><td>
</td><td>
</td><td>
</td><td>
</td><td>
</td></tr><tr style="height: 12pt;" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">3</td><td style="height: 12pt;" height="16">
</td><td>
</td><td>
</td><td>
</td><td>
</td><td>
</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">4</td><td class="excel2" style="height: 12pt;" bgcolor="#dbe5f1" height="16">
</td><td class="excel2" bgcolor="#dbe5f1">Header</td><td class="excel2" bgcolor="#dbe5f1">A</td><td class="excel2" bgcolor="#dbe5f1">B</td><td class="excel2" bgcolor="#dbe5f1">C</td><td class="excel2" bgcolor="#dbe5f1">D</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">5</td><td style="height: 12pt;" align="center" height="16">FALSE</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">6</td><td style="height: 12pt;" align="center" height="16">TRUE</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">7</td><td style="height: 12pt;" align="center" height="16">FALSE</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">8</td><td style="height: 12pt;" align="center" height="16">FALSE</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">9</td><td style="height: 12pt;" align="center" height="16">TRUE</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">10</td><td style="height: 12pt;" align="center" height="16">FALSE</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">11</td><td style="height: 12pt;" align="center" height="16">FALSE</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">12</td><td style="height: 12pt;" align="center" height="16">FALSE</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td></tr></tbody></table>


<table class="excel1" border="1" cellpadding="0" cellspacing="0"><tbody><tr style="height: 12pt;" valign="bottom" bgcolor="#999999" height="16"><td style="height: 12pt; width: 10pt;" align="center">
</td><td style="height: 12pt; width: 48pt;" align="center" height="16">A</td><td style="width: 48pt;" align="center">B</td><td style="width: 48pt;" align="center">C</td><td style="width: 48pt;" align="center">D</td><td style="width: 48pt;" align="center">E</td><td style="width: 48pt;" align="center">F</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt; width: 15pt;" width="64" align="center" bgcolor="#999999">1</td><td style="height: 12pt; width: 48pt;" width="64" align="center" height="16">TRUE</td><td style="width: 48pt;" width="64">
</td><td style="width: 48pt;" width="64">
</td><td style="width: 48pt;" width="64">
</td><td style="width: 48pt;" width="64">
</td><td style="width: 48pt;" width="64">
</td></tr><tr style="height: 12pt;" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">2</td><td style="height: 12pt;" height="16">
</td><td>
</td><td>
</td><td>
</td><td>
</td><td>
</td></tr><tr style="height: 12pt;" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">3</td><td style="height: 12pt;" height="16">
</td><td>
</td><td>
</td><td>
</td><td>
</td><td>
</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">4</td><td class="excel2" style="height: 12pt;" bgcolor="#dbe5f1" height="16">
</td><td class="excel2" bgcolor="#dbe5f1">Header</td><td class="excel2" bgcolor="#dbe5f1">A</td><td class="excel2" bgcolor="#dbe5f1">B</td><td class="excel2" bgcolor="#dbe5f1">C</td><td class="excel2" bgcolor="#dbe5f1">D</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">5</td><td style="height: 12pt;" align="center" height="16">FALSE</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">7</td><td style="height: 12pt;" align="center" height="16">FALSE</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">8</td><td style="height: 12pt;" align="center" height="16">FALSE</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">10</td><td style="height: 12pt;" align="center" height="16">FALSE</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">11</td><td style="height: 12pt;" align="center" height="16">FALSE</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td></tr><tr style="height: 12pt;" valign="bottom" height="16"><td style="height: 12pt;" align="center" bgcolor="#999999">12</td><td style="height: 12pt;" align="center" height="16">FALSE</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td><td>hi</td></tr></tbody></table>

Again, Thanks so much!
 
Upvote 0

Forum statistics

Threads
1,224,542
Messages
6,179,421
Members
452,913
Latest member
JWD210

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top