Vlookups using 2 Values

S

Suzanne

Hi
I am trying to use 2 separate cells of data to get a value in a
vlookup.

=VLOOKUP($D119119+$J119119,Lookup!$J$2:$L20,3,FALSE) - formula I am
using

Is the plus sign correct? When I use the + sign it is adding up and
giving me a number when d119119 is a date and j11919 is a number

Date Shift Letter
2/8 1 C
2/8 2 D
2/9 1 C
2/9 2 D
2/10 1 A
2/10 2 B
2/11 1 A
2/11 2 B
Using info from the date column and shift column to get the info from
the letter column. 1 and 2 are shifts for the day.
Thank You I hope someone knows how to
 
D

Dave Peterson

No. The symbol to use when you're concatening strings is the ampersand (&).

You could add a column to the left of your table (a new column A???) and use:

=text(a2,"yyyymmdd")&c2

And use that as the key into your table:
=vlookup(text(d1,"yyyymmdd")&j1,sheet2!a:d,3,false)

Or you could use this technique:

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

XLjedi

Assuming for a moment that Date and Shift reside in columns A and B
respectively...

The easiest/fastest way to solve that one is to just add a third criteria
column called "Concat" with the formula: =A1 & B1

Then you just base a single vlookup on the concat column in order to return
the appropriate letter.
 

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