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 |
---|
1 | 15000-1 15000-2 |
---|
2 | 15000-1 15000-2 |
---|
3 | |
---|
|
---|
After the macro:
Excel 2007 |
---|
|
---|
| A |
---|
1 | 15000-1,15000-2 |
---|
2 | 15000-1,15000-2 |
---|
3 | |
---|
|
---|
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.