Out of Memory

adavid

Board Regular
Joined
May 28, 2014
Messages
145
Below is my code for updating hyperlink addresses that were corrupted. I can update the hyperlinks in very small batches, but the sheet has almost 3000 rows. All of the hyperlinks are in column B. Any suggestions or code optimization would be very helpful.

Code:
Sub FixHLinks(sFind As String, sReplace As String, _
    Optional lStart As Long = 1, Optional lCount As Long = -1)
    Application.ScreenUpdating = False
    Application.Calculation = xlCalculationManual

    Dim rCell As Range
    Dim hl As Hyperlink

'THIS WAS FOR TESTING PURPOSES
    For Each rCell In ActiveSheet.Range("B461:B561")
'THIS IS IDEAL
    'For Each rCell In ActiveSheet.UsedRange.Cells
        If rCell.Hyperlinks.Count > 0 Then
            For Each hl In rCell.Hyperlinks
                hl.Address = Replace(hl.Address, sFind, sReplace, lStart, lCount, vbTextCompare)
            Next hl
        End If
    Next rCell
 Set rCell = Nothing
 Set hl = Nothing
 Application.ScreenUpdating = True
 Application.Calculation = xlCalculationAutomatic
End Sub

'THE ABOVE CODE IS CALLED FROM THE CODE BELOW
Sub FixThem()
 Application.ScreenUpdating = False
 Application.Calculation = xlCalculationManual
    FindReplaceHLinks "../AppData/Roaming/Microsoft/Excel/", "\\NetworkShare\Folder1\Folder2\Folder3\"
 Application.ScreenUpdating = True
 Application.Calculation = xlCalculationAutomatic
End Sub
 

Excel Facts

Links? Where??
If Excel says you have links but you can't find them, go to Formulas, Name Manager. Look for old links to dead workbooks & delete.
Also, if the code was run "on a new blank workbook" then there would not be a memory error because there would be nothing processing. Like I said in an earlier post, the code will run on limited ranges.

Hi, the purpose of the code in post#10 was to create a test scenario - I was suggesting that you run the code unedited on a new blank workbook to see if it ran quickly without causing the memory error.
 
Upvote 0
If the code in post#2 doesn't help with the out of memory issue then I'm sorry but I'm out of ideas - all I can say is that it works for me with a test workbook that comprises of 3000 hyperlinks.
 
Upvote 0
Do you think it has something to do with what I said in my reply to post#2?

When I hover the cursor over a cell the hyperlink is shown as "file:///C:\Users\e301713\AppData\Roaming\Microsoft\Excel\Folder of File\File Name.pdf"
When I right click to edit the hyperlink it is shown as "..\AppData\Roaming\Microsoft\Excel\Folder%20of%20File%20\File%20Name.pdf"
Other hyperlinks may have ""../AppData/Roaming/Microsoft/Excel/Folder%20of%20File%20/File%20Name.pdf"

I need the Folder of File and File Name.pdf to be maintained. I'm just trying to correct the rest of the path.
 
Upvote 0
Here is how I've re-modified your code from post#2. I still get the "Run-time error 7: Out of memory"
Code:
'''''Strings to Replace'''''
'../AppData/Roaming/Microsoft/Excel/
'C:\Users\username\AppData\Roaming\Microsoft\Excel\WAMS%20added%20to%20WAM%20Track

Sub FixHLinks(sFind As String, sReplace As String, _
    Optional lStart As Long = 1, Optional lCount As Long = -1)
    
    Dim hl As Hyperlink
    
    For Each hl In ActiveSheet.Hyperlinks
        hl.Address = Replace(hl.Address, sFind, sReplace)
    Next hl
 
End Sub

Sub PleaseWork()
Application.ScreenUpdating = False
Application.Calculation = xlCalculationManual

 sFind = "C:\Users\username\AppData\Roaming\Microsoft\Excel\WAMS%20added%20to%20WAM%20Track"
 sReplace = "\\marnv006\Bm\Master Scheduling\PC 2.2.11 Work Authorizing Memorandum (WAMs)\WAMS added to WAM Track"

    FixHLinks "sFind", "sReplace"

Application.ScreenUpdating = True
Application.Calculation = xlCalculationAutomatic
End Sub
 
Last edited:
Upvote 0
Finally figured out a method that worked...
Code:
Sub FixFilePaths() 'WORKING
    Dim hLink As Hyperlink
    Dim wSheet As Worksheet

    For Each wSheet In Worksheets
       For Each hLink In wSheet.Range("B3:B3000").Hyperlinks
       If InStr(1, hLink.Address, "../AppData/Roaming/Microsoft/Excel/", 1) Then
            hLink.Address = Replace(hLink.Address, "../AppData/Roaming/Microsoft/Excel/", "\\NetworkShare\NetworkFolder\NetworkFolder\NetworkFolder\")
       End If
        Next hLink
    Next
End Sub
 
Upvote 0

Forum statistics

Threads
1,215,170
Messages
6,123,422
Members
449,099
Latest member
COOT

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top