Hiding Rows based on cell value using a private sub by value

Dan Swartz

Board Regular
Joined
Apr 17, 2020
Messages
51
Office Version
  1. 365
Platform
  1. Windows
Hi, I'm new here. I have asked this on several other forms and I have not received an answer. I'm also not sure how to ask this as it's pretty complicated. I'll try and keep it on the vague side. I'll upload an image.

The setup:
1. I use conditional formatting using MOD(ROW(),2)=0 to alternate color of cells from B7 to M99.
2. I have a list of questions in column A with Answers in column B and more information in the following columns. If the answer in Column B is "None", then I automatically want to hide that row. Also, "None" Is selected from a dropdown and so if I accidentally select none, then I need to manually be able to unhide the row so I can change the value to the proper value.

What I have right now it working, but I have 3 issues.

Issue 1. When a row is hidden, I no longer have alternating colors on my rows.
Issue 2. If I do multiple selections and delete, or insert a row or do any editing on more then one cell. I get the "Run TIme Error 13 - Type Mismatch"
Issue 3. I have a formula, where if one value says none, then i'm turning the following 6 lines to None, but it won't hide those rows unless I double click in the cell and hit enter.

I hope this is clear enough to get answers.

Here is my code.


Private Sub Worksheet_Change(ByVal Target As Range)
Dim MyRange, N As Range

Set MyRange = Range("B8:B90")

If Not Application.Intersect(Target, MyRange) Is Nothing Then

If Target.Value = "N/A" Then
Target.EntireRow.Hidden = True
Else
Target.EntireRow.Hidden = False
End If

End If

End Sub

Sample Spreadsheet.png
 

Excel Facts

Back into an answer in Excel
Use Data, What-If Analysis, Goal Seek to find the correct input cell value to reach a desired result
Hi & welcome to MrExcel.

Can you please supply links to those sites.

Currently, I'm on a different computer and I don't have them booked marked on this machine. one was a Microsoft community site. I'm not sure what this has to do with my question? If I posted something that was improper. i apologize.
 
Upvote 0
It's not a major problem, but while we do allow Cross-Posting on this site, we do ask that you please mention you are doing so and provide links in each of the threads pointing to the other thread (see rule 13 here along with the explanation: Forum Rules). This way, other members can see what has already been done in regards to a question, and do not waste time working on a question that may already be answered.


As far as part 3 of your, where is the formula & what cells is it pointing at?
 
Upvote 0
I apologize. did not mean to violate anything. I don't have those links today. I won't be able to access until I get back to work after lockdown. It's on my work desktop.

My formula is for cells B30:B37 are all the same and point to B29. It's for all of the interior doors. =if($B$29="None","N/A",if($B$29="N/A","N/A","Wood Species"))
 
Upvote 0
How about
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
   If Target.CountLarge > 1 Then Exit Sub
   If Not Application.Intersect(Target, Range("B8:B90")) Is Nothing Then
      Target.EntireRow.Hidden = Target.Value = "N/A"
      If Target.Address(0, 0) = "B29" Then
         If Target.Value = "None" Or Target.Value = "N/A" Then
            Range("B30:B37").EntireRow.Hidden = True
         Else
            Range("B30:B37").EntireRow.Hidden = False
         End If
      End If
   End If
End Sub
 
Upvote 0
WOW! that is amazing! That solved all but one issue! Thank you!

Do you have any solution for the alternating color issue?

I'm using conditional formating with =mod(row(),2)=0 to color my rows. I have a light blue.

When hiding rows, I lose the alternating color. Notice between lines 28 and 38.

No Alternating color.png
 
Upvote 0
If you convert your data into a structured table, then you can have alternating row colours without using conditional formatting.
 
Upvote 0
I played with that a little but didn't work well in my application because of the way I have things organized. However, I'll go try it again.
 
Upvote 0
You could also try
=MOD(SUBTOTAL(103,$A$2:$A2),2)=1
As long as you have hard values
 
Upvote 0

Forum statistics

Threads
1,214,834
Messages
6,121,873
Members
449,056
Latest member
ruhulaminappu

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