Combining multiple worksheet change events with application.intersect

rada

New Member
Joined
Jun 2, 2021
Messages
2
Office Version
  1. 365
Platform
  1. Windows
Hello all,

I've looked at a few threads but haven't been able to fix my code to do what I want.

I'm writing a basic script to enter the text "Please Select..." in the adjoining criteria fields once a person selects an initial criteria to prompt them to select level 2 and level 3 categories so risk and opportunity data flows correctly through my summary P&L based on 3 levels of category. The selections will reset and display "Please Select..." every time a drop down value has changed so that the conditional drop downs don't stay frozen when a level 1 or level 2 category has been changed. In addition, once a person has selected a category and entered the $ Impact on the same row, I want the risk category drop down cell next to the $ Impact to display "Please Select..." so that they can assign a risk category to the number value they've entered or changed. Here's what I've got, I tried playing with multiple elseifs and application.enableevents = true/false to accomplish this but it usually ends the script after one change event. I want to combine these two change events so that any change in columns b, c, and g trigger the events I've described above. Any help would be appreciated.

VBA Code:
Sub Worksheet_Change(ByVal Target As Range)

Dim Category As Range
Set Category = ActiveSheet.Range("B3:C59")

If Application.Intersect(Target, Category) Is Nothing Then
Exit Sub
ElseIf Application.Intersect(Target, Category).Address = Target.Address Then
Target.Offset(0, 1).Range("a1").Value = "Please Select..."

If Application.Intersect(Target, Category).Value = "" Then
Target.Offset(0, 0).Range("a1").Value = "Please Select..."
End If
End If

Sub Worksheet_Change(ByVal Target As Range)

Dim Category As Range
Set Impact = ActiveSheet.Range("G3:G59")

If Application.Intersect(Target, Impact) Is Nothing Then
Exit Sub
ElseIf Application.Intersect(Target, Impact).Address = Target.Address Then
Target.Offset(0, 1).Range("a1").Value = "Please Select..."

If Application.Intersect(Target, Impact).Value = "" Then
Target.Offset(0, 0).Range("a1").Value = "Please Select..."
End If
End If

End Sub
 

Excel Facts

Which came first: VisiCalc or Lotus 1-2-3?
Dan Bricklin and Bob Frankston debuted VisiCalc in 1979 as a Visible Calculator. Lotus 1-2-3 debuted in the early 1980's, from Mitch Kapor.
Hi & welcome to MrExcel.
How about
VBA Code:
Sub Worksheet_Change(ByVal Target As Range)
   If Target.CountLarge > 1 Then Exit Sub
   If Not Intersect(Target, Range("B3:C59")) Is Nothing Then
      Target.Offset(0, 1).Value = "Please Select..."
      If Target.Value = "" Then Target.Value = "Please Select..."
   ElseIf Not Intersect(Target, Range("G3:G59")) Is Nothing Then
      Target.Offset(0, 1).Value = "Please Select..."
      If Target.Value = "" Then Target.Value = "Please Select..."
   End If
End Sub
 
Upvote 0
Solution
Thank you very much @Fluff, I appreciate the quick reply. That worked perfect!
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,214,822
Messages
6,121,767
Members
449,049
Latest member
greyangel23

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