Paste All Cells Containing External Links As Values

fiberboysa

Board Regular
Joined
Apr 25, 2012
Messages
106
Office Version
  1. 365
Platform
  1. Windows
Hi All,
I have a workbook containing several external links. But the thing is I have roughted these external links through cells in the same workbook for example formula in a cell is appearing like
Excel Formula:
SUMIFS(INDIRECT("'"&$AA$2&"["&$AD$2&"]Aug 21"&"'!"&"$G:$G")
instead of
Excel Formula:
SUMIFS('D:\User Name\STA\JCW\2021 - 22\10 21\[Closing.xlsx]Aug 21!$G:$G")
.
Due to above change in SUMIF formula now excel do not perceive it as a external link and Data -> Queries & Connections ->External Links is disabled.
I share this file with my colleagues and I want to find a way to quickly paste all external link formulas as values so they do not get an error when they open these files.

Any suggestion?
 

Excel Facts

Why does 9 mean SUM in SUBTOTAL?
It is because Sum is the 9th alphabetically in Average, Count, CountA, Max, Min, Product, StDev.S, StDev.P, Sum, VAR.S, VAR.P.
If all you want to do is convert formulas to values, just make sure you have the Workbooks that are linked to the Workbook of focus (that contains the formula links) opened as well as the Workbook of focus. Then run the following code from the Workbook of focus (with the sheet with the formulas that you want to convert activated/selected) to convert all formulas in that specific sheet to values.
VBA Code:
Sub Test__ConvertFormulastoValues()
Call ConvertFormulastoValues(ThisWorkbook, ActiveSheet.name)
End Sub
Sub ConvertFormulastoValues(book As Workbook, sheetName As String)
'Source: https://www.goskills.com/Excel/Resources/VBA-code-library

Dim rng As Range
Dim scopeRange As Range
Set scopeRange = book.Sheets(sheetName).Cells.SpecialCells(xlCellTypeFormulas)
scopeRange = scopeRange.Value

End Sub
 
Upvote 0
If all you want to do is convert formulas to values, just make sure you have the Workbooks that are linked to the Workbook of focus (that contains the formula links) opened as well as the Workbook of focus. Then run the following code from the Workbook of focus (with the sheet with the formulas that you want to convert activated/selected) to convert all formulas in that specific sheet to values.
VBA Code:
Sub Test__ConvertFormulastoValues()
Call ConvertFormulastoValues(ThisWorkbook, ActiveSheet.name)
End Sub
Sub ConvertFormulastoValues(book As Workbook, sheetName As String)
'Source: https://www.goskills.com/Excel/Resources/VBA-code-library

Dim rng As Range
Dim scopeRange As Range
Set scopeRange = book.Sheets(sheetName).Cells.SpecialCells(xlCellTypeFormulas)
scopeRange = scopeRange.Value

End Sub
Thanks for your reply but this code is converting all formulas into values. I only want to convert external links.
Moreover, I am getting a #N/A in many cells as well.
 
Upvote 0
Oh, sorry. I somehow missed that detail even though I was aware of it when I first read your post. How about this? (This assumes that all external links have a "[", which they do. And I guess this puts a restriction that you can't use "[" in the concatenate part of a formula, but . . . )

VBA Code:
Sub Replace_Only_External_Link_Formulas_With_Values()

Dim sheetName As String
sheetName = ActiveSheet.name

Dim cellsWithFormulas As Range
Set cellsWithFormulas = Sheets(sheetName).Cells.SpecialCells(xlCellTypeFormulas)

Dim cell As Range
For Each cell In cellsWithFormulas
    If InStr(cell.Formula, "[") > 0 Then cell = cell.Value
Next cell

End Sub
 
Upvote 0
Solution
Oh, sorry. I somehow missed that detail even though I was aware of it when I first read your post. How about this? (This assumes that all external links have a "[", which they do. And I guess this puts a restriction that you can't use "[" in the concatenate part of a formula, but . . . )

VBA Code:
Sub Replace_Only_External_Link_Formulas_With_Values()

Dim sheetName As String
sheetName = ActiveSheet.name

Dim cellsWithFormulas As Range
Set cellsWithFormulas = Sheets(sheetName).Cells.SpecialCells(xlCellTypeFormulas)

Dim cell As Range
For Each cell In cellsWithFormulas
    If InStr(cell.Formula, "[") > 0 Then cell = cell.Value
Next cell

End Sub
Great. It worked. Thanks...
For all sheets in my workbook. I've modified the code as follows...
VBA Code:
Sub Replace_Only_External_Link_Formulas_With_Values()

Dim ws As Worksheet

Dim cellsWithFormulas As Range

Application.Calculation = xlManual

Dim cell As Range
For Each ws In ThisWorkbook.Worksheets
Set cellsWithFormulas = ws.Cells.SpecialCells(xlCellTypeFormulas)
For Each cell In cellsWithFormulas
    If InStr(cell.Formula, "[") > 0 Then cell = cell.Value
Next cell
Next ws

Application.Calculation = xlAutomatic

End Sub
 
Upvote 0

Forum statistics

Threads
1,214,606
Messages
6,120,485
Members
448,967
Latest member
visheshkotha

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