Excel lookup using multiple cells

sobeitjedi

Board Regular
Joined
Mar 13, 2006
Messages
235
Office Version
  1. 365
Hi.

I have one sheet which contains rows of travel data for multiple users for the week or so ahead. Some of the columns in this sheet are "name" "destination" "from date" "to date"

I have another sheet with similar data in, but it's larger and goes back many months/years.

What I want, is a formula I can put in a cell in the first sheet, which will look up data in the second sheet which matches the conditions for the 4 cells. Let me try to provide an example ...

Sheet1 has
name Destination from date to date
John.Smith London 11/11/2018 15/11/2018
Jane.Sinclair London 11/11/2018 15/11/2018

Sheet2 has
name Destination from date to date
John.Smith Tokyo 05/07/2017 15/08/2017
John.Smith London 11/11/2018 15/11/2018
Clive.Williams London 01/02/2018 15/02/2018
Jane.Sinclair London 07/01/2018 14/01/2018

If the four cells in Sheet 1 can lookup a match in Sheet 2 where all the conditions apply, then put a "yes" in the cell, if not a "no". In this example it would be a yes for John.Smith, but a no for Jane.Sinclair.

Hope that makes sense and someone can help!
 
Last edited:

Excel Facts

Formula for Yesterday
Name Manager, New Name. Yesterday =TODAY()-1. OK. Then, use =YESTERDAY in any cell. Tomorrow could be =TODAY()+1.
One way

in Sheet1!E2
=IF(SUMPRODUCT((A2=Sheet2!A$2:A$1000)*(B2=Sheet2!B$2:B$1000)*(C2=Sheet2!C$2:C$1000)*(D2=Sheet2!D$2:D$1000))=1,"Yes","No")
and copy down the column
 
Last edited:
Upvote 0
try this


Book1
ABCDEFGHIJKL
1nameDestinationfromtonameDestinationfromto
2John.SmithLondon11/11/201815/11/2018John.SmithTokyo05/07/201715/08/2017no
3Jane.SinclairLondon11/11/201815/11/2018John.SmithLondon11/11/201815/11/2018yes
4Clive.WilliamsLondon01/02/201815/02/2018no
5Jane.SinclairLondon07/01/201814/01/2018no
Sheet1
Cell Formulas
RangeFormula
L2{=IF(ISNUMBER(MATCH(G2&H2&I2&J2,$A$2:$A$10&$B$2:$B$10&$C$2:$C$10&$D$2:$D$10,0)),"yes","no")}
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Upvote 0
How about
=IF(COUNTIFS(Sheet2!A:A,A2,Sheet2!B:B,B2,Sheet2!C:C,C2,Sheet2!D:D,D2)>0,"yes","no")
 
Upvote 0
Whoa - thanks for all your quick help - that was fast work! Amazing.

A tweak is needed, when the from date is looked up, it needs to return a "yes" if the date is an approximate match (maybe 7 days either side) - is that possible?
 
Upvote 0
How about
=IF(COUNTIFS(Sheet2!A:A,A2,Sheet2!B:B,B2,Sheet2!C:C,"<="&C2+7,Sheet2!C:C,">="&C2-7,Sheet2!D:D,D2)>0,"yes","no")
 
Upvote 0
Hi. Have been using this formula over the past few months since my original post, which has been working an absolute treat - however, I need a small tweak, if you can help?

=IF(COUNTIFS(TA!B:B,H26,TA!E:E,N26,TA!D:D,"<="&K26+3,TA!D:D,">="&K26-3)>0,"yes","no")

What I would like, is when N26 is compared to column E in table TA, the data must be in the cell (using FIND maybe?).

For example, at the moment, N26 = London, but if the matching row in TA!E:E has "Paris (and London)" then it doesn't match as true at the moment, but I need it to?

Hope that makes sense!
 
Upvote 0

Forum statistics

Threads
1,214,416
Messages
6,119,384
Members
448,889
Latest member
TS_711

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top