Compare arrays

M

mavxob

Hello,
I need to compare a column with a set of columns and get the column number
that match the lookup column. Can somebody help? thanks!

lookup column:
1
2
3

A B C D E F
2 4 5 6 1 5
5 2 3 2 2 4
1 2 5 1 3 6

expected result is 5 (col E)
 
B

Bernie Deitrick

mavxob,

Assuming you will only have one match, with the 'lookup column' in J1:J3

=SUMPRODUCT((J1=A1:F1)*(J2=A2:F2)*(J3=A3:F3)*COLUMN(A1:F1))

HTH,
Bernie
MS Excel MVP
 
M

Max

Another play to try
Assuming source data in A1:F3, with "lookup col" in H1:H3
put in K1's formula bar, then array-enter the formula by pressing
CTRL+SHIFT+ENTER (instead of just pressing ENTER):
=MATCH(1,(A1:F1=H1)*(A2:F2=H2)*(A3:F3=H3),0)
 
M

mavxob

Excellent ! thanks for your propmt feedback

Bernie Deitrick said:
mavxob,

Assuming you will only have one match, with the 'lookup column' in J1:J3

=SUMPRODUCT((J1=A1:F1)*(J2=A2:F2)*(J3=A3:F3)*COLUMN(A1:F1))

HTH,
Bernie
MS Excel MVP
 
M

mavxob

Thanks, this works as expected !

Max said:
Another play to try
Assuming source data in A1:F3, with "lookup col" in H1:H3
put in K1's formula bar, then array-enter the formula by pressing
CTRL+SHIFT+ENTER (instead of just pressing ENTER):
=MATCH(1,(A1:F1=H1)*(A2:F2=H2)*(A3:F3=H3),0)
 

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