Written by Allen Wyatt (last updated September 10, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 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, and Excel in Microsoft 365.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!
You can use the Zoom feature of Excel to magnify what Excel shows of your workbook, but it affects the entire screen. ...
Discover MoreNamed ranges are a great tool to use in developing formula-heavy workbooks. You may want, at some point, to copy your ...
Discover MoreEven if you do nothing but record macros, sooner or later you will have a need to edit what you record. Here's how to get ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2019-09-22 09:42:06
JMJ
Thanks very much to Allen and J. Wooley for this clever solution!
2019-09-14 10:23:12
J. Woolley
Allen's first macro can be simplified:
Sub ChangeNumberFormat()
With Application
.DecimalSeparator = "."
.ThousandsSeparator = ","
.UseSystemSeparators = (Not .UseSystemSeparators)
End With
End Sub
The first time it is run all numbers will change from French (or default) to American:
123 456 789,12 becomes 123,456,789.12
The next time it is run all numbers will change back to French (or default).
Each time it is run the 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 © 2024 Sharon Parq Associates, Inc.
Comments