Adding a comma between single digits in a cell

lind33

New Member
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
 

Eric W

MrExcel MVP
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)
 

mumps

Well-known Member
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
 

Eric W

MrExcel MVP
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! :)
 

Rick Rothstein

MrExcel MVP
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:

DanteAmor

Well-known Member
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)
 

Rick Rothstein

MrExcel MVP
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:

lind33

New Member
Thank you, guys all, for your great answers really. I appreciate it.
 

Rick Rothstein

MrExcel MVP
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:

Some videos you may like

This Week's Hot Topics

  • Get External Data (long shot question!)
    This is likely a long shot but I am wondering if it is at all possible for Excel to somehow 'change' the contents of a URL that is being linked to...
  • Importing multiple excel files into one spreadsheet
    Hi, I'm trying to import multiple excel files (with the same format into a single spreadsheet) so that each day's file is listed underneath the...
  • Cell Formatting
    Good Morning, I need to format a few different cells in the following manners: A1 has to always add a colon (:) after whatever is typed in by a...
  • How to copy multiple rows using If
    Hi all, I'm very new to VBA and have written this simple code to copy certain cells if a certain cell within that row contains any data. I need...
  • Workbook_Change stopped working !
    I am working on an app to speed up & automate processing of Credit Cards statements. After data is input from a CSV file, it is presented to the...
  • VBA If statement
    Dear All, I have two dates, where I'd like a message box to pop, if the dates are between this criteria. [CODE] sDate1 = #10/1/2019#...
Top