vlookup, multiple options

avandever

Board Regular
Joined
Dec 7, 2010
Messages
83
I have a 3 column table, one with the Order Number, one with Notes, and one with the # of characters in the notes.

Each order can have multiple notes that i am concatenating from another table. For example:

A123 note1, note2, note3
A123 note1, note2
A123 note1

I sort these by amount of characters which would make A1233 go to the top. When I vlookup A123 I want it to return the one with all the notes combined(the one towards the top with the most characters.) For the most part it does work by doing this, but sometimes it will return the 2nd or 3rd one within the list. Thanks.
 

Excel Facts

How can you automate Excel?
Press Alt+F11 from Windows Excel to open the Visual Basic for Applications (VBA) editor.
If I follow, try:

<TABLE style="BACKGROUND-COLOR: #ffffff; PADDING-LEFT: 2pt; PADDING-RIGHT: 2pt; FONT-FAMILY: Calibri,Arial; FONT-SIZE: 11pt" border=1 cellSpacing=0 cellPadding=0><COLGROUP><COL style="WIDTH: 30px; FONT-WEIGHT: bold"><COL style="WIDTH: 98px"><COL style="WIDTH: 131px"><COL style="WIDTH: 107px"><COL style="WIDTH: 19px"><COL style="WIDTH: 98px"><COL style="WIDTH: 131px"></COLGROUP><TBODY><TR style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt; FONT-WEIGHT: bold"><TD></TD><TD>A</TD><TD>B</TD><TD>C</TD><TD>D</TD><TD>E</TD><TD>F</TD></TR><TR style="HEIGHT: 18px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">1</TD><TD>Order Number</TD><TD>Notes</TD><TD>Character Count</TD><TD></TD><TD>Order Number</TD><TD>Notes</TD></TR><TR style="HEIGHT: 18px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">2</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">A124</TD><TD>note1, note2</TD><TD style="TEXT-ALIGN: right">12</TD><TD></TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">A123</TD><TD>note1, note2, note3</TD></TR><TR style="HEIGHT: 18px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">3</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">A123</TD><TD>note1, note2, note3</TD><TD style="TEXT-ALIGN: right">19</TD><TD></TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">A124</TD><TD>note1, note2</TD></TR><TR style="HEIGHT: 18px"><TD style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">4</TD><TD style="FONT-FAMILY: Verdana; FONT-SIZE: 10pt">A123</TD><TD>note1</TD><TD style="TEXT-ALIGN: right">5</TD><TD></TD><TD></TD><TD></TD></TR></TBODY></TABLE>

Formula in C2 copied down is:

Code:
=LEN(B2)
Array formula in F2 copied down is:

Code:
=INDEX(B$2:B$4,MATCH(MAX(IF(A$2:A$4=E2,C$2:C$4)),C$2:C$4,0))

Array formulas need committing with CTRL+SHIFT+ENTER.

Matty
 
Upvote 0

Forum statistics

Threads
1,223,460
Messages
6,172,342
Members
452,454
Latest member
MadamRedRabbit

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