+ Reply to Thread
Results 1 to 7 of 7

hyperlink function and macro

Hybrid View

  1. #1
    Registered User
    Join Date
    09-05-2010
    Location
    Chicago
    MS-Off Ver
    Excel 2003
    Posts
    3

    hyperlink function and macro

    Hi,

    I am new here so I apologize in advance if I am not posting or explaining this properly. I have scoured the web and cannot find the answer so hopefully someone here can help...

    I am using the =hyperlink function as follows...

    =HYPERLINK("http://"&A3&I19,"Click Here")
    Now the "Click Here" shows up fine and the link works when I click it manually...

    But I tried to get a macro to automatically click it....

    Sub test()
     For Each Cell In Selection
        ' Check that the cell contains a hyperlink
          If Cell.Hyperlinks.Count > 0 Then
             Cell.Hyperlinks(1).Follow (True)
          End If
      Next Cell
    End Sub
    And the code only works if it is an actual typed in hyperlink and not the hyperlink function using the formula...

    Hope I explained that right... any thoughts? Questions?

    Thanks,

    Henry

  2. #2
    Forum Moderator Leith Ross's Avatar
    Join Date
    01-15-2005
    Location
    San Francisco, Ca
    MS-Off Ver
    2000, 2003, & 2010
    Posts
    23,259

    Re: hyperlink function and macro

    Hello Henry,

    Welcome to the Forum!

    As you have discovered, not all Hyperlinks are created equal. They both produce the same results, but internally they differ in how those results are accomplished. The Hyperlink protocol only describes the Hyperlink's behaviour, not how it has to accomplish it. So, Excel does it one way and VBA does it another way, and browsers do it still in another fashion, but the end results are the same. They just don't play well with others.
    Sincerely,
    Leith Ross

    Remember To Do the Following....

    1. Use code tags. Place [CODE] before the first line of code and [/CODE] after the last line of code.
    2. Thank those who have helped you by clicking the Star below the post.
    3. Please mark your post [SOLVED] if it has been answered satisfactorily.


    Old Scottish Proverb...
    Luathaid gu deanamh maille! (Rushing causes delays!)

  3. #3
    Registered User
    Join Date
    09-05-2010
    Location
    Chicago
    MS-Off Ver
    Excel 2003
    Posts
    3

    Re: hyperlink function and macro

    Thank you for the welcome...

    So I guess my question is...

    Is there a way to make them place nice together? I would like to use the macro to open multiple hyperlinks... the problem is the macro doesn't recognize excels formula syntax as an actual hyperlink?

    Is that fair to say?

    So can I run a script in the macro or change the hyperlink to a syntax that VBA recognizes?

    Thanks,

    Henry

  4. #4
    Forum Guru DonkeyOte's Avatar
    Join Date
    10-22-2008
    Location
    Northumberland, UK
    MS-Off Ver
    O365
    Posts
    21,531

    Re: hyperlink function and macro

    You could iterate the formulae within the selection and test for HYPERLINK in that manner
    (splitting the formula to extract the reference, building the hyperlink & following [then removing])

    How viable that will be will largely depend on the consistency of the formulae themselves (eg embedded functions etc)

    A very basic example assuming non-embedded function calls, valid (& basic) links etc...
    (ie =HYPERLINK() rather than =IF(...,IF(...,HYPERLINK(...),""),"")

    Sub Example()
        Dim rngF As Range, rngC As Range, strLink As String, hl As Hyperlink
        On Error Resume Next
        Set rngF = Selection.SpecialCells(xlCellTypeFormulas).Cells
        On Error GoTo 0
        If Not rngF Is Nothing Then
            For Each rngC In rngF.Cells
                With rngC
                    If InStr(1, .Formula, "HYPERLINK(", vbTextCompare) > 0 Then
                        strLink = Split(.Formula, Chr(34))(1)
                        With rngC
                            .Hyperlinks.Add .Cells(1), strLink
                            .Hyperlinks(1).Follow True
                            .Hyperlinks(1).Delete
                            .Formula = .Formula
                        End With
                    End If
                End With
            Next rngC
        End If
        Set rngF = Nothing
    End Sub
    I've no doubt there's a better method...

  5. #5
    Registered User
    Join Date
    09-05-2010
    Location
    Chicago
    MS-Off Ver
    Excel 2003
    Posts
    3

    Re: hyperlink function and macro

    Thank you for the response DonkeyOte, but I just figured it out...

    Thank you to Leith Ross... your post helped me understand the issue and rethink my solution...

    Here is what I did... not sure if this would be considered "clean code" but it works for me...

    Dim hyperlinkstring As String
    
    
    For x = 1 To Selection.Rows.Count
       ActiveCell.Select
       hyperlinkstring = "http://" & ActiveCell.Value & Range("i19")
       ThisWorkbook.FollowHyperlink Address:=hyperlinkstring
       ActiveCell.Offset(1, 0).Select
    
    Next x
    Basically Leith Ross helped me realize that I needed VBA to see it as a valid hyperlink.

    Thoughts?

    Thanks,

    Henry

  6. #6
    Registered User
    Join Date
    09-05-2011
    Location
    Florida, United States
    MS-Off Ver
    Excel 2010
    Posts
    11

    Re: hyperlink function and macro

    How would this code need to be modified to reference a sheet within the workbook?

  7. #7
    Forum Guru DonkeyOte's Avatar
    Join Date
    10-22-2008
    Location
    Northumberland, UK
    MS-Off Ver
    O365
    Posts
    21,531

    Re: hyperlink function and macro

    If you need to Follow the hyperlink then genuine links is best approach.

    FWIW, I noticed that the code I provided would not have worked for your samples (concatenation) and the strLink line would need to be revised

    strLink = Evaluate(Split(Split(Left(.Formula, Len(.Formula) - 1), "=HYPERLINK(")(1), ",")(0))
    also as you have demonstrated there's no real need to add the links to the cells as I was doing

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Tags for this Thread

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1