count text in cells, dont count duplicates

egris52788

Board Regular
Joined
Mar 6, 2003
Messages
114
i need to count a column of text, but not count duplicates, tried this, but it doesnt work
=SUMPRODUCT((A1:A100<>"")/COUNTIF(A1:A100,A1:A100&""))

Eddie
John
Eddie
jack

answer should be 3 total names
 

Excel Facts

Round to nearest half hour?
Use =MROUND(A2,"0:30") to round to nearest half hour. Use =CEILING(A2,"0:30") to round to next half hour.
Try this:
Code:
=SUMPRODUCT(ISTEXT(A1:A100)*(A1:A100<>"")/COUNTIF(A1:A100,A1:A100&""))
Is that something you can work with?

Edited to include this comment:
BTW....Your formula WILL count all unique items (text and numbers).
If the count of your sample data is 4 and not 3...Are there possibly trailing spaces on any of them?
 
Last edited:
Upvote 0
Does the formula return the #DIV/0! error value? If so, then it's due to an inherent bug...

http://groups.google.com/group/micr...xcel*+author:harlan&rnum=134#c20ec397f954a6ce

Here are a couple of alternatives...

=SUM(IF(A1:A100<>"",1/COUNTIF(A1:A100,A1:A100)))

=SUM(IF(FREQUENCY(IF(A1:A100<>"",MATCH("~"&A1:A100,A1:A100&"",0)),ROW(A1:A100)-ROW(A1)+1),1))

Note that both formulas need to be confirmed with CONTROL+SHIFT+ENTER. Also, the second formula is more efficient.
 
Upvote 0

Forum statistics

Threads
1,213,538
Messages
6,114,218
Members
448,554
Latest member
Gleisner2

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