Inserting Commas in a Value Excel Interprets as a Number

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


Robert has a worksheet that contains a column of area codes. Each cell within the column can contain multiple area codes separated by commas, such as "973,201,732,862." A cell can have anywhere from 1 to 10 area codes in this format. Robert wants to insert a space after each comma, but Excel won't let him because it interprets each cell as containing a large number. He wonders how he can insert the spaces he needs.

The easiest way to do this is to use a formula, such as this:

=SUBSTITUTE(TEXT(A1,"#,##0"), ",", ", ")

The formula converts the value in A1 into a text format that includes commas, and then uses the SUBSTITUTE function to replace all commas with a comma followed by a space.

Understand, though, that this will only work to a point. If Excel is actually converting the area codes into a large number, it won't convert anything over five area codes. So, the following will be treated as a number just fine by Excel and the above formula will work as expected:

973,201,732,862,307

Robert said, though, that a cell could have anywhere from 1 to 10 area codes. If I add the area code 512 to the above number, this is how it would be displayed in Excel:

973,201,732,862,307,000

This has to do with Excel's internal precision which is limited to 15 digits. Five sets of area codes is 15 digits, so they display correctly; six sets is 18 digits, which will not—everything after the fifteenth digit is converted to a 0.

Thus, if Robert is actually seeing a cell that contains 10 area codes, then that cell isn't being interpreted by Excel as a numeric value. Instead, Excel is treating the value as text to begin with, and you can use the following formula to add the spaces:

=SUBSTITUTE(A1, ",", ", ")

No text conversion was necessary, so the SUBSTITUTE function will work by itself just fine.

If you don't know whether the value in A1 will be numeric or text, then you could wrap both formulas into an IF function, in this manner:

=IF(ISTEXT(A1),SUBSTITUTE(A1, ",", ", "),SUBSTITUTE(TEXT(A1,"#,##0"), ",", ", "))

You could rearrange the order of evaluation and make this formula even shorter:

=SUBSTITUTE(IF(ISTEXT(A1),A1,TEXT(A1,"#,000")),",",", ")

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

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

Shortcut Key for Format Painter

The Format Painter is great for copying formatting from one cell to another. If you don't want to grab the mouse to use ...

Discover More

Remove Conditional Formatting but Retain the Effects

If you want to get rid of conditional formatting rules, but retain any formatting that was applied by those rules, then ...

Discover More

Creating an AutoText List

The AUTOTEXTLIST field is one of those esoteric fields that you may know nothing about. The cool thing it does is it ...

Discover More

Best-Selling VBA Tutorial for Beginners Take your Excel knowledge to the next level. With a little background in VBA programming, you can go well beyond basic spreadsheets and functions. Use macros to reduce errors, save time, and integrate with other Microsoft applications. Fully updated for the latest version of Office 365. Check out Microsoft 365 Excel VBA Programming For Dummies today!

More ExcelTips (ribbon)

Combinations for Members in Meetings

Got a large group of people listed in a worksheet and you want to make sure that each person has met with every other ...

Discover More

Separating Names into Individual Columns

If you have a list of names in a column, and you want to separate those names into individual cells, there are several ...

Discover More

Concatenating Values from a Variable Number of Cells

Excel makes it easy to concatenate (or combine) different values into a single cell. If you need to combine a different ...

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 four less than 5?

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.