Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. 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: Highlighting Values in a Cell.
Written by Allen Wyatt (last updated December 4, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Trev has a table of sales forecasts by product that several users review and update. The forecasts are initially set with various formulas, but the users are allowed to override the formulas by entering a value into any cell that contains one of the formulas. If a user does this, it would be helpful for Trev to have Excel somehow highlight that cell.
There are a couple of approaches you can take. First, you could use conditional formatting to do the highlighting. Set the conditional formatting rule type to Format Only Cells that Contain, "Cell Value" "Not Equal To," and then enter the formula as the comparison. This will tell you when the value in the cell does not equal whatever the formula is, but a potential "gottcha" is if the person overrides the formula with the result of that formula. For instance, if the formula would have produced a result of "27" and the user types "27" into the cell.
Another possibility is to define a formula in a named constant and then use that named constant in a conditional format. Follow these steps:
Figure 1. The New Name dialog box.
=NOT(ISFORMULA(INDIRECT("rc",FALSE)))
Note that the ISFORMULA function (step 5) was introduced in Excel 2013. If you are using Excel 2007 or Excel 2010, then you should use the following formula in step 5, instead:
=NOT(GET.CELL(48,INDIRECT("rc",FALSE)))
With the formula set up, you can define some conditional formats and use this named formula in the format. Simply set the conditional formatting rule type to Use a Formula to Determine which Cells to Format and enter the following formula in the condition:
=CellHasNoFormula
The formula returns True or False, depending on whether there is a formula in the cell or not. If there is no formula, then True is returned and whatever format you specify is applied to the cell.
Another approach is to forgo the named constant approach and, instead, use a formula directly in your conditional formatting rule. Make sure you define the rul as Use a Formula to Determine which Cells to Format and enter the following formula in the condition if, for instance, you are conditionally formatting cell C1:
=NOT(ISFORMULA(C1))
The formula returns True if there is no formula in the cell, so the conditional format is applied.
If you are using Excel 2007 or Excel 2010, you can put together your own ISFORMULA function using a macro, like this:
Function IsFormula(Check_Cell As Range) As Boolean Application.Volatile IsFormula = Check_Cell.HasFormula End Function
You can then use your own IsFormula in the conditional formatting rule, as already discussed.
The only downside of using any of these formulas to determine if a formula is in the cell is that it cannot determine if the formula in the cell has been replaced with a different formula. This applies to both the macro approach and the defined formula approach.
A totally different approach is to rethink your worksheet a bit. You can separate cells for user input from those that use the formulas. The formula could use an IF function to see if the user entered something in the user input cell. If not, your formula would be used to determine a value; if so, then the user's input is used in preference to your formula. This approach allows you to keep the formulas you need, without them being overwritten by the user. This results in greater integrity of the formulas and the worksheet results.
defNote:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9270) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Highlighting Values in a Cell.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!
Need to get rid of the borders around a cell? The shortcut in this tip can make quick work of this formatting task.
Discover MoreProfessional typesetting has, in many ways, spoiled us. One way this is evident is in the preference we show for making ...
Discover MoreNeed to use some bizarre font size in your worksheet? Not a problem, provided it is a full or half point size.
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2021-12-06 10:36:15
RKeev
Just make it easy with Ctrl ~ to see formulas/constants
Or Highlight if cell does not contain an equal sign
2021-12-04 10:22:31
Roy
For the idea of changed formula detection, adding a clause to the formula that gets the formula text and compares it to a string that you create from the "correct" formula text would solve that.
So FORMULATEXT, or either GET.CELL (parameter 48, as used here, or... 6, I think, or near that) using our fine friend GET.CELL.
By the way, not precisely related, but either GET.CELL will return the cell contents, formula they may be, or not. FORMULATEXT will return an error if anything other than a formula is present. That difference can be of use. Not necessarily better use than, say, ISFORMULA, but of use.
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.
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