Written by Allen Wyatt (last updated August 2, 2025)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, 2024, and Excel in Microsoft 365
Jean needs to replace commas with periods in a table of numbers. He works in France, using a French PC, but he needs to "translate" these numbers for a non-Excel American application. When he manually does a Find and Replace, everything works well. Of course, his numbers are converted to strings, but that's OK with Jean. When he tries to do the same Find and Replace operation in a macro, nothing happens; the commas seem to be ignored. Jean wonders how he can do this task in a macro rather than needing to do it manually each time.
It is relatively easy to temporarily modify what Excel uses as regional settings so that it can display information just as Jean wants. The following macro will toggle back and forth rather handily between the desired settings:
Sub ChangeNumberFormat() With Application .UseSystemSeparators = False If .DecimalSeparator = "." Then .DecimalSeparator = "," .ThousandsSeparator = "." Else .DecimalSeparator = "." .ThousandsSeparator = "," End If End With End Sub
That changes how the information is displayed, and then you could export the information to whatever non-Excel format desired (such as CSV). Once done, run the macro again and you should have your regional settings back to the way they were originally. The benefit to this approach is that you never really change what is in the cells, just how that information is displayed. This means that your numbers remain numbers, able to continue to be used as such.
If you need something more direct, then it is probably best not to use Find and Replace. Instead, use the macro to directly modify what is in each cell. Such an approach can run much faster than relying on Find and Replace, even in a macro. Here's a simple application of this concept:
Sub SwitchCommasPeriods() Dim c As Range Dim sTemp As String For Each c In Selection sTemp = c.Text sTemp = Replace(sTemp, ",", "|") sTemp = Replace(sTemp, ".", ",") sTemp = Replace(sTemp, "|", ".") c = sTemp Next c End Sub
Note a couple of things in the macro. First, it looks at the Text property for each cell. The reason is because the Text property returns the formatted value of the cell—in other words, what is displayed. (If you simply look at the Value property, you'll get the unformatted number, which is not what you want to use.)
The second thing to notice is that the Replace function is used to first replace all commas with a vertical bar, then all periods with commas, and finally all vertical bars with periods. This approach is necessary because you are essentially swapping periods and commas in the text.
To use the macro, simply select the cells you want to affect and then run it. Only those selected cells are processed. If a cell contains a formula, the macro replaces that formula with the processed result of the formula. This should be fine for Jean's purposes, however.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13675) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, 2024, 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 Data Analysis and Business Modeling today!
Using a macro to add worksheets to your workbook is easy. This tip provides two different methods you can use.
Discover MoreWhen developing a macro, it is often necessary to step through the various code lines so you can see what is happening on ...
Discover MoreWhen creating macros, you often have to know how to display individual worksheets. VBA provides several ways you can ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2025-08-10 10:19:20
J. Woolley
@JMJ.Conseil
Thanks for the report. It's so hard to determine how a macro or UDF will work for someone else.
2025-08-09 12:21:37
JMJ.Conseil
@J. Woolley
In fact, it doesn't really work, because Excel ruthlessly removes all commas from the result! Here are the results of the tests, with both macros:
SwitchCommasPeriods2
? c.value
22,324,648.999
? c.value
22324648999
SwitchCommasPeriods
?sTemp
22324648,999
c.Value=stemp
? c.Value
22324648999
2025-08-09 10:36:38
JMJ.Conseil
@J. Woolley
Thanks for these improvements in the macros. And yes, you're perfectly right: in France, periods are forbidden in numbers (to avoid too much confusion with american numbers). It's the space that must be used.
2025-08-08 15:03:11
J. Woolley
The Tip's second macro is intended to swap comma and period number separators, but it does not discriminate between numeric and alphabetic values that might be present among the selected cells (Selection). Here's an alternate version that does discriminate:
Sub SwitchCommasPeriods2()
Dim c As Range
For Each c In Selection
If IsNumeric(Replace(Replace(c.Value, ",", ""), ".", "")) Then
c.Value = Replace(Replace(Replace(c.Text, ",", "|"), ".", ","), "|", ".")
End If
Next c
End Sub
Notice IsNumeric(X) returns True if X is either a number or numeric text, but numeric text must be compatible with the system default number separators; if the default is American number separators, then IsNumeric("1,234,567.89") is True but IsNumeric("1.234.567,89") is False. Therefore, this version removes commas and periods before confirming a numeric value, which it will change from French to American or vice versa each time it is run.
It is important to note this quote from the Tip: "If a cell contains a formula, the macro replaces that formula with the processed result of the formula."
By the way, the Tip assumes France uses a period for the thousands separator, but I believe the use of a space character is generally preferred.
2025-08-05 10:31:01
J. Woolley
Here's an alternate version of the Tip's first macro:
Sub ChangeNumberFormat2()
With Application
.UseSystemSeparators = (Not .UseSystemSeparators)
If Not .UseSystemSeparators Then
'use American number separators
.DecimalSeparator = "."
.ThousandsSeparator = ","
End If
End With
End Sub
This version is independent of the system default number separators (French or whatever). Each time it is run the number separators will change from their system default to American or vice versa.
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 © 2025 Sharon Parq Associates, Inc.
Comments