VBA to create Hyperlink including cell value

adste89

New Member
Joined
Apr 4, 2012
Messages
4
Hi,
Is it possible to input text into a cell and then a hyperlink is automatically created using a pre-defined link. For example: the user enters 1234 into any cell in column A and then cell A1 is automatically a hyperlink to address.co.uk/1234 ?

So whatever cell has text entered into it, becomes a hyperlink with that text at the end of the web address.

Impossible?
 

Excel Facts

Lock one reference in a formula
Need 1 part of a formula to always point to the same range? use $ signs: $V$2:$Z$99 will always point to V2:Z99, even after copying
Not impossible, you don't even need VBA. For example:

AB
abcdhttp:\\address.co.uk\abcd

<tbody>
[TD="align: center"]1[/TD]

</tbody>
Sheet3

[TABLE="width: 85%"]
<tbody>[TR]
[TD]Worksheet Formulas[TABLE="width: 100%"]
<tbody>[TR]
[TH]Cell[/TH]
[TH="align: left"]Formula[/TH]
[/TR]
[TR]
[TH]B1[/TH]
[TD="align: left"]
Rich (BB code):
=IF(A1="","",HYPERLINK("http:\\address.co.uk\"&A1))
[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
</tbody>[/TABLE]



Put abcd in A1, and B1 becomes a hyperlink using address.co.uk and appending what's in A1.

If you want A1 to become the hyperlink, you would need a VBA event handler to generate the link.
 
Last edited:
Upvote 0
Hi Eric,

Thanks for the quick reply but unfortunately it does need to be in the same cell the text is entered into.

Any idea of the VBA required for this?
 
Upvote 0
Sure. Open a copy of your workbook, right click on the sheet tab on the bottom, select "View Code", and paste this into the window that opens:

Rich (BB code):
Private Sub Worksheet_Change(ByVal target As Range)

    If target.Cells.Count > 1 Then Exit Sub
    If Intersect(target, Range("A1:A10")) Is Nothing Then Exit Sub
    
    Application.EnableEvents = False
    target.Formula = "=HYPERLINK(""http:\\www.address.co.uk\" & target.Value & """)"
    Application.EnableEvents = True
    
End Sub
The range in red is the range of cells that will turn into hyperlinks, change as required. The internet address is in blue.

Now press Alt-Q to close the VBA editor and try it out.
 
Upvote 0
Try this:

You may need to change the address just a little.

This is an auto sheet event script
Your Workbook must be Macro enabled
To install this code:
Right-click on the sheet tab
Select View Code from the pop-up context menu
Paste the code in the VBA edit window

Any time you enter any value into column "A" a Hyperlink to that cells value will be added to that cell.

Not sure about UK .com

So you should see how the script is written and modify it to your needs.
If not check back here for more help.

Code:
Private Sub Worksheet_Change(ByVal Target As Range)
If Not Intersect(Target, Range("A:A")) Is Nothing Then
ActiveSheet.Hyperlinks.Add Anchor:=Target, Address:="https://www." & Target.Value & ".com", TextToDisplay:=Target.Value
End If
End Sub
 
Upvote 0
Thanks Eric,

This works really well but one last question.

How would we:

1) Only display the text entered rather than the full hyperlink and;
2) Only create a hyper link if the text in the cell starts with "bug"?

Thank you.
 
Upvote 0
This should do it:

Code:
Private Sub Worksheet_Change(ByVal target As Range)

    If target.Cells.Count > 1 Then Exit Sub
    If Intersect(target, Range("A1:A10")) Is Nothing Then Exit Sub
    If LCase(Left(target.Value, 3)) <> "bug" Then Exit Sub
    
    Application.EnableEvents = False
    target.Formula = "=HYPERLINK(""http:\\www.address.co.uk\" & target.Value & """,""" & target.Value & """)"
    Application.EnableEvents = True
    
End Sub
 
Upvote 0
Hi. I know replying to a thread that is a couple of years old is not the best idea, but I am going to give it a try :)
I solved a similar issue I had using the macro above, thank you so much.
When I type in the value into the cell by hand or if I copy values into cells one at a time, it works fine. But when i try to copy multiple rows into the column at the same time, it does not work. None of the cells turn into hyperlinks. I would appreciate any help on how this could be solved
 
Upvote 0
Try this:

You may need to change the address just a little.

This is an auto sheet event script
Your Workbook must be Macro enabled
To install this code:
Right-click on the sheet tab
Select View Code from the pop-up context menu
Paste the code in the VBA edit window

Any time you enter any value into column "A" a Hyperlink to that cells value will be added to that cell.

Not sure about UK .com

So you should see how the script is written and modify it to your needs.
If not check back here for more help.

Code:
Private Sub Worksheet_Change(ByVal Target As Range)
If Not Intersect(Target, Range("A:A")) Is Nothing Then
ActiveSheet.Hyperlinks.Add Anchor:=Target, Address:="https://www." & Target.Value & ".com", TextToDisplay:=Target.Value
End If
End Sub
Can you edit the code for multiple ranges? For instance...
If Not Intersect(Target, Range("A2:A30", "C2:C30", "E2:E30", "G2:G30", "I2:I30", "K2:K30", "M2:M30", "O2:O30", "Q2:Q30")) Is Nothing Then
 
Upvote 0

Forum statistics

Threads
1,223,237
Messages
6,170,924
Members
452,366
Latest member
TePunaBloke

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