is this a match ?

Orangeanorak

Active Member
Joined
Nov 22, 2002
Messages
276
Office Version
  1. 365
Platform
  1. Windows
Can you please give me the formula to display the following

I have ten numbers in A1-A10

I have ten numbers in B1-B10 etc

in B11 I want to display the total times the numbers in b1:b10 match the numbers in a1:a10

in row A1-A10 3 5 8 11 22 34 37 45 50 53
row B1-B10 4 8 12 22 35 39 50 55 60 75

B11 would show 3

thank you very much for this
 

Excel Facts

Control Word Wrap
Press Alt+Enter to move to a new row in a cell. Lets you control where the words wrap.
Hi,
try using an array formula (You should confirm it Ctrl+Shift+Enter):
Code:
=SUM(COUNTIF(A1:A10,B1:B10))
Best regards.
 
Upvote 0
I think that I find another, array solution:
Code:
=20-SUM(1/COUNTIF(A1:B10,A1:B10))
Best regards.
 
Upvote 0
If you want a non-CSE formula
=SUMPRODUCT(COUNTIF(A1:A10,B1:B10))

But, if you duplicates in either column, it might not do what you want.
 
Upvote 0
For duplicates an array formula
Code:
=SUM(SIGN(COUNTIF(A1:A10,B1:B10)))
should be more suitable... Best regards.
 
Upvote 0
Can you please give me the formula to display the following

I have ten numbers in A1-A10

I have ten numbers in B1-B10 etc

in B11 I want to display the total times the numbers in b1:b10 match the numbers in a1:a10

in row A1-A10 3 5 8 11 22 34 37 45 50 53
row B1-B10 4 8 12 22 35 39 50 55 60 75

B11 would show 3

thank you very much for this
Here's another one...

=SUMPRODUCT(--ISNUMBER(MATCH(B1:B10,A1:A10,0)))
 
Upvote 0
For duplicates an array formula
Rich (BB code):
=SUM(SIGN(COUNTIF(A1:A10,B1:B10)))
should be more suitable... Best regards.

The OP wants a count of the items from B1:B10 which match A1:A10.
That is, target range = B1:B10, criteria range = A1:A10.

8
4
5
8
8
12
11
22
22
35
34
39
37
50
45
55
50
60
53
75

<tbody>
</tbody>

The formula...

[1]
Rich (BB code):
{=SUM(SIGN(COUNTIF(B1:B10,A1:A10)))}
would be affected by the duplicates that are in the criteria range while occurring just once in the target range...

Here it yields 4.

So would...

[2]
Rich (BB code):
{=SUM(COUNTIF(B1:B10,A1:A10))}
[3]
Rich (BB code):
=SUMPRODUCT(COUNTIF(B1:B10,A1:A10))
But...

[4]
Rich (BB code):
=SUMPRODUCT(ISNUMBER(MATCH(B1:B10,A1:A10,0))+0)
returns a count of 3.

If the intent is to return the count of unique matching items, we would need something like:

[5]
Rich (BB code):
{=SUM(IF(FREQUENCY(IF(ISNUMBER(MATCH(B1:B10,A1:A10,0)),
         MATCH(B1:B10,A1:A10,0)),ROW(B1:B10)-ROW(B1)+1),1))}

Note. Formulas with { and } around are array (CSE) formulas.
 
Upvote 0
There will not be any duplicates

In that case, the formulas, numbered [1] to [5]. all will do, number [4] being a tad faster than others.

The one in [5] meets your expectation ('no duplicates') and avoids counting "unexpected duplicates."
 
Last edited:
Upvote 0

Forum statistics

Threads
1,215,309
Messages
6,124,180
Members
449,146
Latest member
el_gazar

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