Condense a List, Create sort of an Index: Use Functions ONLY

krazykaj

Board Regular
Joined
Jul 20, 2005
Messages
143
Hello all,

Here’s a quick question that I hope I could get some help with :)
------------------------------------------
Say I have this on my worksheet:
(Starting in cell A2, with each new line representing the next cell down . . .)

Apple
Orange
Banana
Banana
Apple
Apple
Apple
Orange
Banana
Mango
Orange
Orange


Is there an *Excel Function(s)* (I'm purposely trying not to do this with VB Code/macros) that will sort through the list and 'remove' the copies to return me sort of an index of the above.
So going off the above list, the function(s) would somehow give me this result:
(Preferably each in its own cell underneath)

Apple
Orange
Banana
Mango


I hope that makes sense . . .
I also don't want to use a Pivot Table, however the effect I'm after, i.e. the way a pivot table condenses a list, removing the duplicates, is the effect I’m after ;)

Basically I want to take a list, and condense it, producing another list which will contain only one instance of each of the values found in the first list.

Can it be done, or do I need to go beyond the simple excel function(s)?

Any help would be greatly appreciated . . . :biggrin:

Thankyou for your time,
Kind Regards,
KJ
 

Excel Facts

Square and cube roots
The =SQRT(25) is a square root. For a cube root, use =125^(1/3). For a fourth root, use =625^(1/4).
Hi

Assuming that the data as per your example is in the range A1:A12, enter a space in A13. In B1 enter the formula
=COUNTIF($A$1:A1,A1)
and copy down to B12.
In C1 array enter (ctrl, shift and enter) the formula
=INDEX($A$1:$A$13,SMALL(IF($B$1:$B$12=1,ROW($B$1:$B$12),13),ROW()))
Copy and paste down to C12.


HTH

Tony
 
Upvote 0
Data>Filter>Advanced Filter...

I'm sorry if that's short.

BUT MY PEGUINS ARE COLD.
 
Upvote 0
How to extract a list of distinct (unique) items by means of formulas?...
Book1
ABCD
104
2ListIdxDistinct List
3Apple1Apple
4Orange2Orange
5Banana3Banana
6Banana Mango
7Apple  
8Apple 
9Apple 
10Orange 
11Banana 
12Mango4
13Orange 
14Orange 
Sheet1


B1 must house a 0.

B3, copied down:

=IF(A3<>"",IF(ISNA(MATCH(A3,$A$2:A2,0)),LOOKUP(9.99999999999999E+307,$B$1:B2)+1,""),"")

C1:

=LOOKUP(9.99999999999999E+307,B1:B14)

C3, copied down:

=IF(ROW()-ROW(C$3)+1<=$C$1,LOOKUP(ROW()-ROW(C$3)+1,$B$3:$B$14,$A$3:$A$14),"")
 
Upvote 0
:LOL:

Have i ever said how much I love this forum :wink:
Cos i'll say it again :biggrin:
This place has got to be the fastest place to dish out quality help that i've ever come across . . .

Anyways, thankyou Aladin Akyurek and acw heaps for the info, they both work great.
Thanks also Norie :)

Cheers
KJ
(if I have any more questions, I'll be sure to ask)
 
Upvote 0

Forum statistics

Threads
1,214,523
Messages
6,120,047
Members
448,940
Latest member
mdusw

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