A Microsoft Office (Excel, Word) forum. OfficeFrustration

If this is your first visit, be sure to check out the FAQ by clicking the link above. You may have to register before you can post: click the register link above to proceed. To start viewing messages, select the forum that you want to visit from the selection below.

Go Back   Home » OfficeFrustration forum » Microsoft Excel » Worksheet Functions
Site Map Home Register Authors List Search Today's Posts Mark Forums Read  

VLOOKUP 2 text columns



 
 
Thread Tools Display Modes
  #1  
Old September 28th, 2005, 10:07 PM
Brent
external usenet poster
 
Posts: n/a
Default VLOOKUP 2 text columns

I am looking up data from one worksheet.

Colunmns A B C
1 smith Joe 85
2 smart John 90
3 smith John 100

so the formula from the other worksheet looks like this:
=VLOOKUP("Smith",A1:C3, 3, FALSE)
but it returns 85 what I want is john smith returning 100.
Can anyone help ?


  #2  
Old September 28th, 2005, 10:22 PM
Domenic
external usenet poster
 
Posts: n/a
Default

Try...

=INDEX(C1:C3,MATCH(1,(A1:A3="Smith")*(B1:B3="John" ),0))

....confirmed with CONTROL+SHIFT+ENTER, not just ENTER.

Hope this helps!

In article ,
"Brent" wrote:

I am looking up data from one worksheet.

Colunmns A B C
1 smith Joe 85
2 smart John 90
3 smith John 100

so the formula from the other worksheet looks like this:
=VLOOKUP("Smith",A1:C3, 3, FALSE)
but it returns 85 what I want is john smith returning 100.
Can anyone help ?

  #3  
Old September 29th, 2005, 03:43 AM
Aussie CPA
external usenet poster
 
Posts: n/a
Default

An option would be to insert a column to the left of A and insert the
following formula =concatenate(b1,a1) (FOR the first row). This will give you
a combination of "Johnsmith".
Then you only need to change your vlookup to read
=vlookup("Johnsmith",a1:d3,4,false) to get the right answer.


"Brent" wrote:

I am looking up data from one worksheet.

Colunmns A B C
1 smith Joe 85
2 smart John 90
3 smith John 100

so the formula from the other worksheet looks like this:
=VLOOKUP("Smith",A1:C3, 3, FALSE)
but it returns 85 what I want is john smith returning 100.
Can anyone help ?


  #4  
Old September 29th, 2005, 05:58 AM
Aussie CPA
external usenet poster
 
Posts: n/a
Default

Hi Domenic,
Out of curiosity I replicated your formula and the spreadsheet.
The formula gives a "#N/A". I thought this strange so I went into formula
editor mode. The actual answer listed for formula result was 100. Do you know
why this would occur.

Thanks,

Adam Wood
PS. I'm using XL 2003

"Domenic" wrote:

Try...

=INDEX(C1:C3,MATCH(1,(A1:A3="Smith")*(B1:B3="John" ),0))

....confirmed with CONTROL+SHIFT+ENTER, not just ENTER.

Hope this helps!

In article ,
"Brent" wrote:

I am looking up data from one worksheet.

Colunmns A B C
1 smith Joe 85
2 smart John 90
3 smith John 100

so the formula from the other worksheet looks like this:
=VLOOKUP("Smith",A1:C3, 3, FALSE)
but it returns 85 what I want is john smith returning 100.
Can anyone help ?


  #5  
Old September 29th, 2005, 06:25 AM
Aussie CPA
external usenet poster
 
Posts: n/a
Default

DOH! CTRL-SHIFT-ENTER!


"Aussie CPA" wrote:

Hi Domenic,
Out of curiosity I replicated your formula and the spreadsheet.
The formula gives a "#N/A". I thought this strange so I went into formula
editor mode. The actual answer listed for formula result was 100. Do you know
why this would occur.

Thanks,

Adam Wood
PS. I'm using XL 2003

"Domenic" wrote:

Try...

=INDEX(C1:C3,MATCH(1,(A1:A3="Smith")*(B1:B3="John" ),0))

....confirmed with CONTROL+SHIFT+ENTER, not just ENTER.

Hope this helps!

In article ,
"Brent" wrote:

I am looking up data from one worksheet.

Colunmns A B C
1 smith Joe 85
2 smart John 90
3 smith John 100

so the formula from the other worksheet looks like this:
=VLOOKUP("Smith",A1:C3, 3, FALSE)
but it returns 85 what I want is john smith returning 100.
Can anyone help ?


  #6  
Old September 30th, 2005, 03:05 AM
D Hilberg
external usenet poster
 
Posts: n/a
Default

If your data in column C is truly numeric, you can use this:

=sumproduct((A1:A3="smith")*(B1:B3="John")*C1:C3)

- David

 




Thread Tools
Display Modes

Posting Rules
You may not post new threads
You may not post replies
You may not post attachments
You may not edit your posts

vB code is On
Smilies are On
[IMG] code is Off
HTML code is Off
Forum Jump

Similar Threads
Thread Thread Starter Forum Replies Last Post
Formulas dealing with text data Bagia Worksheet Functions 6 June 20th, 2005 10:29 PM
Need Subforms? AccessRookie Using Forms 7 April 8th, 2005 09:30 AM
Combo Box & Text Box AccessRookie Using Forms 3 April 6th, 2005 11:33 PM
Concatenatd fields in a query for a searching form Marc Running & Setting Up Queries 8 October 19th, 2004 08:49 PM
Make Columns in a Text Box? Les Coover Visio 3 October 3rd, 2004 07:20 PM


All times are GMT +1. The time now is 04:38 PM.


Powered by vBulletin® Version 3.6.4
Copyright ©2000 - 2024, Jelsoft Enterprises Ltd.
Copyright ©2004-2024 OfficeFrustration.
The comments are property of their posters.