Apply list selection to multiple columns

patiofern

New Member
Joined
Mar 6, 2021
Messages
1
Office Version
  1. 365
Platform
  1. MacOS
Hello,

I found this piece of code online and am trying to adapt it to work in a range of columns and multiple cells in that column. The code currently adds a dropdown list to the column (column 2 in as written here) then converts the value selected from the dropdown list to a corresponding numerical value in the "dropdown" range. I would like to have the ability to apply this list selection/conversion to numerical value to a range of columns rather than just a single column. Please see code below . . . Thanks!

Private Sub Worksheet_Change(ByVal Target As Range)
'Updateby Extendoffice
selectedNa = Target.Value
If Target.Column = 2 Then
selectedNum = Application.VLookup(selectedNa, ActiveSheet.Range("dropdown"), 2, False)
If Not IsError(selectedNum) Then
Target.Value = selectedNum
End If
End If
End Sub
 

Excel Facts

Add Bullets to Range
Select range. Press Ctrl+1. On Number tab, choose Custom. Type Alt+7 then space then @ sign (using 7 on numeric keypad)
I would like to have the ability to apply this list selection/conversion to numerical value to a range of columns rather than just a single column.


Try this:

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
  'Updateby Extendoffice
  Dim rng As Range, c As Range
  Dim selectedNum
  
  Set rng = Intersect(Target, Range("B2:B20, D2:D20, F2:F20"))
  If Not rng Is Nothing Then
    For Each c In rng
      selectedNum = Application.VLookup(c.Value, ActiveSheet.Range("dropdown"), 2, False)
      If Not IsError(selectedNum) Then
        Application.EnableEvents = False
        c.Value = selectedNum
        Application.EnableEvents = True
      End If
    Next
  End If
End Sub
 
Upvote 0

Forum statistics

Threads
1,214,920
Messages
6,122,272
Members
449,075
Latest member
staticfluids

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