Excel Macro: Run Macro Based on a cell value

rorymcc

New Member
Joined
Jul 7, 2017
Messages
9
Hi I'm trying to run a macro based on another cell value. I simply want to hide rows based on a dropdown value from another cell. Is this possible. I have working code that is hiding rows, but it is not being triggered when the value is selected I have to manually run the macro. Could someone help me?

Code:

Private Sub worksheet_change(ByVal target As Range)
Set target = Range("B1")
If target.value = "Delete" Then
Call Macro1
End If
End Sub


Sub Macro1

If Range("B1").Value="Delete" Then
Rows("3:4").EntireRow.Hidden = True .......etc


The sub macro1 is working but not being triggered by the private sub on the worksheet
 

Excel Facts

Round to nearest half hour?
Use =MROUND(A2,"0:30") to round to nearest half hour. Use =CEILING(A2,"0:30") to round to next half hour.
Welcome to the Board!

In a Worksheet_Change procedure, you don't set the Target range. The Target range is the range that was updated that triggered the procedure to run.

So I think you can do all that you want like this:

Code:
[COLOR=#333333]Private Sub worksheet_change(ByVal target As Range)[/COLOR]
[COLOR=#333333]    If Target.Address(0,0) = "B1" Then[/COLOR]
[COLOR=#333333]        If Target.Value = "Delete" Then
[/COLOR]            [COLOR=#333333]Rows("3:4").EntireRow.Hidden = True
[/COLOR]        End If
[COLOR=#333333]    End If[/COLOR]
[COLOR=#333333]End Sub[/COLOR]
Note. If you want the procedure just to call Macro1, it isn't necessary to check that B1 is equal to "Delete" in both procedures, just one is sufficient.
 
Last edited:
Upvote 0
Hi Joe,

Thanks for your reply. I've removed my code and just put this in. But nothing is happening. Have typed in delete, added it from a dropdown and no macro is being triggered. Is there something I'm missing here?
 
Upvote 0
Did you place the code in the appropriate Sheet module (and not in a Standard module)?
Worksheet_Change event procedures must be in the appropriate sheet module in order to run correctly.

Also, have you disabled events anywhere along the way? If so, you will need to re-enable them, like with a short procedure like this:
Code:
Sub ReEnableEvents()
    Application.EnableEvents = True
End Sub
Just put that code in any module and run it to make sure events are enabled.

Also, it shouldn't really matter, but the procedure name and Target are usually capitalized, i.e.
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Target.Address(0, 0) = "B1" Then
        If Target.Value = "Delete" Then
            Rows("3:4").EntireRow.Hidden = True
        End If
    End If
End Sub
Maybe some versions of Excel are sensitive to that.
 
Last edited:
Upvote 0
Hi Joe,

Thanks again for your help. This has been so useful already. It was the enable events that was causing the issue.

I just have one more question, this one might be slightly more complicated but hopefully you can help.

What would I need to do to change the code so that:

If the user selected "Delete" then it would hide the rows, if the user selected "Open" it would hide the rows. If anything else it would unhide the rows and bring them back.

Thanks again!
 
Upvote 0
Sorry to stick in, but try that
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Target.Address(0, 0) = "B1" Then
        Select Case Target
        Case "Delete", "Open"
            Rows("3:4").EntireRow.Hidden = True
        Else
            Rows("3:4").EntireRow.Hidden = False
        End Select
    End If
End Sub
 
Upvote 0
If I understand you correctly, maybe something like this:
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Target.Address(0, 0) = "B1" Then
        If (Target.Value = "Delete") Or (Target.Value = "Open") Then
            Rows("3:4").EntireRow.Hidden = True
        Else
            Rows("3:4").EntireRow.Hidden = False
        End If
    End If
End Sub
 
Upvote 0
Thanks again Joe, I tried you method as well S_Wish and was getting a Complile Else with If Error. I've seen the case method on other forums so think it could work but appreciate your help.

Joe- code worked perfectly and used it with multiple 'If' & 'Or' statements which is what I need
 
Upvote 0
I love Case statements!
But I typically only use them when there are more than two possibilities. Otherwise, there isn't much of an advantage.
 
Upvote 0

Forum statistics

Threads
1,213,522
Messages
6,114,112
Members
448,549
Latest member
brianhfield

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