Count Discrete Text values in column if other column value

chauber

New Member
Joined
Oct 14, 2019
Messages
5
I have a large set of data from which I am trying to generate information. I am having difficulty with the following example (obviously my data set is much larger than this):

Name
Favorite Color
# of Pets
Joeyellow4
Kellygreen3
Davidgreen3
Richardorange2
Vickiblue3

<tbody>
</tbody>

What I am trying to do is make a function that will determine how many different favorite colors there are for people who have X amount of pets. For example, there are 2 different favorite colors for people who own 3 pets.

Since my data set is large, I would like to create a formula that can do this over a ~5000 rows.

Thanks
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
Welcome to Mr Excel forum

Try


A
B
C
D
E
F
1
Name​
Favorite Color​
# of Pets​
# of Pets​
Diff Colors​
2
Joe​
yellow​
4​
3​
2​
3
Kelly​
green​
3​
4​
1​
4
David​
green​
3​
2​
1​
5
Richard​
orange​
2​
6
Vicki​
blue​
3​
7

Criteria in colunm E

Array formula in F2 copied down
=SUM(IF(FREQUENCY(IF(C$2:C$5000=E2,IF(B$2:B$5000<>"",MATCH(B$2:B$5000,B$2:B$5000,0))),ROW(B$2:B$5000)-ROW(B$2)+1),1))
confirmed with Ctrl+Shift+Enter simultaneously, not just Enter

Hope this helps

M.
 
Upvote 0

Forum statistics

Threads
1,213,534
Messages
6,114,185
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