How to hide or unhide entire rows based on multiple drop down lists number selection for for each data set

Trent30

New Member
Joined
Jan 12, 2021
Messages
11
Office Version
  1. 365
Platform
  1. Windows
I am new to VBA codes. I have a worksheet where column A data changes between “Hide” and “Show” when you select a different drop down option (ex – 1-8). I am wanting to show the number of lines selected from a drop down box for each individual data set of 8 rows for data set 1 and a further 8 rows for data set 2. E.g. I want to show the first 4 lines of data set 1 and the 3 lines from data set 2.

1610446020200.png


I have tried the below code which works for the first data set (and I didn’t need to add column A to have Show or Hide appear depending on the drop down value), however I couldn’t get it to work for the second data set as I don’t know how to add multiple macros (and it seems a bit long winded for the code).


1610446141827.png
 

Excel Facts

What do {} around a formula in the formula bar mean?
{Formula} means the formula was entered using Ctrl+Shift+Enter signifying an old-style array formula.
Welcome to the MrExcel board!

First a couple of forum hints.
  • Investigate XL2BB for providing sample data to make it easier for helpers by not having to manually type out sample data to test with.
  • When posting code, don't post a picture, post the actual code from your vba window and use code tags to display it properly in your post. More details in my signature block below.

See if this does what you want. I wasn't sure what you would want if the cells in column D are cleared? My code hides all the group rows since there is then no number in the "Show lines" cell.

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
  Dim Changed As Range, c As Range
 
  Set Changed = Intersect(Target, Range("D2, D14"))
  If Not Changed Is Nothing Then
    Application.ScreenUpdating = False
    For Each c In Changed
      c.Offset(1).Resize(8).EntireRow.Hidden = True
      If Len(c.Value) > 0 Then c.Offset(1).Resize(c.Value).EntireRow.Hidden = False
    Next c
    Application.ScreenUpdating = True
  End If
End Sub
 
Upvote 0
Hi Trent,

Please check this:

VBA Code:
Sub showRows()
Dim rowsFToShow As Integer, rowsSToShow As Integer
Sheets("Sheet3").Cells.EntireRow.Hidden = False

rowsFToShow = Sheets("Sheet3").Range("D2")
rowsSToShow = Sheets("Sheet3").Range("D14")

Sheets("Sheet3").Range(3 + rowsFToShow & ":10").EntireRow.Hidden = True
Sheets("Sheet3").Range(15 + rowsSToShow & ":22").EntireRow.Hidden = True


End Sub
 
Upvote 0
Solution
Welcome to the MrExcel board!

First a couple of forum hints.
  • Investigate XL2BB for providing sample data to make it easier for helpers by not having to manually type out sample data to test with.
  • When posting code, don't post a picture, post the actual code from your vba window and use code tags to display it properly in your post. More details in my signature block below.

See if this does what you want. I wasn't sure what you would want if the cells in column D are cleared? My code hides all the group rows since there is then no number in the "Show lines" cell.

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
  Dim Changed As Range, c As Range

  Set Changed = Intersect(Target, Range("D2, D14"))
  If Not Changed Is Nothing Then
    Application.ScreenUpdating = False
    For Each c In Changed
      c.Offset(1).Resize(8).EntireRow.Hidden = True
      If Len(c.Value) > 0 Then c.Offset(1).Resize(c.Value).EntireRow.Hidden = False
    Next c
    Application.ScreenUpdating = True
  End If
End Sub
Thanks Peter_SSs,

That works how I intended it, it looks a lot simpler than the code I had.

I will keep your hints in mind for future questions
 
Upvote 0
Hi Trent,

Please check this:

VBA Code:
Sub showRows()
Dim rowsFToShow As Integer, rowsSToShow As Integer
Sheets("Sheet3").Cells.EntireRow.Hidden = False

rowsFToShow = Sheets("Sheet3").Range("D2")
rowsSToShow = Sheets("Sheet3").Range("D14")

Sheets("Sheet3").Range(3 + rowsFToShow & ":10").EntireRow.Hidden = True
Sheets("Sheet3").Range(15 + rowsSToShow & ":22").EntireRow.Hidden = True


End Sub
Sorry Saurabhj this one didn't do anything
 
Upvote 0
You're welcome. Thanks for the follow-up. :)
 
Upvote 0

Forum statistics

Threads
1,214,415
Messages
6,119,382
Members
448,889
Latest member
TS_711

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