Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, and 2016. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Replacing Some Formulas with the Formula Results.

Replacing Some Formulas with the Formula Results

by Allen Wyatt
(last updated March 11, 2017)

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 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.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12158) applies to Microsoft Excel 2007, 2010, 2013, and 2016. You can find a version of this tip for the older menu interface of Excel here: Replacing Some Formulas with the Formula Results.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He  is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Working with Form Fields

You know you want to use form fields in your document (they are essential in creating forms, after all) but you need to ...

Discover More

Comments in Headers and Footers

Comments can be a necessity when developing documents in conjunction with other people. They can be used to help document ...

Discover More

Using the Same Range Name on Different Worksheets

Defined names can be a great boon when working in a worksheet. Usually names are available throughout an entire workbook, but ...

Discover More

Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!

More ExcelTips (ribbon)

Specifying Location for a Message Box

When writing macros, you may want to position a message box at a specific location on the screen. This can't be done in ...

Discover More

Running a Macro when a Workbook is Closed

One of the automatic macros you can set up in Excel is one that is triggered when a workbook is closed. This tip explains how ...

Discover More

Opening a Workbook and Suppressing Automatic Macros

Want to stop Excel from running any automatic macros that may be stored with a workbook? Here's how to do it.

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is 3 + 8?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.