Vlookup request - this time without the html markup! doh!

JohnDouglas

Board Regular
Joined
Jan 5, 2005
Messages
239
hi

i'm hoping you guys can help with this. i've realised that i need vlookup formulas for this.

what i need is that when in say sheet1 some types the city in a1 and the fruit in b1, in c1 the value of available pieces of fruit will be returned for that city. is it possible to do something like that?

i've pasted the data in below. how would i get excel to return the number of pears available in london?

thank you very much for you help. hopefully the data will show correctly in this post so that it can be cut and pasted should you need to.

thanks again

City ; status ; Pears ; Apples ; Bananas ; Oranges ;
London ; Available ; 10 ; 6 ; 4 ; 7 ;
0 ; Eaten ; 12 ; 2 ; 6 ; 2 ;
London Total ; ; 22 ; 8 ; 10 ; 9 ;
London Percentage Eaten ; ; 0.545454545 ; 0.25 ; 0.6 ; 0.222222222 ;
Tokyo ; Available ; 3 ; 6 ; 8 ; 9 ;
0 ; Eaten ; 2 ; 3 ; 4 ; 9 ;
Tokyo Total ; ; 5 ; 9 ; 12 ; 18 ;
Tokyo Percentage Eaten ; ; 0.4 ; 0.333333333 ; 0.333333333 ; 0.5 ;
New York ; Available ; 1 ; 1 ; 4 ; 6 ;
0 ; Eaten ; 6 ; 7 ; 4 ; 2 ;
New York Total ; ; 7 ; 8 ; 8 ; 8 ;
New York Percentage Eaten ; ; 0.857142857 ; 0.875 ; 0.5 ; 0.25 ;
 

Excel Facts

Select a hidden cell
Somehide hide payroll data in column G? Press F5. Type G1. Enter. Look in formula bar while you arrow down through G.
Try the following...

=INDEX(C2:F13,MATCH(A17,A2:A13,0),MATCH(B17,C1:F1,0))

If you want to be able to choose the 'status'...

=INDEX(C2:F13,MATCH(A17,A2:A13,0)+(C17="Eaten"),MATCH(B17,C1:F1,0))

...where A17 contains the city of interest, B17 contains the fruit of interest, and C17 the status of interest.

Hope this helps!
 
Upvote 0
Thanks very much. I'll give it a go first thing tomorrow when i get to work. will let you know how i fare.
 
Upvote 0
sadly doesn;t work

hi domenic

i had a go but the forumla you gave doesn't work. i just get #N/A.

do you have any other ideas?

thanks again
 
Upvote 0
I think your problem is that you have spaces before/after some/all of your row/column headings.

Search this board for the TRIMALL macro, and see if that corrects your problem -- it should.
 
Upvote 0
Thanks just_jon, i search and replaced all the spaces and the formula worked perfectly. i'll add spaces to my list of things that ruin formulas.

domenic - many thanks for your wonderful forumla!
 
Upvote 0
Thanks for your help, i got the following to work wonderully:

=INDEX(INDIRECT("'"&$A4&"'!$D$2:$AJ$101"),MATCH(CONCATENATE($B$1,B$3),INDIRECT("'"&$A4&"'!$A$2:$A$101"),0),MATCH($E$1,INDIRECT("'"&$A4&"'!$D$1:$AJ$1"),0))

where A4 is the name of the sheet to be referenced
 
Upvote 0

Forum statistics

Threads
1,215,054
Messages
6,122,893
Members
449,097
Latest member
dbomb1414

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