ExcelBanter

ExcelBanter (https://www.excelbanter.com/)
-   Excel Worksheet Functions (https://www.excelbanter.com/excel-worksheet-functions/)
-   -   vlookup on multiple values (https://www.excelbanter.com/excel-worksheet-functions/186509-vlookup-multiple-values.html)

Samuel

vlookup on multiple values
 
I have the following data in 3 columns

A B C
TOP BULB 1
TOP SCREW 5
TOP LIGHT 1
TOP LAMP 1
TOP PAPER 1
BOTTOM BULB 5
BOTTOM SCREW 4
BOTTOM LIGHT 2
BOTTOM LAMP 8
BOTTOM PAPER 7


I want to be able to first match against the value in column a then find the
match in column b once it finds both match then return the result of column
3.


ND Pard

vlookup on multiple values
 
Insert a new column A.

In the new column A concatenate the data from what is now column B and
column C. Example of a row two formula:

=B2&" "&C2

Now you can use a vLookUp function on Column A with an offset of 4 to return
data from what is now column D.

Good Luck.

"samuel" wrote:

I have the following data in 3 columns

A B C
TOP BULB 1
TOP SCREW 5
TOP LIGHT 1
TOP LAMP 1
TOP PAPER 1
BOTTOM BULB 5
BOTTOM SCREW 4
BOTTOM LIGHT 2
BOTTOM LAMP 8
BOTTOM PAPER 7


I want to be able to first match against the value in column a then find the
match in column b once it finds both match then return the result of column
3.


Bernard Liengme

vlookup on multiple values
 
1) If you can add a new A column:
In new A1 use =B1&C1
With BOTTOM in G1 and SCREW in H1, use =VLOOKUP(G1&H1,A1:D10,4,FALSE)

2) If you cannot insert, then add a new column (I will assume in D but
anywhere is OK)
In D1 use =A1&B1
With BOTTOM in G1 and SCREW in H1, use =INDEX(D1:D10,MATCH(G1&H1,A1:A10,0))

best wishes
--
Bernard V Liengme
Microsoft Excel MVP
http://people.stfx.ca/bliengme
remove caps from email

"samuel" wrote in message
...
I have the following data in 3 columns

A B C
TOP BULB 1
TOP SCREW 5
TOP LIGHT 1
TOP LAMP 1
TOP PAPER 1
BOTTOM BULB 5
BOTTOM SCREW 4
BOTTOM LIGHT 2
BOTTOM LAMP 8
BOTTOM PAPER 7


I want to be able to first match against the value in column a then find
the
match in column b once it finds both match then return the result of
column
3.




Teethless mama

vlookup on multiple values
 
=SUMPRODUCT(--(A1:A100="Top"),--(B1:B100="Bulb),C1:C100)


"samuel" wrote:

I have the following data in 3 columns

A B C
TOP BULB 1
TOP SCREW 5
TOP LIGHT 1
TOP LAMP 1
TOP PAPER 1
BOTTOM BULB 5
BOTTOM SCREW 4
BOTTOM LIGHT 2
BOTTOM LAMP 8
BOTTOM PAPER 7


I want to be able to first match against the value in column a then find the
match in column b once it finds both match then return the result of column
3.



All times are GMT +1. The time now is 10:05 PM.

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