Formula challenge - How to write a formula that returns non-duplicate items from a list?

mfexcel

Well-known Member
Joined
Jan 8, 2009
Messages
791
Hi all experts,
I am wondering if I could create a dynamic name range that returns only non-duplicate items from a list?

e.g. in cell A1:A6, I have
Apple
Apple
Apple
Banana
Grape
Grape

I want to create a dynamic name range that returns only Apply,Banana,Grape.

Is it possible?

Any hints are appreciate!
 
Hi Aladin,
Thanks so much. This is also nice!!
Noted that you have put "~"& and &"" in the Match formula, is there any special reason for that?? coz i tried to put that out and the formula seems working well too.
actually, i don't get the usage of array very well when the "Criteria" is a range rather than just a value or logic...
Appreciate your advise.


A single formula approach...

B1, control+shift+enter, not just enter, and copy down:
Rich (BB code):
=IFERROR(INDEX($A$1:$A$7,SMALL(IF(FREQUENCY(IF($A$1:$A$7<>"",
  MATCH("~"&$A$1:$A$7,$A$1:$A$7&"",0)),ROW($A$1:$A$7)-ROW($A$1)+1),
  ROW($A$1:$A$7)-ROW($A$1)+1),ROWS(B$1:B1))),"")
 
Upvote 0
Hi Aladin,
Thanks so much. This is also nice!!
Noted that you have put "~"& and &"" in the Match formula, is there any special reason for that?? coz i tried to put that out and the formula seems working well too.
actually, i don't get the usage of array very well when the "Criteria" is a range rather than just a value or logic...
Appreciate your advise.

Those bits are meant to counteract special meaning chars like <, etc. If they can't occur in your situation, drop them. That would improve the efficiency somewhat...

Rich (BB code):
=IFERROR(INDEX($A$1:$A$7,SMALL(IF(FREQUENCY(IF($A$1:$A$7<>"",
  MATCH($A$1:$A$7,$A$1:$A$7,0)),ROW($A$1:$A$7)-ROW($A$1)+1),
  ROW($A$1:$A$7)-ROW($A$1)+1),ROWS(B$1:B1))),"")
 
Upvote 0
Data --> Remove Duplicates
that helps you to create a unique list quickly without any formulation.
depends on what you try to do, you don't have to use the array formula discussed which serves another purpose.

Dear Sir

can we create unique list without Array Formula, Which calculate faster

Ankur
 
Upvote 0
Data --> Remove Duplicates
that helps you to create a unique list quickly without any formulation.
depends on what you try to do, you don't have to use the array formula discussed which serves another purpose.

Certainly a good idea, but manual. If a somewhat fast formula approach is wanted, for a generic (non-conditional) case we can have:

[TABLE="width: 202"]
<TBODY>[TR]
[TD="class: xl64, width: 91, bgcolor: transparent"]ITEMS
[/TD]
[TD="class: xl64, width: 64, bgcolor: transparent, align: right"]0
[/TD]
[TD="class: xl63, width: 115, bgcolor: transparent, align: right"]3
[/TD]
[/TR]
[TR]
[TD="class: xl63, bgcolor: transparent"]Apple
[/TD]
[TD="class: xl63, bgcolor: transparent, align: right"]1
[/TD]
[TD="class: xl64, bgcolor: transparent"]Unique List
[/TD]
[/TR]
[TR]
[TD="class: xl63, bgcolor: transparent"]Apple
[/TD]
[TD="class: xl63, bgcolor: transparent"][/TD]
[TD="class: xl63, bgcolor: transparent"]Apple
[/TD]
[/TR]
[TR]
[TD="class: xl63, bgcolor: transparent"]Apple
[/TD]
[TD="class: xl63, bgcolor: transparent"][/TD]
[TD="class: xl63, bgcolor: transparent"]Banana
[/TD]
[/TR]
[TR]
[TD="class: xl63, bgcolor: transparent"]Banana
[/TD]
[TD="class: xl63, bgcolor: transparent, align: right"]2
[/TD]
[TD="class: xl63, bgcolor: transparent"]Grape
[/TD]
[/TR]
[TR]
[TD="class: xl63, bgcolor: transparent"]Grape
[/TD]
[TD="class: xl63, bgcolor: transparent, align: right"]3
[/TD]
[TD="class: xl63, bgcolor: transparent"][/TD]
[/TR]
[TR]
[TD="class: xl63, bgcolor: transparent"]Grape
[/TD]
[TD="class: xl63, bgcolor: transparent"][/TD]
[TD="class: xl63, bgcolor: transparent"][/TD]
[/TR]
</TBODY>[/TABLE]

B1 must house a 0.

B2, copied down:
Rich (BB code):
=IF(ISNUMBER(MATCH(A2,$A$1:A1,0))+(A2=""),"",
  LOOKUP(9.99999999999999E+307,$B$1:B1)+1)

C1, just enter:
Rich (BB code):
=LOOKUP(9.99999999999999E+307,B:B)
C3, just enter and copy down:
Rich (BB code):
=IF(ROWS($C$3:C3)<=$C$1,LOOKUP(ROWS($C$3:C3),B:B,A:A),"")

Note that the foregoing set up trades off memory against time (speed).
 
Last edited:
Upvote 0

Forum statistics

Threads
1,226,848
Messages
6,193,317
Members
453,790
Latest member
yassinosnoo1

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