vlookup with 4 sets of criteria to match?

C

confused

Hi, I'm wondering if it's possible to do a vlookup with 4 different sets of
criteria?

I need to match
Column A = Qtr
Column C = SO
Column G = Eff Dt
Column H = End Dt

with another tab to pull in Column J = type of deal

is this easily done? Thank you!!!
 
D

Dave Peterson

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

Or if you want to include the "router-1" in the formula:

=sumproduct(--(othersheet!a1:a10=a1),
--(othersheet!b1:b10="router-1"),
(othersheet!c1:c10))

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

===========================

So in your example, you may want something like:

=index(othersheet!$j$1:$j$100,
match(1,(a2=othersheet!$a$1:$a$100)
*(b2=othersheet!$c$1:$c$100)
*(c2>=othersheet!$g$1:$g$100)
*(c2<=othersheet!$h$1:$h$100),0))

Where the current sheet has:
qtr in A2 (exact match)
so in B2 (exact match)
date in C2 (where C2 >= effective date and at the same time <= end date)

(remember, it's still an array formula.)
 
C

confused

thank you Dave. Here's what I tried but it's returning NA and it does have a
match

=INDEX(Bookings!J2:$J$829,MATCH(1,('Product
Bookings'!A2=Bookings!$A$2:A829)*('Product
Bookings'!C2=Bookings!C2:$C$829)*('Product
Bookings'!G2=Bookings!F2:$F$829)*('Product
Bookings'!H2=Bookings!G2:$G$829),0))

Any ideas
 
C

confused

my mistake I found that I didn't type ctl shift and forgot to put some dollar
signs in there
=INDEX(Bookings!J2:$J$829,MATCH(1,('Product
Bookings'!A2=Bookings!$A$2:$A$829)*('Product
Bookings'!C2>=Bookings!$C$2:$C$829)*('Product
Bookings'!G2=Bookings!$F$2:$F$829)*('Product
Bookings'!H2<=Bookings!$G$2:$G$829),0))

Thank you!!! :)
 
D

Dave Peterson

If you put the entries to match on the "product bookings" sheet and the formula
on that same "product bookings" sheet, you could drop the name of that sheet
from your formula.

=INDEX(Bookings!J2:$J$829,
MATCH(1,(A2=Bookings!$A$2:$A$829)
*(C2>=Bookings!$C$2:$C$829)
*(G2=Bookings!$F$2:$F$829)
*(H2<=Bookings!$G$2:$G$829),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