How to convert a hyperlink to its target full-text URL

G

Guest

I have a large excel sheet where one column contains hyperlinks. They are all of the form:
Map_This
and I'd like to substitute the underlying URL so that I can save this to a text file and put it in a database.

Anyone have an idea? What I don't want to do is to do them all manually by right-clicking, editing the link and
cutting and pasting the URL in the "display as". I tried making a macro, but I can't figure out how to make a macro
that works in all columns as opposed to just a single cell.

TIA.
 
A

Anne Troy

Perhaps you can try this?
http://www.vbaexpress.com/kb/getarticle.php?kb_id=227

*******************
~Anne Troy

www.OfficeArticles.com
www.MyExpertsOnline.com


I have a large excel sheet where one column contains hyperlinks. They are all of the form:
Map_This
and I'd like to substitute the underlying URL so that I can save this to a
text file and put it in a database.
Anyone have an idea? What I don't want to do is to do them all manually by
right-clicking, editing the link and
cutting and pasting the URL in the "display as". I tried making a macro,
but I can't figure out how to make a macro
 
D

Dave Peterson

Saved from a previous post:

One way to extract those URL's from a hyperlink created via Insert|Hyperlink
is with a userdefinedfunction.

Here's one that may help:

Option Explicit
Function GetURL(Rng As Range) As String
Application.Volatile

Set Rng = Rng(1)

If Rng.Hyperlinks.Count = 0 Then
GetURL = ""
Else
GetURL = Rng.Hyperlinks(1).Address
End If
End Function

So if you had a hyperlink in A1, you could put =getURL(a1) in that adjacent
cell.

Be aware that if you change the hyperlink, then this formula cell won't change
until your workbook calculates.

If you're new to macros, you may want to read David McRitchie's intro at:
http://www.mvps.org/dmcritchie/excel/getstarted.htm

Short course:

Open your workbook.
Hit alt-f11 to get to the VBE (where macros/UDF's live)
hit ctrl-R to view the project explorer
Find your workbook.
should look like: VBAProject (yourfilename.xls)

right click on the project name
Insert, then Module
You should see the code window pop up on the right hand side

Paste the code in there.

Now go back to excel.
Into a test cell and type:
=getURL(a1)
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top