Adding a comma between single digits in a cell

lind33

New Member
Joined
Jun 25, 2019
Messages
14
Office Version
  1. 2016
Platform
  1. Windows
I am looking for a way to add a comma after every single digit in a cell.
I found some formulas on the web but since the number of digits is not equal in the cells, I can't get the result I need.

For example, in column A:
12345
12
135789
135
etc.

What formula can give me the result I need? can I get some help, please? thanks.
Expected results of the above example:
1,2,3,4,5
1,2
1,3,5,7,8,9
1,3,5
 

Excel Facts

Bring active cell back into view
Start at A1 and select to A9999 while writing a formula, you can't see A1 anymore. Press Ctrl+Backspace to bring active cell into view.
Try:

Code:
=MID(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(A1,0,",0"),1,",1"),2,",2"),3,",3"),4,",4"),5,",5"),6,",6"),7,",7"),8,",8"),9,",9"),2,999)
 
Upvote 0
Thanks, Eric. That was quick, and that's hell of a formula :)
 
Upvote 0
This macro will place the results in column B.
Code:
Sub lind33()
    Dim i As Long, rng As Range, RngList As Object
    LastRow = Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
    Set RngList = CreateObject("Scripting.Dictionary")
    For Each rng In Sheets("Sheet1").Range("A1:A" & LastRow)
        For i = 1 To Len(rng)
            RngList.Add Mid(rng, i, 1), Nothing
        Next i
        rng.Offset(0, 1) = Join(RngList.keys, ", ")
        RngList.RemoveAll
    Next rng
End Sub
 
Upvote 0
Yeah, it is quite a formula, isn't it?! :rolleyes:

If you have Excel 365 with the TEXTJOIN function, you can simplify it to:

=TEXTJOIN(",",1,MID(A1,ROW(INDIRECT("1:"&LEN(A1))),1))

confirmed with Control+Shift+Enter. But I didn't want to assume you had that. In any event, glad we could help! :)
 
Upvote 0
This macro will place the results in column B.
Code:
Sub lind33()
    Dim i As Long, rng As Range, RngList As Object
    LastRow = Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
    Set RngList = CreateObject("Scripting.Dictionary")
    For Each rng In Sheets("Sheet1").Range("A1:A" & LastRow)
        For i = 1 To Len(rng)
            RngList.Add Mid(rng, i, 1), Nothing
        Next i
        rng.Offset(0, 1) = Join(RngList.keys, ", ")
        RngList.RemoveAll
    Next rng
End Sub
Your macro can be written using only one loop...
Code:
Sub AddCommasBetweenDigits()
  Dim X As Long, LastRow As Long, Cell As Range
  LastRow = Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
  For Each Cell In Sheets("Sheet2").Range("A1:A" & LastRow)
    Cell.Offset(, 1) = Replace(StrConv(Cell.Value, vbUnicode), Chr(0), ",", , Len(Cell.Value) - 1)
  Next
End Sub

HOW TO INSTALL MACROs
------------------------------------
If you are new to macros, they are easy to install and use. To install it, simply press ALT+F11 to go into the VB editor and, once there, click Insert/Module on its menu bar, then copy/paste the above code into the code window that just opened up. That's it.... you are done. To use the macro, go back to the worksheet with your data on it and press ALT+F8, select the macro name (AddCommasBetweenDigits) from the list that appears and click the Run button. The macro will execute and perform the action(s) you asked for. If you will need to do this again in this same workbook, and if you are using XL2007 or above, make sure you save your file as an "Excel Macro-Enabled Workbook (*.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.
 
Last edited:
Upvote 0
Try whit UDF (User Definition Function)

Code:
Function AddComma(s As Range)
    Dim i As Long, cad As String
    For i = 1 To Len(s)
        cad = cad & Mid(s, i, 1) & ","
    Next
    AddComma = Left(cad, Len(cad) - 1)
End Function

Use like formula excel:

=AddComma(A1)
 
Upvote 0
Yeah, it is quite a formula, isn't it?! :rolleyes:

If you have Excel 365 with the TEXTJOIN function, you can simplify it to:

=TEXTJOIN(",",1,MID(A1,ROW(INDIRECT("1:"&LEN(A1))),1))

confirmed with Control+Shift+Enter. But I didn't want to assume you had that. In any event, glad we could help! :)
Actually Eric, this can be done with a "simple" normally-entered formula in any version of Excel (that I am familiar with)...

=MID(TEXT(A1,REPT("\,0",LEN(A1))),2,2*LEN(A1))
 
Last edited:
Upvote 0
Thank you, guys all, for your great answers really. I appreciate it.
 
Upvote 0
Try whit UDF (User Definition Function)

Code:
Function AddComma(s As Range)
    Dim i As Long, cad As String
    For i = 1 To Len(s)
        cad = cad & Mid(s, i, 1) & ","
    Next
    AddComma = Left(cad, Len(cad) - 1)
End Function

Use like formula excel:

=AddComma(A1)

Given the formula I posted in Message #8 , a UDF for this functionality (if one was thought to be necessary now) could be written as a non-looping one-liner...
Code:
Function AddCommas(s As String) As String
  AddCommas = Evaluate(Replace("MID(TEXT(@,REPT(""\,0"",LEN(@))),2,2*LEN(@))", "@", s))
End Function
 
Last edited:
Upvote 0

Forum statistics

Threads
1,213,549
Messages
6,114,264
Members
448,558
Latest member
aivin

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