Returning a cell from a range on a diff sheet

Arthur D.

New Member
Joined
Jul 15, 2008
Messages
10
I am trying to figure out how to return a value of a cell one column to the left of anywhere excel finds a reference cell in a given range. I thought the offset function would work, but it does not seem to accept a given range. Ex:
A B
1 1 a
2 2 b
3 3 c
4 4 d
Basically from a diff tab I want excel to return the value to the left of wherever it finds the value "c" in the range a1.c4.

I know this is prob very simple.

Thanks for your help!!!
 

Excel Facts

Return population for a City
If you have a list of cities in A2:A100, use Data, Geography. Then =A2.Population and copy down.
Welcome to the board. Index/Match is best suited for this...

=INDEX('Sheet 1'!A:A,MATCH("c",'Sheet 1'!C:C,0))

Returns the value from Column A where "c" is in Column C.

Hope that helps..
 
Upvote 0
Thank you for your response. Can you explain the syntax of your formula? I was thinking something more along the lines of =offset(a13, sheet2!$a$1.$z$26, 0, -1, 1, 1)

Obviously that doesnt work or else I wouldnt have posted to this site. Essentially I want it to find a cusip (which is an identifier for a commodity instrument) in a specified range and return the value to the left of it. Vlookup doesnt work as the data is not to the left of the lookup. Also, the location may be different day to day.

Lastly I was wondering, instead of saying return the value one column to the left, is it possible to name columns and rows and just instruct excel to locate a reference cell in a range and retrieve the "price" of it regardless of where it is relative to that cell? Can excel identify the column "price" and then cross reference the value specified in the fomula with its respective value in the "price" column?

Thanks again!!!!
 
Upvote 0
=INDEX('Sheet 1'!A:A,MATCH("c",'Sheet 1'!C:C,0))

the Match part looks up "c" in Colum C of sheet 1. And returns the position# it was found in. So say "c" is in C43, the match returns 43...
so now it's

=INDEX('Sheet 1'!A:A,43)

that returns the value in the 43rd row of column A.
 
Upvote 0
Yes, you can have headers to determine which column it returns..

Here is just a Basic Example, Using Cars and Colors. You should get the idea

G5 formula is
=INDEX(A2:D5,MATCH(G3,E2:E5,0),MATCH(G2,A1:D1,0))

Hope that helps..
Personal.xls
ABCDEFG
1RedBlueYellowGreen
2$24,584.00$20,497.00$10,817.00$15,897.00ChevyBlue
3$22,025.00$16,139.00$12,363.00$21,954.00FordFord
4$14,084.00$15,291.00$15,236.00$13,787.00Toyota
5$15,073.00$23,148.00$11,247.00$10,921.00Honda$16,139.00
Sheet2
 
Upvote 0

Forum statistics

Threads
1,214,649
Messages
6,120,730
Members
448,987
Latest member
marion_davis

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