Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Replacing Some Formulas with the Formula Results.
Written by Allen Wyatt (last updated May 26, 2018)
This tip applies to Excel 97, 2000, 2002, and 2003
Brian has a need to process a worksheet before it can be handed out to other people. What he needs is to eliminate most, but not all, of the formulas in the worksheet. He wants to step through all the cells in a selected range of cells and, if the cell contains a formula, check that formula. If the formula contains a reference (any reference) to a different worksheet in the current workbook, then the formula is ignored. If the formula does not contain such a reference, then the macro needs to replace the formula with the result of the formula.
This is a relatively straightforward task; all you need to do is have your macro step thorough the cells and (1) find out if the cell contains a formula. If it does, then check to see if the formula contains an exclamation point. Exclamation points are used in formula references, such as the following:
=Sheet2!A1
So, if the formula contains an exclamation point, you can ignore it. If it doesn't contain an exclamation point then you can replace it with its value.
Sub ConvertFormulas1() Dim c As Variant Dim frm As String On Error Resume Next For Each c In Selection If c.HasFormula Then frm = c.Formula If InStr(1, frm, "!") = 0 Then c.Value = c.Value End If End If Next c End Sub
There is one drawback to this approach: the exclamation point will appear in all formulas external to the current worksheet, including those that are in other workbooks. If you truly want to only replace formulas to other worksheets in the current workbook but ignore formulas that reference sheets on other workbooks, then you need to add some additional logic. The logic makes itself apparent when you look at how Excel references those other workbooks:
=[OtherWorksheet.xls]Sheet1'!$C$9
Note that the name of the other workbook is contained within brackets. Thus, after testing for the exclamation point (which informs you that the reference is to another worksheet, you need to check for the presence of a left bracket. If it is there, then the reference is not to a cell within the current workbook.
Sub ConvertFormulas2() Dim c As Variant Dim OtherSheet As Boolean Dim frm As String On Error Resume Next For Each c In Selection If c.HasFormula Then frm = c.Formula OtherSheet = False If InStr(1, frm, "!") Then OtherSheet = True If InStr(1, frm, "[") Then OtherSheet = False End If End If If Not OtherSheet Then c.Value = c.Value End If End If Next c End Sub
It should be pointed out that it would be relatively easy to modify the formula used in this macro so that it got rid of all external references while leaving the references to the current worksheet intact. In fact, all you need to do is get rid of the checking for the bracket and then get rid of the "Not" keyword in the structure that checks the OtherSheet variable.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (6959) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Replacing Some Formulas with the Formula Results.
Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!
An Excel workbook can contain quite a few different objects. Sometimes those objects can be hidden so that they are not ...
Discover MoreWhen you assign a macro to a shortcut key, you make it easy to run the macro without ever removing your hands from the ...
Discover MorePart of writing macros is to make sure they work as you expect. This involves a process known as debugging. Here's how ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments