Macro replace spaces with comma

joickle

New Member
Joined
Mar 2, 2015
Messages
15
I have about 2000 that I need to go through and replace the spaces with a single comma. Some of the data may have 5 spaces between them and some may have 20.

For example:
A1:
15000-1 15000-2 (5 spaces between the values)
A2:
15000-1 15002-2 (20 spaces between values)

and I want:

A1:
15001-1,15000-2

A2:
15000-1,15002-2

Can anyone help?
 

Excel Facts

Enter current date or time
Ctrl+: enters current time. Ctrl+; enters current date. Use Ctrl+: Ctrl+; Enter for current date & time.
Try this on a COPY of your book...

Code:
Sub test()
Dim c As Range, lr As Long
lr = Cells(Rows.Count, "A").End(xlUp).Row
For Each c In Range("A1:A" & lr)
    c.Value = Replace(Application.Trim(c), " ", ",")
Next c
End Sub
 
Upvote 0
joickle,

Here is another macro solution for you to consider that does not use looping, that is based on your raw data, and, results.

Sample raw data:


Excel 2007
A
115000-1 15000-2
215000-1 15000-2
3
Sheet1


After the macro:


Excel 2007
A
115000-1,15000-2
215000-1,15000-2
3
Sheet1


Please TEST this FIRST in a COPY of your workbook (always make a backup copy before trying new code, you never know what you might lose).

1. Copy the below code
2. Open your NEW workbook
3. Press the keys ALT + F11 to open the Visual Basic Editor
4. Press the keys ALT + I to activate the Insert menu
5. Press M to insert a Standard Module
6. Where the cursor is flashing, paste the code
7. Press the keys ALT + Q to exit the Editor, and return to Excel
8. To run the macro from Excel press ALT + F8 to display the Run Macro Dialog. Double Click the macro's name to Run it.

Code:
Sub ReplaceSpacesWithComma()
' hiker95, 05/27/2015, ME857588
With Range("A1:A" & Cells(Rows.Count, "A").End(xlUp).Row)
  .Value = Evaluate("IF(ISTEXT(" & .Address & "),TRIM(" & .Address & "),REPT(" & .Address & ",1))")
  .Value = Evaluate("IF(ROW(),SUBSTITUTE(" & .Address & ","" "","",""),"""")")
End With
End Sub

Before you use the macro with Excel 2007 or newer, save your workbook, Save As, a macro enabled workbook with the file extension .xlsm, and, answer the "do you want to enable macros" question as "yes" or "OK" (depending on the button label for your version of Excel) the next time you open your workbook.

Then run the ReplaceSpacesWithComma macro.
 
Upvote 0
Similar underlying concept to the one hiker95 used, just a little more compact...
Code:
Sub ReplaceMultipleAndSingleSpacesWithSingleComma()
  Dim Addr As String
  Addr = "A1:A" & Cells(Rows.Count, "A").End(xlUp).Row
  Range(Addr) = Evaluate(Replace("IF(LEN(@),SUBSTITUTE(TRIM(@),"" "","",""),"""")", "@", Addr))
End Sub
 
Upvote 0

Forum statistics

Threads
1,202,913
Messages
6,052,527
Members
444,588
Latest member
ViJN

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top