Count Unique values only

GreenyMcDuff

Active Member
Joined
Sep 20, 2010
Messages
313
Hi guys,

I have what seemed like a simple problem at first.

In a list of data like this:


BE0002362342
BE0932894455
DE000A0DALH4
DE000A0DALH4
DE000A0DALH4
DE000A0DALH4
DE000A0DALH4
DE000A0EUMQ9
DE000A0EUMQ9
DE000A0EUMQ9


I want to count the number if entries that only appear once.

So out of the list above, if I counted the number of unique entries I would end up with 2 (the first 2).

Hope this makes sense, if not just let me know and I will try and explain it again.

Cheers

Chris
 

Excel Facts

How to fill five years of quarters?
Type 1Q-2023 in a cell. Grab the fill handle and drag down or right. After 4Q-2023, Excel will jump to 1Q-2024. Dash can be any character.
It's ok. I should have spent longer thinking about it.

For anyone else that comes up with the same problem in future here is the answer:

1. Sort the list

2. Enter this formula in the column next to it

Code:
=IF(AND(B2<>B1,B2<>B3),"Unique","Multiple")

Hope this helps someone
 
Upvote 0
Alternatively:
Rich (BB code):
=IF(COUNTIF($B$1:$B$10,B1)=1,"Unique","Multiple")
This eliminates the need to sort your data. Change 10 to whatever the last row number of your data list is.
 
Upvote 0
You could also try putting the following formula in a cell below your data:

{=SUM(IF(COUNTIF($A$2:$A$11;$A$2:$A$11)=1;1;0))}
<?xml:namespace prefix = o ns = "urn:schemas-microsoft-com:eek:ffice:eek:ffice" /><o:p></o:p>
<o:p>Don't forget to press Ctrl-Shift-Enter when you enter the formula as this is an array formula.</o:p>
<o:p></o:p>
<o:p>Hope this helps</o:p>
 
Upvote 0
if data is in A1:A10
=SUM(IF(FREQUENCY(MATCH(A1:A10,A1:A10,0),MATCH(A1:A10,A1:A10,0))=1,1))
 
Upvote 0
How could I change this code, so that if I had a column full of a few hundred entries similar to this;

apples
apples
apples
pears
pears
oranges
oranges
bananas
grapefruit
apple

I would get a unique count of each, like;

apples = 3
apple = 1
pears = 2
oranges = 2
bananas = 1
grapefruit = 1

Thanks
 
Last edited:
Upvote 0
If Column A contains the few hundred entries
and Column B already has:
apples
apple

pears
oranges

bananas
grapefruit
then Column C just requires a CountIF
ex. formula in C1
=Countif(A:A,B1)

if Column B needs to be filled:
1) Go To The Data Tab
2) Under Sort & Filter, Click Advanced
3) Under Action, Enable Copy to Another Location
4) For List range: Select Column A
5) For Copy to: Select B1
6) Check the Box for Unique records only
 
Upvote 0
Hi guys,

I have what seemed like a simple problem at first.

In a list of data like this:


BE0002362342
BE0932894455
DE000A0DALH4
DE000A0DALH4
DE000A0DALH4
DE000A0DALH4
DE000A0DALH4
DE000A0EUMQ9
DE000A0EUMQ9
DE000A0EUMQ9


I want to count the number if entries that only appear once.

So out of the list above, if I counted the number of unique entries I would end up with 2 (the first 2).

Hope this makes sense, if not just let me know and I will try and explain it again.

Cheers

Chris

Control+shift+enter, not just enter:

=SUM(IF(FREQUENCY(IF(A2:A9<>"",MATCH("~"&A2:A9,A2:A9&"",0)),ROW(A2:A9)-ROW(A2)+1),1))
 
Upvote 0
If Column A contains the few hundred entries
and Column B already has:
apples
apple

pears
oranges

bananas
grapefruit
then Column C just requires a CountIF
ex. formula in C1
=Countif(A:A,B1)

if Column B needs to be filled:
1) Go To The Data Tab
2) Under Sort & Filter, Click Advanced
3) Under Action, Enable Copy to Another Location
4) For List range: Select Column A
5) For Copy to: Select B1
6) Check the Box for Unique records only

Hi Ganjin,

The second column doesn't have the unique fields. How can I auto generate all the uniques (approx 100+) in column B?

Thanks
 
Upvote 0
my friend, the answer is right under your nose :p

if Column B needs to be filled:
1) Go To The Data Tab
2) Under Sort & Filter, Click Advanced
3) Under Action, Enable Copy to Another Location
4) For List range: Select Column A
5) For Copy to: Select B1
6) Check the Box for Unique records only
 
Upvote 0

Forum statistics

Threads
1,213,568
Messages
6,114,348
Members
448,570
Latest member
rik81h

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