How many values appear more than once in a range?

B

Bruce Norris

Could someone help me out on this, please?

I have a single column range as a defined name (rngPlaces).

I want a formula in another cell to count how many values (text) appear
more than once in the range.

So...
- Values that appears only once in the list: Don't count.
- Values that appears more than once in the list: Count the value as 1.
- Blank cells: Don't count.

To further clarify - a value that appears multiple times is only
counted once.

- "Mexico City" appears 50 times: "Mexico City" counted as 1
- "Paris" appears 2 times: "Paris" counted as 1
- "Denver" appears 1 time: "Denver" counted as 0

Any ideas?

Excel 2002.

Thanks.
 
B

Bernie Deitrick

Bruce,

Array enter (enter using Ctrl-Shift-Enter)

=SUM(IF(1/COUNTIF(rngPlaces,rngPlaces)<1,1/COUNTIF(rngPlaces,rngPlaces),0))

will work as long as rngPlaces isn't a complete column (must be less than
65536 cells long)

HTH,
Bernie
MS Excel MVP
 
M

Max

Perhaps try, array-entered (CTRL+SHIFT+ENTER):

=SUM(IF(LEN(rngPlaces)>0,1/COUNTIF(rngPlaces,rngPlaces)))-SUM(--(COUNTIF(rng
Places,rngPlaces)=1))
 
H

Harlan Grove

Bruce Norris said:
I want a formula in another cell to count how many values (text) appear
more than once in the range.

So...
- Values that appears only once in the list: Don't count.
- Values that appears more than once in the list: Count the value as 1.
- Blank cells: Don't count.
....

Another alternative,

=SUMPRODUCT((Rng<>"")*(COUNTIF(Rng,Rng)>1)/(COUNTIF(Rng,Rng)+(Rng="")))
 
H

Harlan Grove

Bernie Deitrick said:
Array enter (enter using Ctrl-Shift-Enter)

=SUM(IF(1/COUNTIF(rngPlaces,rngPlaces)<1,1/COUNTIF(rngPlaces,rngPlaces),0))
....

You didn't test this with the OP's specs in mind. If the OP's range contains
blanks (and since the OP explicitly mentions this case, whatcha suppose the
odds are that there will be some blank cells?), your formula returns #DIV/0!
 
B

Bruce Norris

Hmmm. I see what your formulas do, but was looking more to answer this
question...
"How many cities in the list appear more than once?"

So, I don't want to only count "Mexico City", but any and all cities that
appear more than once. Again, I'm looking for a formula in one cell to do
this. I know I can put a special countif in an additional column within each
record then sum that up or whatever. But I'm hoping for one formula to do
it.

Any thoughts?
 
B

Bruce Norris

Oh, that was soooo close, but like Harlan points out, I do have some blanks
involved. Bummer.

Maybe there's no way to do this with just a formula?
 
B

Bruce Norris

Brilliant. That seems to work great. I don't understand it, but it works.

What is the "--" for in the syntax?

Maybe you can look at my other question,
"How to CountIf Involving Another Column"?

Thanks a bunch for your time!!
 
B

Bruce Norris

Harlan Grove said:
...

Another alternative,

=SUMPRODUCT((Rng<>"")*(COUNTIF(Rng,Rng)>1)/(COUNTIF(Rng,Rng)+(Rng="")))

That works too! Thanks, Harlan. I have to admit, I'm more used to Sumproduct
functions. Can you see any advantage to yours over the one Max offered?

Would you mind looking at my other question,
"How to countif involving another column"?

Thanks for all your time, Harlan.
 
H

Harlan Grove

Bruce Norris said:
....
. . . Can you see any advantage to yours over the one Max offered?

Which is (using same range name)

=SUM(IF(LEN(Rng)>0,1/COUNTIF(Rng,Rng)))-SUM(--(COUNTIF(Rng,Rng)=1))

Max's might be more recalc efficient, but array formulas can be perverse at
times. Max's also is shorter, which is usually better. However, I didn't
need one of my numerator tests since blank cells in Rng have count 0, so
make that

=SUMPRODUCT((COUNTIF(Rng,Rng)>1)/(COUNTIF(Rng,Rng)+(Rng="")))

which is now shortest.
 
M

Max

Bruce Norris said:
Brilliant. That seems to work great.
.. I don't understand it, but it works.

Some clarifications ..

SUM(IF(LEN(rngPlaces)>0,1/COUNTIF(rngPlaces,rngPlaces)))

The 1st part of the formula (above) returns the
count of all unique items in the range

SUM(--(COUNTIF(rngPlaces,rngPlaces)=1))

The 2nd part of the formula (above) returns the
count of unique items which appear only *once* in the range
(This count has to be subtracted from the 1st part of the formula
according to your specs)

So the net return (1st - 2nd) gives the desired result
What is the "--" for in the syntax?

In ... SUM(--(COUNTIF(rngPlaces,rngPlaces)=1))

The "--" is to coerce the TRUE / FALSE returns by the COUNTIF(...)
into 1's and 0's for SUM(...) to return the total
 
B

Bernie Deitrick

Bruce,

Just for completeness - the correct form of my formula to ignore blanks is
to array enter

=SUM(IF(COUNTIF(rngplaces,rngplaces)>1,1/COUNTIF(rngplaces,rngplaces),0))

Sorry that I missed that requirement.

HTH,
Bernie
MS Excel MVP
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top