How to write a formula that returns the number of distinct entries in a
range?

 

First, let's clarify the question. We're hunting for a formula that, given
the range that contains the values 100, 99, 98, 100, 98, 100, 98, would
return 3. In other words, this range contains three different values, some
of them repeated. 

 

This type of counting requires an array formula. The formula below, for
example, counts the number of distinct entries in the range A1:D100.

 

 =SUM(1/COUNTIF(A1:D100, A1:D100)) 

When you enter this formula, you must press Ctrl-Shift-Enter. Pressing only
Enter will give you the wrong result. Excel will place brackets around the
formula to remind you that you've created an array formula. 

 

The preceding formula works fine in many cases, but it will return an error
if the range contains any blank cells. The formula below (also an array
formula, so input it with Ctrl-Shift-Enter) is more complex, but it will
handle a range that contains a blank cell. 

 

=SUM(IF(COUNTIF(A1:D100,A1:D100)=0, "", 1/COUNTIF(A1:D100,A1:D100)))

 

 

 

Regards,

 

Upendra Singh

+91-9910227325, +91-9310760597

 

----------------------------------------------------------------------------
---------------------------------

There are 10 kinds of people: Those who understand binary and those who
don't.

----------------------------------------------------------------------------
---------------------------------


--~--~---------~--~----~------------~-------~--~----~
----------------------------------------------------------------------------------
Some important links for excel users:
1. Excel and VBA Tutorials(Video and Text), Free add-ins downloads at 
http://www.excelitems.com
2. Excel tutorials at http://www.excel-macros.blogspot.com
3. Learn VBA Macros at http://www.vbamacros.blogspot.com
4. Excel Tips and Tricks at http://exceldailytip.blogspot.com
 

To post to this group, send email to excel-macros@googlegroups.com
If you find any spam message in the group, please send an email to:
Ayush Jain  @ jainayus...@gmail.com or
Ashish Jain @ 26may.1...@gmail.com
<><><><><><><><><><><><><><><><><><><><><><>
HELP US GROW !!

We reach over 5,000 subscribers worldwide and receive many nice notes about the 
learning and support from the group. Our goal is to have 10,000 subscribers by 
the end of 2009. Let friends and co-workers know they can subscribe to group at 
http://groups.google.com/group/excel-macros/subscribe
-~----------~----~----~----~------~----~------~--~---

Reply via email to