How to convert hyperlink in Excel to show hyperlinked address?

  • Thread starter Thread starter Bruce
  • Start date Start date
B

Bruce

I have an Excel spreadsheet with a list of hyperlinked email addresses. For
example the list displays "Email", but the hyperlinked data is
"mailto:[email protected]".
I need to "un-hyperlink" the information so that I have a list of the data
itself - i.e. so I have a list of the (e-mail address removed) addresses.

Using Excel 2003.

Thanks for any help you can provide!
 
IN EXCEL 2007 (maybe 2003 but not sure) / right click the cell and select
Remove Hyperlink.

If my comment has helped please hit Yes.

Thanks.
 
Maybe you could use a userdefined function to extract the hyperlink from the
cells that have them.

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:

Debra Dalgleish has some notes how to implement macros here:
http://www.contextures.com/xlvba01.html

David McRitchie has an intro to macros:
http://www.mvps.org/dmcritchie/excel/getstarted.htm

Ron de Bruin's intro to macros:
http://www.rondebruin.nl/code.htm

(General, Regular and Standard modules all describe the same thing.)

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)

==================
I'd convert the formulas to values (edit|copy, followed by edit|paste
special|values).

Then edit|replace
what: mailto:
with: (leave blank)
replace all

but you could use:

=MID(geturl(A1),8,255)
and keep the formulas.
(255 is a large enough number to get all the email address)
 
Dave - this post was brilliant. Very easy to follow and it seems to have worked perfectly! Now I can upload to Outlook with actual web addresses rather than "CLICK HERE" in the Website space! Thank you
Kirsty
 
At last someone who knows how to do something and gives an idiots guide to get a result - thank you : how much time have you saved me ??? you're a star
 
Back
Top