Multiple Lookup return 1 result

J

JHL

Hello,
I have the following scenario where I want to match the two columns in
Sheet1, with the columns Code and State in Sheet2, but list the Branch found
in Sheet2.

I would like the Branch to populate a column in Sheet1.

Thanks for your help.

Sheet1:
Ref State
0 CA
0 FL
0 MD
13 NV
144 TX


Sheet2:
Code Branch State
0 NJP33 NJ
13 NVP22 NV
144 TXP62 TX
 
D

Dave Peterson

Saved from a previous post:

If you want exact matches for just two columns (and return a value from a
third), you could use:

=index(othersheet!$c$1:$c$100,
match(1,(a2=othersheet!$a$1:$a$100)
*(b2=othersheet!$b$1:$b$100),0))

(all in one cell)

This is an array formula. Hit ctrl-shift-enter instead of enter. If you do it
correctly, excel will wrap curly brackets {} around your formula. (don't type
them yourself.)

Adjust the range to match--but you can only use the whole column in xl2007.

This returns the value in othersheet column C when column A and B (of
othersheet) match A2 and B2 of the sheet with the formula.

And you can add more conditions by just adding more stuff to that product
portion of the formula:

=index(othersheet!$d$1:$d$100,
match(1,(a2=othersheet!$a$1:$a$100)
*(b2=othersheet!$b$1:$b$100)
*(c2=othersheet!$c$1:$c$100),0))

============
If there is only one match and you're bringing back a number (or 0 if there is
no match for all the criteria), you can use:

=sumproduct(--(othersheet!a1:a10=a1),
--(othersheet!b1:b10=b1),
(othersheet!c1:c10))

Adjust the ranges to match--but you can't use whole columns (except in xl2007).

=sumproduct() likes to work with numbers. The -- stuff changes trues and falses
to 1's and 0's.

Bob Phillips explains =sumproduct() in much more detail here:
http://www.xldynamic.com/source/xld.SUMPRODUCT.html

And J.E. McGimpsey has some notes at:
http://mcgimpsey.com/excel/formulae/doubleneg.html
 
J

JHL

Thank you Dave!
When you say "you can't use whole columns (except in xl2007)", I don't
follow.

One additional question about the formula, it works fine, but it seems that
I can't use references like C:C. I'm using xl2000, but another person who
will use this is using xl2007. The tables are going to grow and it will be a
constant editing of the formula to accommodate the changes.
 
D

Dave Peterson

C:C is an entire column
C1:C10 is not
c2:C65536 is not

If you want to see results in xl2k, then you can't use the entire column. But
you can make that range as big as you'll ever need.

I like to double my estimate and add a few more.

If I think I need 1000 rows, I'll use 2500 in my formulas.
 

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