Revealing hyperlink url

P

Paul

I have a large number of worksheets where the urls have been entered as
hyperlinks. I need to export the entire contents of these sheets as flat
files to be used elsewhere. Right now my problem is that I can find no
way of exporting the underlying url.

When I try and export as .csv for instance I get for the columns of
interest "MyURL" showing as plain text rather the the target I need of
"http://MyUrl.com".

Does anyone know of a way I can either export in such a manner as to
reveal the url during the export or edit the sheets using a macro or
whatever so as to reveal the underlying urls. There are way to many of
these things to try and do by hand. Thanks if advance.

BTW Beer is on me for the first person who can help me out of this jamb!!!

Paul
 
D

Dave Peterson

You can use a UserDefined Function to extract that URL.

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)
 
P

Paul

Dave said:
You can use a UserDefined Function to extract that URL.

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
Thanks, works great I do have another question but perhaps I will put it
in a different thread

Paul
 

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