Forum Discussion

frri3484's avatar
frri3484
Copper Contributor
Jul 17, 2019
Solved

Text to Columns for Multiple Columns at Once

I have maybe 100 columns that have all similar info like "number X". All of these columns need to be split into "number" and "X". So far I have been using the text to columns feature for each individual column. I am wondering, is there a way to split all of these at once? Thanks in advanced!

Example:

|A   |B     |C    |D   |         to-->        |A   |B  |C   |D   |

|1 X|        |2 Y|      |                        | 1  | X  | 2  | Y  |            

  • frri3484 

    If you already have blank columns next to your data, you can use a simple macro to automate your text to column conversions. I suggest recording the conversion of one column, then generalizing the recorded macro because the text to columns method is a little complicated.

     

    The code below was based on a recorded macro. It assumes you select the cells to be converted, that every other column will be converted, and that you already have the necessary blank columns.

    Sub TextToColumnator()
    Dim rg As Range
    Dim i As Long, n As Long
    Application.ScreenUpdating = False
    Application.DisplayAlerts = False
    Set rg = Selection
    n = rg.Columns.Count
    For i = 1 To n Step 2
        rg.Columns(i).TextToColumns Destination:=rg.Cells(1, i), DataType:=xlDelimited, _
            TextQualifier:=xlDoubleQuote, ConsecutiveDelimiter:=True, Tab:=True, _
            Semicolon:=False, Comma:=False, Space:=True, Other:=False, FieldInfo _
            :=Array(Array(1, 1), Array(2, 1)), TrailingMinusNumbers:=True
    Next
    Application.DisplayAlerts = True
    End Sub

10 Replies

  • tauqeeracma's avatar
    tauqeeracma
    Iron Contributor

    frri3484 

    Hi,

    There is another way of splitting the columns in excel using Left() & Right() functions.

    If the formation of your data is somehow uniform you can use these functions and easily split all columns in one go.

     

    I have attached a sample file just for understanding purpose.

     

    You may also share your file, so more solutions can be suggested.

    Thanks, 

    Tauqeer

    • frri3484's avatar
      frri3484
      Copper Contributor

      tauqeeracmaI was hoping this would work since it's easier, however my data is all over the place in length. But thanks for the response! I never knew this was a function before.

      • Brad_Yundt's avatar
        Brad_Yundt
        MVP

        frri3484 

        "however my data is all over the place in length"

         

        That's why you should always post a sample workbook with data illustrating the problem. Then instead of getting a suggestion that solves the question you asked, you get one that addresses the specifics of your actual data.

         

        If the columns are of different length, that is easily addressed with a tweak to the macro. If the blank columns between your data don't exist, that can also be addressed. If you may have more than one delimiter in each cell, even that can also be addressed (though with somewhat more difficulty).

         

        Brad

  • frri3484 

    If you already have blank columns next to your data, you can use a simple macro to automate your text to column conversions. I suggest recording the conversion of one column, then generalizing the recorded macro because the text to columns method is a little complicated.

     

    The code below was based on a recorded macro. It assumes you select the cells to be converted, that every other column will be converted, and that you already have the necessary blank columns.

    Sub TextToColumnator()
    Dim rg As Range
    Dim i As Long, n As Long
    Application.ScreenUpdating = False
    Application.DisplayAlerts = False
    Set rg = Selection
    n = rg.Columns.Count
    For i = 1 To n Step 2
        rg.Columns(i).TextToColumns Destination:=rg.Cells(1, i), DataType:=xlDelimited, _
            TextQualifier:=xlDoubleQuote, ConsecutiveDelimiter:=True, Tab:=True, _
            Semicolon:=False, Comma:=False, Space:=True, Other:=False, FieldInfo _
            :=Array(Array(1, 1), Array(2, 1)), TrailingMinusNumbers:=True
    Next
    Application.DisplayAlerts = True
    End Sub
    • alinadavis's avatar
      alinadavis
      Copper Contributor

      Brad_Yundt 

       

      Hi Brad - what if I didn't want to select the columns to use this macro on, and rather wanted it to just run through each column of my data until it reached the end? Is this possible?

       

      I have data that is coming in with numbers as text, and changing the cell formatting the normal way does not work until I click into the cell and click out. Obviously I can't do this for every cell in a spreadsheet with hundreds of cells. I have found using text to columns to just paste the new data over the source data works to change it to number format. I'd like to automate this with a macro and yours works well for my purposes, but I would like it to just run on all columns instead of selecting.

       

      Thank you!

      • byundt's avatar
        byundt
        Brass Contributor

        alinadavis 

        Change the fifth statement to:

        Set rg = ActiveSheet.UsedRange.EntireColumn
    • frri3484's avatar
      frri3484
      Copper Contributor

      Brad_Yundt 

      Oh wow! I got the macro you shared to work, thank you! I was initially trying to record my own macro instead, which I'd still like to figure out. But for my current purposes, yours works exactly how I need!

      :)

      • Brad_Yundt's avatar
        Brad_Yundt
        MVP

        frri3484 

        It is also possible to use a macro to insert the blank columns.

         

        Select your data, then run the macro. It will add blank columns after each column in your selection.

        Sub InsertBlankColumns()
        Dim rg As Range
        Dim i As Long, n As Long
        Application.ScreenUpdating = False
        Set rg = Selection.EntireColumn
        n = rg.Columns.Count
        For i = n To 1 Step -1
            rg.Columns(i + 1).EntireColumn.Insert
        Next
        End Sub

Resources