Matching Three columns and returning a value

R

Rob

I have a Spreadsheet with two sheets.
Sheet 1 has the following data in columns
Forname Surname Birth Place Nationality
Alan Jones Liverpool
Allan Jones Cardiff
David Ellis Manchester
David Ellis Leeds
Clive Newman London
Sarah Roberts Cardiff

Sheet 2 has the following
Surname Forename Birthplace Nationality Forename Birthplace
Natioanlity
Jones Alan Liverpool English Allan
Cardiff Welsh
Ellis David Manchester English David
Leeds English

etc

How can I insert in sheet 1 the nationality where all three varialble must
match
i.e. Alan Jones Liverpool = Jones Alan Liverpool and returns the text
English in Sheet 1
 
P

Pete_UK

You could insert a new column D in Sheet2 and fill it with this
formula:

=A2&B2&C2

and copy this down. Similarly, insert a new column H and put this
formula in H2:

=A2&F2&G2

and copy this down. Then in Sheet1 D2 you can put this formula:

=IF(ISNA(VLOOKUP(B2&A2&C2,Sheet2!D:E,
2,0)),IF(ISNA(VLOOKUP(B2&A2&C2,Sheet2!H:I,2,0)),"not
present",VLOOKUP(B2&A2&C2,Sheet2!H:I,2,0)),VLOOKUP(B2&A2&C2,Sheet2!D:E,
2,0))

Copy this down as required.

Hope this helps.

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