Arbitrary Lookups - return ALL found values

B

baki

Hello, for long time now I'm searching a way in excel to solve following:
Data I have:
Name Score
Annie 11
Beth 22
Cathy 33
Dana 44
Annie 55
Beth 66
Annie 77
Beth 88
Cathy 99

Data I want to produce:
Name Score
Annie 11|55|77
Beth 22|66
Cathy 33|99
Dana 44

The character "|" is just a example of separator it can be any other
meaningfull characted.
 
T

Teethless mama

Download and install the free add-in Morefunc.xll from:
http://xcell05.free.fr/english/

then use the following formulas

To get unique names:

In D2:
=IF(ISERR(SMALL(IF(MATCH(Name,Name,0)=ROW(INDIRECT("1:"&ROWS(Name))),MATCH(Name,Name,0)),ROWS($1:1))),"",INDEX(Name,SMALL(IF(MATCH(Name,Name,0)=ROW(INDIRECT("1:"&ROWS(Name))),MATCH(Name,Name,0)),ROWS($1:1))))

ctrl+shift+enter, not just enter
copy down

In E2: =SUBSTITUTE(TRIM(MCONCAT(IF(Name=$D2,Score,"")&" "))," ","|")

ctrl+shift+enter, not just enter
copy down
 
G

Gary''s Student

With your data in cols A & B, running this macro:

Sub baki()
Range("C:D").Clear
n = Cells(Rows.Count, 1).End(xlUp).Row
Cells(2, 3).Value = Cells(2, 1).Value
k = 3
For i = 3 To n
Set bb = Range("A2:A" & i)
cnt = Application.WorksheetFunction.CountIf(bb, Cells(i, 1))
If cnt = 1 Then
Cells(k, 3).Value = Cells(i, 1).Value
k = k + 1
End If
Next

For i = 2 To k - 1
flr = Cells(i, 3).Value
For j = 2 To n
If flr = Cells(j, 1).Value Then
Cells(i, 4).Value = Cells(i, 4).Value & Cells(j, 2).Value & "!"
End If
Next
Next
End Sub

will give you the desired data in cols C & D
 
B

baki

Hi Teethless mama,
I've downloaded add-in but your first formula is not wokring for me.
I've put data starting in A1 but when I insert your function in D2 it does
not show any data nor error - just blank. Am I missing something.
 
T

T. Valko

If you're going to use Morefunc to concat the data why not use Morefunc to
extract the uniques?
=IF(ISERR(SMALL(IF(MATCH(Name,Name,0)=ROW(INDIRECT("1:"&ROWS(Name))),MATCH(Name,Name,0)),ROWS($1:1))),"",INDEX(Name,SMALL(IF(MATCH(Name,Name,0)=ROW(INDIRECT("1:"&ROWS(Name))),MATCH(Name,Name,0)),ROWS($1:1))))


=INDEX(UNIQUEVALUES(Name),ROWS(A$1:A1))
 
B

baki

Hi again Teethless mama,
I was wrong, your code does work, I'm not so profound with Excel so I did
not get it right away that ranges shuld be defined. Thanks for your help.
 
T

Tim Fisher

The code works great for total nummeric values in 'A2:A' but is there a way to open the format requirements, to allow text or any of the other formats available to be in column A? For example I have some ESNs (Alphanumeric data) that when I paste them, I get the green triangle in the upper right corner. If I leave them alone and run the macro, it wont comeplete the. IF I convert the pasted data to where all the data is alligned to the right side of the cell(green thiny goes away)... excel will truncate the data; and the macro will complete. I have data for an example and I am not seeing where i can upload data for an example....I will return to see if there is a reply. Thx.
 
G

Gord Dibben

Try posting within the original thread.

A standalone post like yours gives no background or information about the
original problem or the code supplied.


Gord Dibben MS Excel MVP
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top