Change Value of another cell based on typed in cell value

RagingBokky

New Member
Joined
May 27, 2017
Messages
12
Hello All,

My current problem is

I want to be able to type in a certain value such as test and when I press enter to finalize the value I want it to change a value of another cell or more

I have the following private sub

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Not Intersect(Target, Cells(Selection.Row, 13)) Is Nothing Then
        Select Case Cells(Selection.Row, 13)
            Case "NA":             Cells(Selection.Row, 8) = "NWR"
                                   Cells(Selection.Row, 9) = "NWR"
                                   Cells(Selection.Row, 10) = "NWR"
            Case "Desktop Survey": Cells(Selection.Row, 8) = "Desktop Survey"
                                   Cells(Selection.Row, 9) = "NWR"
                                   Cells(Selection.Row, 10) = "NWR"
            End Select
            ElseIf Not Intersect(Target, Cells(Selection.Row, 5)) Is Nothing Then
                Select Case Cells(Selection.Row, 5).Value
                    Case "test":    Cells(Selection.Row, 13) = "Desktop Survey"
                    
                End Select
                                    
            End If
            
        
            End Sub

however when I type in test in the E column the expected outcome of changing column M to Desktop Survey doesn't happen

but...when I change it to a data validation type thing with a drop down menu works perfectly...but its not how I want it to function

I have tried as well

VBA Code:
Private Sub Worksheet_SelectionChange(ByVal Target As Range)
    If Cells(Selection.Row, 5) = "test" Then
        Cells(Selection.Row, 13) = "Desktop Survey"
        End If

'End Sub

I type in test this time however it does nothing when I press enter in column E but does finally change the value if I deselect and then select the cell

It is not how I ideally want it to function

I really prefer to type in the Value itself and upon pressing enter to finalize the cell value due to the value equal change the value of another cell

I am wondering if I am using the function wrong at all so I am not entirely sure
 

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.
Check if this is what you need.

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
  If Target.CountLarge > 1 Then Exit Sub
  
  If Not Intersect(Target, Range("E:E")) Is Nothing Then
    If Target.Value = "test" Then Cells(Target.Row, "M") = "Desktop Survey"
  End If
  
  If Not Intersect(Target, Range("M:M")) Is Nothing Then
    Select Case Target.Value
      Case "NA"
        Cells(Target.Row, 8) = "NWR"
        Cells(Target.Row, 9) = "NWR"
        Cells(Target.Row, 10) = "NWR"
      Case "Desktop Survey"
        Cells(Target.Row, 8) = "Desktop Survey"
        Cells(Target.Row, 9) = "NWR"
        Cells(Target.Row, 10) = "NWR"
    End Select
  End If

End Sub
 
Upvote 0
Thanks for the Building Block @DanteAmor

It worked as required intention but it only work for 1 value and I was wondering what if I wanted to add to that list. Alter the code a little bit and made it work as well make a clear content if that cell has no value

My Final code

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
  If Target.CountLarge > 1 Then Exit Sub
  
  If Not Intersect(Target, Cells(Target.Row, 5)) Is Nothing Then
    If Target.Value = "test" Then
        Cells(Target.Row, 13) = "Desktop Survey"
    ElseIf Target.Value = "data" Then
        Cells(Target.Row, 13) = "Desktop Survey"
    ElseIf Target.Value = "123" Then
        Cells(Target.Row, 13) = "NA"
    Else
        Cells(Target.Row, 8).ClearContents
        Cells(Target.Row, 9).ClearContents
        Cells(Target.Row, 10).ClearContents
        Cells(Target.Row, 13).ClearContents
  End If
  End If

  
  If Not Intersect(Target, Cells(Target.Row, 13)) Is Nothing Then
    Select Case Target.Value
      Case "NA"
        Cells(Target.Row, 8) = "NWR"
        Cells(Target.Row, 9) = "NWR"
        Cells(Target.Row, 10) = "NWR"
      Case "Desktop Survey"
        Cells(Target.Row, 8) = "Desktop Survey"
        Cells(Target.Row, 9) = "NWR"
        Cells(Target.Row, 10) = "NWR"
    End Select

End If

End Sub
 
Upvote 0
Try this

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
  If Target.CountLarge > 1 Then Exit Sub
  
  If Not Intersect(Target, Range("E:E")) Is Nothing Then
    Select Case Target.Value
      Case "test", "data"
        Cells(Target.Row, "M") = "Desktop Survey"
      Case "123"
        Cells(Target.Row, "M") = "Desktop Survey"
      Case Else
        Cells(Target.Row, 8).ClearContents
        Cells(Target.Row, 9).ClearContents
        Cells(Target.Row, 10).ClearContents
        Cells(Target.Row, 13).ClearContents
    End Select
  End If
  
  If Not Intersect(Target, Range("M:M")) Is Nothing Then
    Select Case Target.Value
      Case "NA"
        Cells(Target.Row, 8) = "NWR"
        Cells(Target.Row, 9) = "NWR"
        Cells(Target.Row, 10) = "NWR"
      Case "Desktop Survey"
        Cells(Target.Row, 8) = "Desktop Survey"
        Cells(Target.Row, 9) = "NWR"
        Cells(Target.Row, 10) = "NWR"
    End Select
  End If

End Sub

Note:
For me it is easier to read:
Target, Range ("E: E")
Cells (Target.Row, "M")
etc.

instead of:
Cells(Target.Row, 5)
Cells(Target.Row, 13)
 
Upvote 0
I'm glad to help you. Thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,214,653
Messages
6,120,748
Members
448,989
Latest member
mariah3

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