Converting to Hyperlinks in a Shared Workbook

Eric has a shared workbook that contains a database of some 3,500 records. Two of the cells in each record contain an e-mail address and a URL. When a new record is added to the database, the e-mail address and URL appear as regular text instead of as hyperlinks. To make them into hyperlinks Eric must unshare the workbook, make the change, and then reshare the workbook. Eric wondered if there is, perhaps, an easier way to handle this situation.

Quite simply, adding and editing hyperlinks is not allowed when using a shared workbook. The simplest way around it is to put the links in separate cells as text and then use the HYPERLINK formula to reference those cells.

For example, if the URL is entered into cell E2, you could use the following formula in a different cell:

=HYPERLINK(E2, E2)

The first argument in this formula is to the cell that contains the address and the second argument is for the text to be displayed for the hyperlink. This approach requires two additional columns (for the HYPERLINK formulas) but will not require unsharing and resharing the workbook.

The only other option is to create a macro that can automate the process of unsharing and resharing the workbook. The following macro will do this and convert whatever is in the selected cell into a hyperlink.

Sub AddHyperlink()
    Dim cell As Range

    Application.DisplayAlerts = False

    ' Unshare the Workbook
    If ActiveWorkbook.MultiUserEditing Then
        ActiveWorkbook.ExclusiveAccess
    End If

    ' Change address in cell to a hyperlink.
    If ActiveCell = "" Then
        ActiveCell.Hyperlinks.Delete
    Else
        For Each cell In Intersect(Selection, _
          Selection.SpecialCells(xlConstants, xlTextValues))
            With Worksheets(1)
                .Hyperlinks.Add Anchor:=cell, _
                  Address:=cell.Value, _
                  ScreenTip:=cell.Value, _
                  TextToDisplay:=cell.Value
            End With
        Next cell
    End If

    ' Reshare the Workbook
    If Not ActiveWorkbook.MultiUserEditing Then
        ActiveWorkbook.SaveAs _
          Filename:=ActiveWorkbook.FullName, _
          AccessMode:=xlShared
    End If
End Sub