LOOKUP but with 2 parameters ?

M

Maileen

Hi,

on sheet2, i have the following table
col1 col2 col3
A 1 10
A 2 11
B 1 20
B 2 25
C 1 30
C 2 32
....

on sheet1, i have the following table

col1 col2 col3
A 2
B 1
A 1
C 1

i would like in col3 the result of the search...something like
research on sheet 2 the couple sheet1:col1 and sheet1:col2
if found sheet1:col3 = result of research

this exist vis LOOKUP function, but it does not allow a research based on 2
parameter...
how can i do it ?

thanks a lot for help

Maileen
 
D

Dave Peterson

You can use this kind of syntax:

=index(othersheet!$c$1:$c$100,
match(1,(a2=othersheet!$a$1:$a$100)*(b2=othersheet!$b$1:$b$100),0))
(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't use the whole column.

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))

(still an array formula)
 

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