Hyperlink & Vlookup formula

kywenyi

New Member
Joined
May 11, 2019
Messages
13
hi, i have 1 workbook with 2 tabs - on Sheet 1 i need to hyperlink the column COLOR to Sheet 2 with vlookup function.

i've tried this but doesn't work. =HYPERLINK(VLOOKUP(B2,'SHEET 2'!A1:B3,2,0)

please help me with this. i will need to key in the formula in Sheet 1 B2, and when click on B2, it brings me to Sheet 2 A2, and in Sheet 1 B2, it will display as Sheet 2 A2 name.

Sheet1

[TABLE="class: grid, width: 400, align: left"]
<tbody>[TR]
[TD][/TD]
[TD]A[/TD]
[TD]B[/TD]
[/TR]
[TR]
[TD]1[/TD]
[TD]FRUIT[/TD]
[TD]COLOR[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]APPLE[/TD]
[TD]RED[/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]LEMON[/TD]
[TD]YELLOW[/TD]
[/TR]
</tbody>[/TABLE]







Sheet 2

[TABLE="class: grid, width: 400, align: left"]
<tbody>[TR]
[TD][/TD]
[TD]A
[/TD]
[TD]B
[/TD]
[/TR]
[TR]
[TD]1
[/TD]
[TD]COLOR[/TD]
[TD]DETAILS[/TD]
[/TR]
[TR]
[TD]2
[/TD]
[TD]RED[/TD]
[TD]SWEET[/TD]
[/TR]
[TR]
[TD]3
[/TD]
[TD]YELLOW[/TD]
[TD]SOUR[/TD]
[/TR]
</tbody>[/TABLE]
 

Excel Facts

Why does 9 mean SUM in SUBTOTAL?
It is because Sum is the 9th alphabetically in Average, Count, CountA, Max, Min, Product, StDev.S, StDev.P, Sum, VAR.S, VAR.P.
Since you are attempting to reference the same cell that you are wanting to place the formula in you will need to reference the actual text value you are searching for.

Place the following formula in cell B2 on Sheet 1
=HYPERLINK("#"&CELL("address",INDEX(Sheet2!$A1:$B3,MATCH("Red",Sheet2!$A:$A,0),0)),"Red")

If you want to use a cell reference you will need to place the formula in a cell other than the one you are referencing.
 
Upvote 0
i cannot do that. i have a full list of data and they are not in fixed row on sheet 2. previously my colleague use the normal hyperlink but i realise whenever i add a data in sheet 2, my hyperlink all wrong due to insert of row. thus, i need hyperink with vlookup. anything you can suggest?
 
Upvote 0
Can you place this formula in C2?

=HYPERLINK("#"&CELL("address",INDEX(Sheet2!$A1:$B3,MATCH($B2,Sheet2!$A:$A,0),0)),$B2)
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,177
Members
453,021
Latest member
Justyna P

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