Count duplicates and count duplicates based on criteria

leterrier

New Member
Joined
Jan 5, 2013
Messages
44
Products
Suppliers
doorsHarper
windowsSmith
floorsBrown
lightsSmith
tablesJohnson
chairsJones
bedsCooper
sinksJones
baths
sofasSmith

<tbody>
</tbody>

Friends, I again request your assistance.

I have 2 columns of sales data, A and B. Range A3:A12 contains unique product names, range B3:B12 contains non-unique (possibly blank) supplier names.

I wish to know how to construct formulas to tell me;

i) how many suppliers provide more than one product i.e. how many duplicates are in col B? The answer is 2 (Smith and Jones)
and;

ii) for each of these duplicates, how many products do they supply? i.e how many times does each duplicate supplier appear? The answers are Smith = 3, Jones = 2.

Thank you sincerely in anticipation.
 
Dear Aladin_Ayurek,

Thank you for responding to another of my posts. I had missed your reply so apologise for being late in acknowledging. I will give this suggestion a try and let you know!

Control+shift+enter, not just enter:

=SUM(IF(FREQUENCY(IF(B3:B12<>"",MATCH(B3:B12,B3:B12,0)),ROW(B3:B12)-ROW(B3)+1)>1,1))
 
Upvote 0

Excel Facts

Spell Check in Excel
Press F7 to start spell check in Excel. Be careful, by default, Excel does not check Capitalized Werds (whoops)
.. is there a single formula I can place on the sheet that will tell me that 2 suppliers provide more than one product?
I think you'll find that Aladin's formula does exactly that. :)
 
Upvote 0
There's possibly also these?
Both entered with Ctrl+Shift+Enter

1. If any blanks in column B are true blanks (not "" null strings)

=COUNTA(B3:B12)-SUM(IF(B3:B12="",1,1/(COUNTIF(B3:B12,B3:B12))))

2. If blanks are, or may be null strings

=COUNTIF(B3:B12,"?*")-SUM(IF(B3:B12="",1,1/(COUNTIF(B3:B12,B3:B12))))
 
Upvote 0
Aladdin,

This does the trick!!!! Thank you.

Dear Aladin_Ayurek,

Thank you for responding to another of my posts. I had missed your reply so apologise for being late in acknowledging. I will give this suggestion a try and let you know!
 
Upvote 0

Forum statistics

Threads
1,214,944
Messages
6,122,387
Members
449,080
Latest member
Armadillos

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