VLookup from a multiselect data validation list

JackReacher85

Banned user
Joined
Sep 14, 2021
Messages
12
Office Version
  1. 2016
Platform
  1. Windows
Hi guys,

Thanks for taking the time to look over this, i have no idea if this is even possible but im intrigued to know if it is.

I have VBA code that allows me to select multiple items in a data validation list rather than the default Excel option of being able to select only one option only.

What im seeking is the ability to have a vlookup look into the drop down list and return results from all the values within the drop down, so for example if the user selects from the drop down, C0, 100 XS, Expert Select the vlookup will then look for each of those items and return the results which would simply be some text the user needs to read etc.

Is this possible or am i barking up the wrong tree?
 

Excel Facts

Convert text numbers to real numbers
Select a column containing text numbers. Press Alt+D E F to quickly convert text to numbers. Faster than "Convert to Number"
Is this possible or am i barking up the wrong tree?
Yes, I think, if I understand what you're trying to achieve.

Consider the following sheet, with multi-select possible in cell A1.
Book1
ABCDE
1adam; clara; dorisNameHDR1HDR2
2adama - 1a - 2
3barneyb - 1b - 2
4clarac - 1c - 2
5dorisd - 1d - 2
6evee - 1e - 2
7fredf - 1f - 2
8
9Output below
10
11
12
Sheet1
Cells with Data Validation
CellAllowCriteria
A1List=$C$2:$C$7


Now running the following code, will use each separate value within the multiple choices, and use that value to do a Vlookup in the range C2:E7 - returning the value from the 3rd column in the range. I saved the values returned in another array, and returned those values below Output Below:
VBA Code:
Option Explicit
Sub test()
    Dim a, b, s As String, i As Long, r As Range
    Set r = Sheet1.Range("C2:E7")
    s = Sheet1.Range("A1")
    a = Split(s, "; ")                  '<~~ This splits each value individually
    ReDim b(0 To UBound(a), 1 To 1)
    For i = LBound(a) To UBound(a)      '<~~ Using each value - one at a time...
        b(i, 1) = WorksheetFunction.VLookup(a(i), r, 3, 0)  '<~~ ...use those values in a Vlookup()
        Debug.Print b(i, 1)             '<~~ (Left in just to show the individual values)
    Next i
    Sheet1.Range("C10").Resize(UBound(b, 1) + 1, 1).Value = b   '<~~ Output the Vlookup results to the sheet
End Sub

Vlookup results put back to the sheet - not sure what exactly you wanted to do with them...
Book1
ABCDE
1adam; clara; dorisNameHDR1HDR2
2adama - 1a - 2
3barneyb - 1b - 2
4clarac - 1c - 2
5dorisd - 1d - 2
6evee - 1e - 2
7fredf - 1f - 2
8
9Output below
10a - 2
11c - 2
12d - 2
Sheet1
Cells with Data Validation
CellAllowCriteria
A1List=$C$2:$C$7


Does this help?
 
Upvote 0
Thanks for the above, however i dont think ive explained myself very well, I have the below code to allow the selecting of multiple items from a drop down list and incorporated into this is code to trigger a warning box when an item is selected from a drop down lists in Cells C7 and G7.

VBA Code:
Private Sub Worksheet_Change(ByVal Destination As Range)
  Dim rngDropdown As Range
  Dim oldValue As String
  Dim newValue As String
  Dim DelimiterType As String
  DelimiterType = " | "
  Dim DelimiterCount As Integer
  Dim TargetType As Integer
  Dim i As Integer
  Dim arr() As String
 
  If Destination.Count > 1 Then Exit Sub
  On Error Resume Next
 
  Set rngDropdown = Cells.SpecialCells(xlCellTypeAllValidation)
  On Error GoTo exitError
 
  If rngDropdown Is Nothing Then GoTo exitError
 
  If Not Intersect(Destination, Range("C25")) Is Nothing Then
    TargetType = 0
    TargetType = Destination.Validation.Type
    If TargetType = 3 Then  ' is validation type is "list"
        Application.ScreenUpdating = False
        Application.EnableEvents = False
        newValue = Destination.Value
        Application.Undo
        oldValue = Destination.Value
        Destination.Value = newValue
        If oldValue <> "" Then
            If newValue <> "" Then
                If oldValue = newValue Or oldValue = newValue & Replace(DelimiterType, " ", "") Or oldValue = newValue & DelimiterType Then ' leave the value if there is only one in the list
                    oldValue = Replace(oldValue, DelimiterType, "")
                    oldValue = Replace(oldValue, Replace(DelimiterType, " ", ""), "")
                    Destination.Value = oldValue
                ElseIf InStr(1, oldValue, DelimiterType & newValue) Then
                    arr = Split(oldValue, DelimiterType)
                If Not IsError(Application.Match(newValue, arr, 0)) = 0 Then
                    Destination.Value = oldValue & DelimiterType & newValue
                        Else:
                    Destination.Value = ""
                    For i = 0 To UBound(arr)
                    If arr(i) <> newValue Then
                        Destination.Value = Destination.Value & arr(i) & DelimiterType
                    End If
                    Next i
                Destination.Value = Left(Destination.Value, Len(Destination.Value) - Len(DelimiterType))
                End If
                ElseIf InStr(1, oldValue, newValue & Replace(DelimiterType, " ", "")) Then
                    oldValue = Replace(oldValue, newValue, "")
                    Destination.Value = oldValue
                Else
                    Destination.Value = oldValue & DelimiterType & newValue
                End If
                Destination.Value = Replace(Destination.Value, Replace(DelimiterType, " ", "") & Replace(DelimiterType, " ", ""), Replace(DelimiterType, " ", "")) ' remove extra commas and spaces
                Destination.Value = Replace(Destination.Value, DelimiterType & Replace(DelimiterType, " ", ""), Replace(DelimiterType, " ", ""))
                If Destination.Value <> "" Then
                    If Right(Destination.Value, 2) = DelimiterType Then  ' remove delimiter at the end
                        Destination.Value = Left(Destination.Value, Len(Destination.Value) - 2)
                    End If
                End If
                If InStr(1, Destination.Value, DelimiterType) = 1 Then ' remove delimiter as first characters
                    Destination.Value = Replace(Destination.Value, DelimiterType, "", 1, 1)
                End If
                If InStr(1, Destination.Value, Replace(DelimiterType, " ", "")) = 1 Then
                    Destination.Value = Replace(Destination.Value, Replace(DelimiterType, " ", ""), "", 1, 1)
                End If
                DelimiterCount = 0
                For i = 1 To Len(Destination.Value)
                    If InStr(i, Destination.Value, Replace(DelimiterType, " ", "")) Then
                        DelimiterCount = DelimiterCount + 1
                    End If
                Next i
                If DelimiterCount = 1 Then ' remove delimiter if last character
                    Destination.Value = Replace(Destination.Value, DelimiterType, "")
                    Destination.Value = Replace(Destination.Value, Replace(DelimiterType, " ", ""), "")
                End If
            End If
        End If
        Application.EnableEvents = True
        Application.ScreenUpdating = True
    End If
  End If
 
  If Not Intersect(Destination, Range("C7")) Is Nothing Then
      Select Case Destination
          Case Is = "Solutions"
              MsgBox "YOU HAVE SELECTED: SOLUTIONS POLICY - NO NCD CHECK REQUIRED"
          Case Is = "H/Sol"
              MsgBox "YOU HAVE SELECTED HEALTHIER SOLUTIONS POLICY - CHECK THE NCD IN UNO AND ACPM"
         End Select
  End If
            
        If Not Intersect(Destination, Range("G7")) Is Nothing Then
      Select Case Destination
          Case Is = "NMORI"
              MsgBox "NMORI - FULL HISTORY TO BE TAKEN - USE STEP 2 TO HELP YOU DETERMINE IF THE SYMPTOMS ARE PRE-EXISTING"
          Case Is = "CMORI"
              MsgBox "CMORI - FULL HISTORY TO BE TAKEN - USE STEP 2 TO HELP YOU DETERMINE IF THE SYMPTOMS ARE PRE-EXISTING"
          Case Is = "CME"
              MsgBox "CME - CHECK IF THE SYMPTOMS ARE RELATED TO ANY EXCLUSIONS IF NOT RELATED TREAT AS MHD"
          Case Is = "FMU"
              MsgBox "FMU - CHECK HISTORY, CHECK IF SYMPTOMS ARE RELATED TO ANY EXCLUSIONS & CHECK IF THE SYMPTOMS REPORTED SHOULD HAVE BEEN DELCARED TO US"
          Case Is = "MHD"
       
              MsgBox "MHD - TAKE BRIEF HISTORY ONLY"
End Select
End If

exitError:
  Application.EnableEvents = True
End Sub

Cell C25 is where the Multiselect drop down list is placed, in this cell i can select multiple items, what i need to have is the Vlookup find each item selected in the list from sheet 2 and return the required value in to the Cell D25.

I hope this provides better context
 
Upvote 0
what i need to have is the Vlookup find each item selected in the list from sheet 2 and return the required value in to the Cell D25.
I think this is the part that I've been focussing on - and I'll leave the rest to you ;)
The following code takes each item in the multi-selection dropdown in cell C25 on sheet 1 and does a Vlookup on a table on sheet 2 - concatenating as many items that you selected and putting the result into cell D25 on sheet 1. Obviously I have no idea where your lookup table is in sheet 2, or which column you want returned, so the following is purely for demonstration purposes to show what is possible:
Is this possible or am i barking up the wrong tree?
Where this would fit into your existing code is a matter for you to decide - if it's even what you've been looking for in the first place. So, running this code:
VBA Code:
Option Explicit
Sub test_Vlookup_Return()
    Dim a, s As String, x As String, i As Long, r As Range
    Set r = Sheet2.Range("A2:C7")
    s = Sheet1.Range("C25")
    a = Split(s, "; ")                  '<~~ This splits each value individually
    For i = LBound(a) To UBound(a)      '<~~ Using each value - one at a time...
        If x = "" Then
            x = WorksheetFunction.VLookup(a(i), r, 3, 0)
        Else
            x = x & "; " & WorksheetFunction.VLookup(a(i), r, 3, 0)
        End If
        Sheet1.Range("D25") = x
    Next i
End Sub

and using this as a lookup table on sheet 2:
jack reacher.xlsm
ABC
1NameHDR1HDR2
2adama - 1a - 2
3barneyb - 1b - 2
4clarac - 1c - 2
5dorisd - 1d - 2
6evee - 1e - 2
7fredf - 1f - 2
Sheet2


Starting from this multi-selection on sheet 1:
jack reacher.xlsm
CD
25fred; barney; eve
Sheet1
Cells with Data Validation
CellAllowCriteria
C25List=Sheet2!$A$2:$A$7


Gives you this result:
jack reacher.xlsm
CD
25fred; barney; evef - 2; b - 2; e - 2
Sheet1
Cells with Data Validation
CellAllowCriteria
C25List=Sheet2!$A$2:$A$7
 
Upvote 0

Forum statistics

Threads
1,215,097
Messages
6,123,076
Members
449,094
Latest member
mystic19

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