Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, 2021, 2024, 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: Matching Formatting when Concatenating.

Matching Formatting when Concatenating

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


1

When using a formula to merge the contents of multiple cells into one cell, Kris is having trouble getting Excel to preserve the formatting of the original cells. For example, assume that cells A1 and B1 contain 1 and 0.33, respectively. In cell C1, he enters the following formula:

=A1 & " : " & B1

The result in cell C1 looks like this:

1:0.3333333333

The reason that the resulting C1 doesn't match what is shown in B1 (0.33) is because the value in B1 isn't really 0.33. Internally, Excel maintains values to 15 digits, so that if cell B1 contains a formula such as =1/3, internally this is maintained as 0.33333333333333. What you see in cell B1, however, depends on how the cell is formatted. In this case, the formatting probably is set to display only two digits beyond the decimal point.

There are several ways you can get the desired results in cell C1, however. One method is to simply modify your formula a bit so that the values pulled from cells A1 and B1 are formatted. For instance, the following example uses the TEXT function to do the formatting:

=TEXT(A1,"0") & " : " & TEXT(B1,"0.00")

In this case, A1 is formatted to display only whole numbers and B1 is formatted to display only two decimal places. You could also use the ROUND function to achieve a similar result:

=ROUND(A1,0) & " : " & ROUND(B1,2)

Another possible solution is to change how Excel deals with precision in the workbook. Follow these steps:

  1. Display the Excel Options dialog box. (In Excel 2007 click the Office button and then click Excel Options. In Excel 2010 or a later version, display the File tab of the ribbon and then click Options.)
  2. Click the Advanced option at the left of the dialog box.
  3. Scroll through the available options until you see the When Calculating This Workbook section. (See Figure 1.)
  4. Figure 1. The Advanced options of the Excel Option dialog box.

  5. Ensure that the Set Precision As Displayed check box is selected.
  6. Click OK.

Now, Excel uses the precision shown on the screen in all of its calculations and concatenations instead of doing calculations at the full 15-digit precision it normally maintains. While this approach may be acceptable for some users, for others it will present more problems than it solves. You will need to determine if you can live with the lower precision in order to get the output formatted the way you expect.

Still another approach is to create your own user-defined function that will return what is displayed for the target cell, rather than what is stored there. The following macro will work great in this regard:

Function FmtText(rng As Range)
    Application.Volatile
    FmtText = rng.Cells(1).Text
End Function

To use this macro, you would use a formula like this in your worksheet:

=FmtText(A1) & " : " & FmtText(B1)

Notice that the function is designated as volatile. This designation means that the macro will run any time that a recalculation is done. This is not strictly necessary, but it is helpful in certain situations. Consider that someone could change the formatting of cell A1. This would not trigger a recalculation, so FmtText will not return an updated text string. However, the next time the recalc is triggered, it will return the re-formatted contents of the cells.

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (8886) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, 2024, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Matching Formatting when Concatenating.

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

Replacing with a Subscript

The Find and Replace capabilities of Word are quite powerful. One type of replacing may not seem possible at ...

Discover More

Searching for Character Formatting

Need to look for a piece of text possessing a particular formatting attribute? Here's the skinny on how this is accomplished.

Discover More

Copying Headers and Footers

Need to copy headers and footers from one worksheet to another? How about from one workbook to another? Here are some ...

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 Data Analysis and Business Modeling today!

More ExcelTips (ribbon)

Problems with Custom Views

If you get an error when you try to use one of your custom views, it could be due to the protection you have applied to ...

Discover More

Mimicking Small Caps in Excel

Word provides a much wider range of formatting tools and options than you can find in Excel. One example is when it comes ...

Discover More

Unwanted Strikethrough Formatting

Enter something in a cell, and you may be surprised by how the information is displayed. If you are surprised, then the ...

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 one more than 2?

2025-11-22 06:05:06

jamies

And the primary thing to remember,
throughout any work in Excel (and other Apps)
is that -
Arithmetic processes, especially division usually end up with the "result" being held as floating point value,
and that is very likely to be held as a power of 2 - BINARY
so 0.5 is, as that is exactly 1/(2^1) is likely to be held accurately as a floating point value
but
0.2 is 1/ (2^3) + 1/(2^4) 0.125 + 0.06125 + ....

To see the actuality - format the display from cols A:E as 0.0
And then increase the decimal places shown in A:D to be at least 17
( more than that will get Excel to be showing the equivalent of using scientific notation -
so much more accuracy as the numbers get smaller than Excel will use - it only holding 16 significant digits -
but if you put in a very small value, then the extra digits may become significant
so maybe more than 17 after the decimal point may be significant for that value you entered !)

Now formulas - in row 2
A2=A1-INT(A1)
B2 =1/(2^ROW(B1))
C2=IF($A$2-(B2+SUM(C$1:C1))>0,B2,0)
D2=SUM(C$1:C2)
E2=10^16*D2
Copy the row 2 down to at least row 50

And enter a numeric value ( or formula) into cell A1.

You will then be shown,
column B shows the decimal value of the binary value of successively smaller halved values of the integer "1"
column C shows the decimal value of the binary value of successively smaller halved values of the integer "1" relevant to the value in cell A2
column D shows the decimal value of the accumulated binary values of successively smaller halved values of the integer "1" relevant to the value in cell A2

With the caveat that - Excel ceases to adjust the accumulated value with amounts that are so small they would not effect the 16th significant digit in the current total e.g.
0.123456789012345000 =
0.000000000000000100
is still
0.123456789012345000

but
0.000000000000000900
0.123456789012346000

It was rounded UP ! not down !
and moving the decimal point placeholder the same number of places in each of those numbers gets the same effect !

column E is a visual clue of the significant digits of the decimal value that Excel may be using if the value in A1 is greater than the integer 1

and that's why I recommend not testing for equality to numeric values,
but checking if the difference between the tested value, and the target value is less than anything your calculation, and presentation needs would consider significant !

as in not =IF(CELL()=0,"Yes ","NO ") with the 0 being an implied 0.0000000000000000000000000000000000000000000 (lots more zeros if you want.)
but use =IF(ABS(CELL()-wantedvalue)<0.0000000000001),"Yes ","NO ")


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.