Display data using hlookup, index-match and offset

N

Namit

Hi,
I have a data set as follows:
ABC Run 3
ABC Walk 2
ABC Sleep 5
XYZ Run 3
XYZ Walk 1
LMN Jog 10
LMN Sing 12
I am creating a formula wherein when the user selects an input from a
list with options from Col 1 and 2, the formula displays the
corresponding value of Col 3. Hence, when I choose ABC and Walk I get
2. I have tried to using index-match but am not able to display the
data properly. Also, I tried using the offset function. The way I did
it was by having to sort the col 1 first and then change the reference
everytime there is a new entry. But the problem with this logic is
that everytime I have a new entry like OPQ for eg. I'll have to add
another IF statement to identify it.
Also, I tried using row with hlookup which does not work in
identifying the row no.
=+ROW(HLOOKUP(A11,$A$1:$C$10,MATCH(B1,$B$1:$B$10,0),FALSE))
A11 and B11 has the input for col 1 and 2 resp.

Thanks,
Namit.
 
D

Dave Peterson

if the value in column 3 are always numeric and there is a unique entry for each
combination (or you want to sum the values in column 3), you could use:

=sumproduct(--(Othersheet!a1:a10=x1),
--(Othersheet!b1:b10=y1),
Othersheet!c1:c10)

Where Othersheet!A1:C10 contains the table
and
x1 and y1 of the current sheet contains the values to match.

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

If the value in the 3rd column can be text, then this won't work.

But this will:

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

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