Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, 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.
Written by Allen Wyatt (last updated August 31, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
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:
Figure 1. The Advanced options of the Excel Option dialog box.
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)
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (8886) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 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.
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!
Excel allows you to adjust spacing between cell walls and the contents of those cells. It does not, however, allow you to ...
Discover MoreWhen you format your data as a table, Excel allows you to apply a style to that table. You can even create your own table ...
Discover MoreWhen you use the sorting tool, Excel tries to automatically figure out if your data includes a header row or not. Here ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2023-09-02 10:28:29
J. Woolley
After further consideration of my last comment below, with or without Application.Volatile FmtText(A1) will not update if A1 is simply reformatted; in this case, however, FmtText(A1) will update the next time any cell on the worksheet is recalculated if and only if Application.Volatile is included.
2023-09-01 15:33:43
J. Woolley
@Mike J
You are correct. Application.Volatile is unnecessary because the UDF will automatically recalculate whenever its argument changes. It should be noted that the argument must refer to a range of one or more cells like A1 or A1:D4 but only the first cell (A1) applies. If the argument is a formula like A1+B1, the result is a #VALUE! error. However, a formula that returns a range like OFFSET(B1,0,-1) is okay.
2023-08-31 05:34:27
Mike J
Why does the UDF require Application.Volatile? It seems an unnecessary overhead.
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