Written by Allen Wyatt (last updated October 14, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Excel has an alert feature for possible errors in a cell. This alert shows as a green triangle in the top-left corner of a cell. This is helpful in some instances but a real bother in others. For example, Peter has a list of addresses in a worksheet. In one column he has the ZIP Codes formatted as text. Excel constantly tells him that all the cells in this column are numbers formatted as text, a fact that (in his case) is intentional. Peter wonders if there is a way to suppress that particular alert for just that column. He tried selecting the column and clicking "Ignore error," but that only works temporarily. If he edits a cell the alert returns, and if he closes and reopens the workbook the alert returns.
Excel allows you to adjust which errors it flags and which it ignores. You can do so by following these steps:
Figure 1. The Formulas settings in the Excel Options dialog box.
Now, Excel will not mark these types of potential errors as you are using the program. If you wanted to, you could handle this process by using a macro. This would allow you to turn this error checking off while using the worksheet, but back on if you go to another worksheet. You would do this by using the Worksheet_Activate and Worksheet_Deactivate event handlers, in this manner:
Private Sub Worksheet_Activate() Application.ErrorCheckingOptions.NumberAsText = False End Sub
Private Sub Worksheet_Deactivate() Application.ErrorCheckingOptions.NumberAsText = True End Sub
You can get to the code window where these event handlers are entered by right-clicking on the worksheet tab and choosing the Code option from the resulting Context menu.
Of course, Peter asked that the errors only be suppressed on the single column. This gets a bit trickier, but can still be done. Unfortunately, VBA only allows you to set the error checking options on a cell-by-cell basis, which means that it becomes unworkable to change the setting for the entire column. If you wanted to do it for a range of cells in a particular column, you could do it in this manner:
Private Sub Workbook_Open() Dim c As Range For Each c In Worksheets("Retail Figures").Range("A1:A100") c.Errors(xlNumberAsText).Ignore = True Next End Sub
Note that this is the Workbook_Open event handler, which is placed in the code window for the ThisWorkbook object. It runs when the workbook is opened, and it sets the error checking for the A1:A100 range on the Retail Figures worksheet. You'll obviously want to change the range to reference the cells you want to affect.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (5229) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.
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!
Want to easily see the location of named ranges in your worksheet? It's easy; all you need to do is use the familiar Zoom ...
Discover MoreMany Windows applications rely on information stored in the Registry. If that information cannot be accessed, the ...
Discover MoreOne of the many pieces of information that Excel keeps track of is your name. If you want to change your name for Excel's ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2023-10-18 15:31:22
J. Woolley
Re. formula error checking, the Tip says, "This is helpful in some instances but a real bother in others." In my humble opinion it is best to uncheck the option labeled "Enable background error checking" and avoid the bother.
My Excel Toolbox's ToggleFormulaErrorChecking macro (Ctrl+T F E) will toggle that option (Enable/Disable). The macro supports Undo (Ctrl+Z). Here is an abbreviated version:
Sub ToggleFormulaErrorChecking()
Const myName As String = "ToggleFormulaErrorChecking"
With Application.ErrorCheckingOptions
.BackgroundChecking = (Not .BackgroundChecking)
End With
Application.OnUndo myName, (ThisWorkbook.Name + "!" + myName)
End Sub
See https://sites.google.com/view/MyExcelToolbox
2023-10-17 12:04:36
J. Woolley
My Excel Toolbox includes the following array function to report the status of error checking options:
=ListErrorCheckingOptions()
Expect 2 columns and 13 rows. When using pre-2021 versions of Excel without support for dynamic arrays, review UseSpillArray.pdf.
See https://sites.google.com/view/MyExcelToolbox
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