Limiting Input to Two Decimal Places

Written by Allen Wyatt (last updated March 16, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021


6

Ashley wonders how to limit the input of a number to 2 decimal places. In trying to figure it out, she notes that the Data Validation tool does not seem to work for this requirement.

There are two ways you can approach this problem. The first is to use a custom rule in Excel's Data Validation tool. Follow these steps:

  1. Select the cell where you want to limit the input to two decimal places. (For this example, let's assume you select cell A1.)
  2. Display the Data tab of the ribbon.
  3. Click the Data Validation tool. Excel displays the Data Validation dialog box.
  4. Make sure the Settings tab is displayed. (See Figure 1.)
  5. Figure 1. The Settings tab of the Data Validation dialog box.

  6. In Allow drop-down list, choose Custom.
  7. In the Formula box (which appears when you complete step 5), enter the following formula:
     =MOD(A1*100,1)=0
  • Click OK to close the dialog box.
  • This validation formula works because it checks to make sure that the value in A1, when multiplied by 100 and then divided by 1, has no remainder. It will only have this remainder if there are three or more decimal places in the value entered. Validation will also fail if someone tries to enter text into cell A1.

    There are, of course, any number of other formulas you could use in step 6. Here are a few:

    =INT(A1*100)=(A1*100)
    =A1=ROUND(A1,2)
    =ABS(A1-ROUND(A1,2))<1E-8
    =FIND(".",A1,1)>=LEN(A1)-2
    

    Instead of using Data Validation, there is another approach you could take. This one involves using the following steps:

    1. Select the cell where you want to limit the input to two decimal places. (For this example, let's assume you select cell A1.)
    2. Format the cell as desired, but make sure it is at least formatted to display only two decimal places.
    3. Display the Excel Options dialog box. (In Excel 2007 click the Office button and then click Excel Options. In Excel 2010 and later versions display the File tab of the ribbon and then click Options.)
    4. Click the Advanced option at the left of the dialog box.
    5. Scroll through the available options until you see the When Calculating This Workbook section. (See Figure 2.)
    6. Figure 2. The Advanced options of the Excel Options dialog box.

    7. Ensure that the Set Precision as Displayed check box is selected.
    8. Click OK.

    Now, when someone enters a value into the cell you formatted in step 2, it will be rounded to two decimal places automatically, and Excel will make sure that any calculations use the two-decimal-place value.

    The drawback to this approach is that changing how Excel does its calculations (steps 3 through 6) affects the entire workbook, not just the data-entry cell selected in step 1. If this is unacceptable to you, then you should definitely choose the Data Validation approach, discussed earlier.

    ExcelTips is your source for cost-effective Microsoft Excel training. This tip (889) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.

    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

    Adding Hyphens to Phrases

    Editing text to turn regular words into hyphenated phrases can be a real bother. The chore can become a breeze if you ...

    Discover More

    Entering Many Items In a Drop-Down Form Field

    One of the controls you can add to a Word form is a drop-down form field. This field is similar to drop-down lists used ...

    Discover More

    Expanding PivotTable Rows to Sheets

    PivotTables are a great way to work with large quantities of data in an intelligent manner. Sometimes, however, you just ...

    Discover More

    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!

    More ExcelTips (ribbon)

    Making a Drop-Down List Indicator Visible

    Data validation allows you to create drop-down lists that aid data entry. If you want the indicator for the drop-down ...

    Discover More

    Answering Questions in Order

    It is not unusual to use Excel to gather the answers to users' questions. If you want your users to answer your questions ...

    Discover More

    Limiting Entry of Prior Dates

    Want to establish a "bottom limit" on what dates can be entered in a cell? This tip presents two different ways you can ...

    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}] (all 7 characters, in the sequence shown) 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 two more than 7?

    2024-03-22 12:47:36

    J. Woolley

    My Excel Toolbox now includes the Modulo function described in my most recent comment below.
    See https://sites.google.com/view/MyExcelToolbox/


    2024-03-21 18:04:48

    J. Woolley

    The following function might be more reliable than Excel's MOD function:

    Public Function Modulo(Number As Double, Divisor As Double) As Double
        Modulo = Number - Divisor * WorksheetFunction.Floor(Number / Divisor, 1)
        If Abs(Modulo) < 0.0000000001 Then Modulo = 0
    End Function

    It solves the floating-point residual problem by returning 0 if its absolute value is less than 1.E-10. And it doesn't have the problems mentioned by Tomek where MOD returns 1 or 10 when the result should be 0.
    For more on this subject, see the following:
    https://stackoverflow.com/a/17525046/10172433
    https://en.wikipedia.org/wiki/Modulo


    2024-03-19 00:56:03

    Tomek

    Of the four additional formulas from the tip the first three seem to work fine, but the last one
    =FIND(".",A1,1)>=LEN(A1)-2
    incorrectly identifies whole numbers as not satisfying the condition, even if the cell is formatted to show two decimals, or even when you enter a number like 4.00. The underlying value does not have a decimal point, so it cannot be found.


    2024-03-19 00:29:28

    Tomek

    @J. Woolley and @R. A. Williams:

    MOD(A1*1000,10) does not work either. For example if the cell A1 contains 8.05,
    =MOD(A1*1000,10) returns 9.09495E-13
    =MOD(A1*100,1) returns 1.13687E-13

    This is so, even if you enter =Mod(8.05*1000,10) instead of referring to a cell.

    Even worse MOD(8.11*1000, 10) returns 10 (!) Of course this is not 10 but a number that differs from 10 by a very small value and is rounded up, but because it is less than 10, it is treated as a reminder from division by 10.
    Similarly MOD(8.29*100,1) returns 1.

    You are right that this must be rounding error from floating-point arithmetic. The question is how to account for this.
    First I thought that formula =MOD(A1*100,10) < 1E-12 could work, but it would still be wrong for MOD(8.29*100,1) as it returns 1.
    Possibly a more complicated formula could be used, like =OR(MOD(A2*100,1)<0.000000000001,1-(MOD(A2*100,1)<0.000000000001)), and would do the trick. It did work in my limited testing.

    Note: I did make sure that the series of numbers I tested were actually up to two decimal digits, and did not have more digits hidden due to rounding. Such thing happened, when i tried to generate a series of numbers by a formula, or even by filing a range of cells using series option, even after I copied the cells and then pasted them as values. The explicit calculation, or calculation done by excel when filling a series simply accumulates the rounding errors. First, I fell into that trap and almost all my numbers caused the original formula to fail. In this case "What You See Is Not What You Get" WYSINWYG

    When I have more time I will check your VBA suggestion. I also did not check the remaining formulas from the tip.


    2024-03-18 15:00:12

    J. Woolley

    @R. A. Williams
    Thank you for identifying a problem with Excel's MOD function using the formula MOD(A1*100,1). I believe the problem results unavoidably from floating-point arithmetic. Curiously, MOD(A1*1000,10) seems to work as desired, but MOD(A1*10000,100) does not.
    Apparently Excel's MOD function returns the floating-point result of this:
        MOD(Number, Divisor) = Number - Divisor*INT(Number/Divisor)
    VBA's Mod operator appears to round its parameters with fixed-point result:
        Number Mod Divisor =
            Round(Number) - Round(Divisor)*Int(Round(Number)/Round(Divisor))
    Therefore, the following function does not produce the same result as MOD:

    Function ModVBA(Number, Divisor)
        ModVBA = Number Mod Divisor
    End Function

    Conclusion: Be careful when using either function.


    2024-03-16 16:41:17

    R. A. Williams

    I thoroughly enjoy your Tips! So I tried out the current Tip (at https://excelribbon.tips.net/T000889_Limiting_Input_to_Two_Decimal_Places.html) and accidentally discovered something somewhat disturbing! I set up the Data Validation with the custom formula you first suggested (= MOD( A1 * 100, 1 ) = 0) and found that certain inputs unexpectedly triggered the "invalid" response! Some examples --

    OK Invalid OK Invalid OK Invalid OK Invalid OK Invalid
    4.55 4.56 4.57 4.56 4.5 4.6 4.62 4.61 4.63 4.64

    OK Invalid OK Invalid OK Invalid OK Invalid OK Invalid
    4.66 4.65 4.68 4.69 4.76 4.77 4.80 4.81 4.84 4.85

    OK Invalid OK Invalid OK Invalid OK Invalid OK Invalid
    4.87 4.86 4.88 4.89 4.91 4.90 4.93 4.94 4.97 4.98

    A few other invalid values found: 5.02, 5.06, 5.1, 5.11 and 4.1, 4.11, 4.14, 4.15, 4.19, 4.4.

    Am I going crazy? Looked a bit outside of the ranges noted above; all looked good. And none of the other four formulae you suggested display this phenomenon. Checked a few negative values; they all follow the pattern for positive values.

    I don't have an easy way to validate these bizarre observations and can't think of what to blame them on. If you can try it out and confirm or deny, I would be very interested! (I hate it when shit like this happens!)

    Thanks,
    Bob Williams


    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.