Change some of the formulae to value using VBA

Learning Excel

Board Regular
Joined
Jul 27, 2002
Messages
99
Hi,
I have a spreadsheet with some formulae and I would like to change some of them to values using VBA that contain indirect and vlookup formulae

Appreciate some helps on this as after going through the forum, cannot find help close to this.

Learning Excel
 

Excel Facts

VLOOKUP to Left?
Use =VLOOKUP(A2,CHOOSE({1,2},$Z$1:$Z$99,$Y$1:$Y$99),2,False) to lookup Y values to left of Z values.
Code:
Dim c As Range
For Each c in ActiveSheet.SpecialCells(xlCellTypeFormulas)
    If Instr(1,c.FormulaR1C1,"INDIRECT") > 0 Or Instr(1,c.FormulaR1C1,"VLOOKUP") > 0 Then
        c.FormulaR1C1 = c.Value
    End If
Next c
Denis
 
Upvote 0
Hi,
Thank you for the quick response.
There is a error msg Run-time error 438.Object does not support this property or method at line

For Each c In ActiveWorkbook.SpecialCells(xlCellTypeFormulas)

Did I miss something ?

Learning Excel
 
Upvote 0
There is a error msg Run-time error 438.Object does not support this property or method at line

For Each c In ActiveWorkbook.SpecialCells(xlCellTypeFormulas)

Did I miss something ?
Yep. You should have used ActiveSheet instead of ActiveWorkbook.

If you need to go to each sheet, you have to cycle through them. One way:
Code:
Dim Sht as Worksheet
Dim c as Range

For Each Sht In ActiveworkBook.Sheets
   Sht.Activate
   For Each c in ActiveSheet.SpecialCells(xlCellTypeFormulas)
      'do stuff here
   Next c
Next Sht
Denis
 
Upvote 0

Forum statistics

Threads
1,214,920
Messages
6,122,262
Members
449,075
Latest member
staticfluids

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