Matching numbers in two Columns

tikrit

New Member
Joined
Jun 16, 2012
Messages
12
Hello,

This is my second question here. You helped me with my first one, Thank you.

I have the following columns (O & S):

S O
-----
1 3
3 7
6 6
8 4
1 3
2 8
1 6

I want a code (Formula) do the follwoing: Matching number 1 in column S with number 3 in Column O and count how many matches found in the two columns, Which in this case only two.

Thanks in advance for all
 

Excel Facts

Can you sort left to right?
To sort left-to-right, use the Sort dialog box. Click Options. Choose "Sort left to right"
This formula should work...

=SUMPRODUCT((O1&S1=O1:O100&S1:S100)*(O1&S1<>""))

The bottom row of 100 for the table range was just a guess... the number you actually use in place of both 100's (the numbers must be the same) would be a row number equal to or greater than the maximum row number you ever expect to have data in.
 
Upvote 0
This formula should work...

=SUMPRODUCT((O1&S1=O1:O100&S1:S100)*(O1&S1<>""))

The bottom row of 100 for the table range was just a guess... the number you actually use in place of both 100's (the numbers must be the same) would be a row number equal to or greater than the maximum row number you ever expect to have data in.

@Rick
Thank you for your fast response.
Actually, I hav only seven rows. So, I will replace the 100 by 7. Ok.

But where is the maching condition between 1 and 3 ? I want the formula to count for every 1 in column S with 3 in Column O.
Which in my case must show 2. Because I only have two maches of this type.

Thanks
 
Upvote 0
Excel 2010
ABC
1132
237
366
484
513
628
716

<colgroup><col style="width: 25pxpx"><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Sheet1

Array Formulas
CellFormula
C1{=SUM(IF(FREQUENCY(IF(A1:A7=1,MATCH(B1:B7,B1:B7,0)),ROW(A1:A7)-ROW(A2)+1),1))}

<thead>
</thead><tbody>
</tbody>
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself

<tbody>
</tbody>
 
Upvote 0
Hi,
analogous to the Solution of RR try the table formula (You have to accept it using Ctrl+Shift+Enter):
Code:
=SUM(IF(A1:A7&B1:B7="13";1;0))
Best regards.
 
Last edited:
Upvote 0
Hello tikrit,

If you are on Excel 2007 or later, COUNTIFS is one option.

=COUNTIFS(S2:S100,1,O2:O100,3)

Or, this will work with all versions.

=SUMPRODUCT((S2:S100=1)*(O2:O100=3))
 
Upvote 0
@Rick
Thank you for your fast response.
Actually, I hav only seven rows. So, I will replace the 100 by 7. Ok.

But where is the maching condition between 1 and 3 ? I want the formula to count for every 1 in column S with 3 in Column O.
Which in my case must show 2. Because I only have two maches of this type.
Oh, you want it to always be 1 and 3. Also, it is usually a good idea to present column references in alphabetical order (your original table showed S-O which I thought might be a typo). Here is my formula set up to look for exactly 3 and 1 in Columns O and S...

=SUMPRODUCT(("31"=O1:O100&S1:S100)*(O1&S1<>""))
 
Upvote 0
Sorry I misread the request
Yet another two ways
Excel 2010
BCDOPQRS
12213
237
366
484
513
628
716

<colgroup><col style="width: 25pxpx"><col><col><col><col><col><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Sheet1

Worksheet Formulas
CellFormula
B1=SUMPRODUCT(--(O1:O7&S1:S7="13"))

<thead>
</thead><tbody>
</tbody>

<tbody>
</tbody>

Array Formulas
CellFormula
C1{=SUM(--(INDEX(O1:O7&S1:S7="13",)))}

<thead>
</thead><tbody>
</tbody>
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself

<tbody>
</tbody>
 
Upvote 0

Worksheet Formulas
Cell
Formula
B1
=SUMPRODUCT(--(O1:O7&S1:S7="13"))

<tbody>
</tbody>

<tbody>
</tbody>


Array Formulas
Cell
Formula
C1
{=SUM(--(INDEX(O1:O7&S1:S7="13",)))}

<tbody>
</tbody>
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself

<tbody>
</tbody>
You did what I did originally and misread the request because the OP listed the columns out of alphabetical order. Here is what the OP said...

" I want the formula to count for every 1 in column S with 3 in Column O."
 
Upvote 0
Thank you Rick.
In this case:
Excel 2010
BCDOPQRS
12231
273
366
448
531
682
761

<colgroup><col style="width: 25pxpx"><col><col><col><col><col><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Sheet1

Worksheet Formulas
CellFormula
B1=SUMPRODUCT(--(S1:S7&O1:O7="13"))

<thead>
</thead><tbody>
</tbody>

<tbody>
</tbody>

Array Formulas
CellFormula
C1{=SUM(--(INDEX(S1:S7&O1:O7="13",)))}

<thead>
</thead><tbody>
</tbody>
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself

<tbody>
</tbody>
 
Upvote 0

Forum statistics

Threads
1,213,546
Messages
6,114,256
Members
448,558
Latest member
aivin

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