Written by Allen Wyatt (last updated November 1, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
In a worksheet, Carol has a cell formatted to "Accounting." If someone accidentally enters a date (mm/dd/yy) in that cell, Excel automatically changes the formatting of the cell to show the date correctly. However, if she tries to enter a dollar amount in that cell again, it will not go back to the "Accounting" format; the cell remains in the date format. This is fine if the user sees the error and corrects it, but many times this is happening in a template with "boilerplate" text and the template is protected with no access to formatting cells. Carol wonders if anyone has any ideas on why this happens and how to correct it.
If you want a quick way to prevent the formatting change in simple worksheets, follow these steps:
Figure 1. The Advanced options in the Excel Options dialog box.
This particular option causes Excel to evaluate (parse) entered information in the same way that Lotus 1-2-3 did. This means that dates are no longer parsed as dates, but as a formula. Thus, if someone enters 11-16-13 into a cell, then it is parsed as "eleven minus sixteen minus thirteen" and shown in the cell as -18. Because it was not parsed as a date, then the Accounting format is left associated with the cell, as desired.
There are drawbacks to this approach, though. Because Excel subsequently parses any entries according to Lotus rules, your users may conclude that your worksheet doesn't work properly since it doesn't follow the same rules that other Excel worksheets do. This is why I mentioned that this approach may be acceptable for simple worksheets; you'll need to make the determination if your worksheet qualifies.
If you don't want to change how parsing is done, the best approach may be to add some event handlers to your worksheet. For instance, you could include an event handler that looks at where data was entered and ensures that any changes to those cells retain the desired formatting.
Private Sub Worksheet_Change(ByVal Target As Range) Dim rngToCheck As Range Set rngToCheck = Range("E2") If Intersect(Target, rngToCheck) Then rngToCheck.NumberFormat = _ "_($* #,##0.00_);_($* (#,##0.00);_($* "" - ""??_);_(@_)" End If End Sub
In this example, the cell that you want to retain the Accounting format in is E2, as assigned to the rngToCheck variable. If you want to force the format on a different cell range, then just change the assignment line.
If you wanted a bit more flexibility, then you could use a different set of event handlers. For instance, the following examples use both the SelectionChange and Change events of the Worksheet object. They result in something that doesn't so much force a particular format, but it prevents the formatting of a cell from being changed from whatever it was before. Thus, this approach protects any formatting, not just enforcing an Accounting format.
Dim nFormat As String Private Sub Worksheet_Change(ByVal Target As Range) Dim rngToCheck As Range Set rngToCheck = Range("E2") If Intersect(Target, rngToCheck) Then rngToCheck.NumberFormat = nFormat End If End Sub
Private Sub Worksheet_SelectionChange(ByVal Target As Range) nFormat = Target.NumberFormat End Sub
The SelectionChange event handler fires first, setting the existing format into the nFormat variable. Then the Change event handler fires and sets the formatting back to the original.
Another approach you could try is to use data validation. This approach doesn't require any macros and is therefore suitable if your workbook will be used by people who may have macros disabled on their system. Follow these general steps:
Figure 2. The Data Validation dialog box.
The formula (step 5) checks the formatting of the cell and either allows or disallows entry based on that formatting. In the formula as cited, format C2 is the internal name for the Accounting format. You could easily change the codes in the formula to some other format, such as ",2", "C2", "C0", "C2-", or "C0-" depending on your preference. The easiest way to figure out what format you should use is to format a cell, as desired, before applying the data validation rule. (For instance, let's say you apply the formatting to cell L13.) You can then use this formula in a different cell to see what format Excel believes you've applied:
=CELL("format",L13)
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12729) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!
Need the contents of a cell to be shown in a direction different than normal? Excel makes it easy to have your content ...
Discover MoreWant to change the size of the font within a worksheet? Excel allows you to choose from a list of sizes, as well as ...
Discover MoreNeed to cram a bunch of text all on a single line in a cell? You can do it with one of the lesser-known settings in Excel.
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2023-08-04 12:46:12
Wayne
This does not correct the issue for me. When I enter a range (e.g. "10-15") in any cell, the result is "15-Oct". The format is not changed to Date but rather to Custom. The Advance Option edit described above has no effect. If I enter a range as indicated above. I must enter a leading single quote to force Excel to treat the entry as nothing more than general characters with no deeper meaning.
2022-01-07 06:04:43
John
Such an annoying problem, such a straightforward fix! Thanks!
2020-02-07 01:31:12
yudi
thanks its very helpful!
2019-03-23 19:30:45
John Mann
If I understand the tip correctly, the formula :"=CELL("format",L13)" is used to find out the "formating code" for a particular formula. Thus if you format cell L13 as Percentagbe, the execuate that formula, you will get back a code P2, If you set it to either Accounting or Currency you get back C2 (at least in Excel 2010). This is intended as a test to find out what code to enter in the data validation formula "=CELL("format",B2)="C2"" if you want to protect some fromat other than the acoounting format requested in the Help Wanted.
My testing seems to imply that it won't distinguish between Accounting format and Currency format, though I haven't tested the actual data validation process.
2019-03-23 11:55:04
Brian Primeau
How does Excel know what format "C2" consists of? That is, how do you tell Excel what the format is that you want to enforce in L13?
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