ExcelBanter

ExcelBanter (https://www.excelbanter.com/)
-   Excel Discussion (Misc queries) (https://www.excelbanter.com/excel-discussion-misc-queries/)
-   -   lookup 2 columns, return value from third (https://www.excelbanter.com/excel-discussion-misc-queries/192710-lookup-2-columns-return-value-third.html)

slezgus

lookup 2 columns, return value from third
 
I have two tables of pretty much the same format. Column A shows a name that
may or may not be repeated a few times, while column B shows one of four
values (say, 1, 2, 3, 4). I need a formula that will return the result of
the third column, if it matches Column A and Column B.

Dave Peterson

lookup 2 columns, return value from third
 
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))

slezgus wrote:

I have two tables of pretty much the same format. Column A shows a name that
may or may not be repeated a few times, while column B shows one of four
values (say, 1, 2, 3, 4). I need a formula that will return the result of
the third column, if it matches Column A and Column B.


--

Dave Peterson

Max

lookup 2 columns, return value from third
 
Something like this in say D1, array-entered*:
=INDEX(C2:C10,MATCH(1,(A2:A10="Name1")*(B2:B10=3), 0))
Press CTRL+SHIFT+ENTER to confirm the formula
--
Max
Singapore
http://savefile.com/projects/236895
xdemechanik
---
"slezgus" wrote:
I have two tables of pretty much the same format. Column A shows a name that
may or may not be repeated a few times, while column B shows one of four
values (say, 1, 2, 3, 4). I need a formula that will return the result of
the third column, if it matches Column A and Column B.


vba_n00b_CA

Quote:

Originally Posted by Max (Post 685747)
Something like this in say D1, array-entered*:
=INDEX(C2:C10,MATCH(1,(A2:A10="Name1")*(B2:B10=3), 0))
Press CTRL+SHIFT+ENTER to confirm the formula
--
Max
Singapore
http://savefile.com/projects/236895
xdemechanik
---
"slezgus" wrote:
I have two tables of pretty much the same format. Column A shows a name that
may or may not be repeated a few times, while column B shows one of four
values (say, 1, 2, 3, 4). I need a formula that will return the result of
the third column, if it matches Column A and Column B.



Hi the
Thank you.. this formula works great!

I was wondering how, if at all, I can use the IFNA with the Index+Match formula above.
I tried using it this way but I ended up with a #NA

Quote:

=IFNA(INDEX(ActualHours!C$1:C$200,MATCH(1,($A3=Act ualHours!$A$1:$A$200)*($B3=ActualHours!$B$1:$B$200 ),0)),"")
(ended it with a ctrl +shift + enter)

Thanks for your help...


All times are GMT +1. The time now is 07:28 PM.

Powered by vBulletin® Copyright ©2000 - 2025, Jelsoft Enterprises Ltd.
ExcelBanter.com