Is it even POSSIBLE to get multiple outcome via vlookup?

sejun87

New Member
Joined
Nov 11, 2018
Messages
11
Hello, I've got a question regarding extracting multiple values. I'm well aware of vlookup and other frequently used functions but I need your advice for this one.


833590295_MFWhSzN9_vlookup.jpg



[FONT=굴림][/FONT][FONT=맑은 고딕]Let's say there are teachers and we want to match their subjects they teach at school using pre-existing subject key codes. [/FONT]

[FONT=굴림][/FONT][FONT=맑은 고딕] [/FONT]

[FONT=굴림][/FONT][FONT=맑은 고딕]Let's say column E and F are already set, and I'm trying to fill in column C. Instead of putting typing every value, I'm using subject key codes. Teacher A and B are fine just using simple vlookup function, but when it comes to teacher C, who teaches both math and science, I don't seem to know any functions that would make this possible. [/FONT]

[FONT=굴림][/FONT][FONT=맑은 고딕] [/FONT]
[FONT=굴림][/FONT][FONT=맑은 고딕]Format doesn't matter (as shown in teacher D), but I'd like the result (cell C3) say Math, Science (or Math|Science). Is there any way I can possibly try? [/FONT]

[FONT=굴림][/FONT][FONT=맑은 고딕] [/FONT]
[FONT=굴림][/FONT][FONT=맑은 고딕]Thanks[/FONT]

[FONT=굴림][/FONT]
 

Excel Facts

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.
There are some really long, complicated formulas to do what you want, but even then you'd need the TEXTJOIN function, which is currently only available in Excel 365. You're better off using a UDF. To try that, open a copy of your workbook. Press Alt-F11 to open the VBA editor. From the menu select Insert > Module. In the window that opens, paste this code:

Code:
Public Function GetSubject(ByVal Codes As String, ByVal SubTab As Range, ByVal Delim As String) As String
Dim i As Long, MyVals As Variant
    
    For i = 1 To Len(Codes)
        If Not Mid(Codes, i, 1) Like "#" Then Mid(Codes, i, 1) = " "
    Next i
    MyVals = Split(WorksheetFunction.Trim(Codes), " ")
    On Error Resume Next
    For i = 0 To UBound(MyVals)
        GetSubject = GetSubject & Delim & WorksheetFunction.VLookup(CLng(MyVals(i)), SubTab, 2, 0)
    Next i
    GetSubject = Mid(GetSubject, Len(Delim) + 1)
    
End Function
Press Alt-Q to close the editor. Now you can use the new function as in the example below:

ABCDEF
1NameSubject key codeSubjectNo.Subject
2Teacher A1Math1Math
3Teacher B2Science2Science
4Teacher C1,2Math, Science3English
5Teacher D1|2Math, Science
6Teacher E2,4|3Science, English

<colgroup><col style="width: 25pxpx"><col><col><col><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Sheet5

Worksheet Formulas
CellFormula
C2=getsubject(B2,$E$2:$F$4,", ")

<thead>
</thead><tbody>
</tbody>

<tbody>
</tbody>

The first parameter is the key code, the next is the address of the table, and the last is the delimiter you want to use between the results.
 
Upvote 0

Forum statistics

Threads
1,214,584
Messages
6,120,385
Members
448,956
Latest member
JPav

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