custom column to row

kambing_tempur

New Member
Joined
Jan 10, 2016
Messages
11
Hi, I have a number of similarly formatted data but they are all in stacked together in 1 column, I want to move them so that each data has their own columns, it should be something like this:

1A1A2A3A
1B1B2B3B
1C1C2C3C
2A
2B==>
2C
3A
3B
3C

<tbody>
</tbody>

Does anyone have any idea? thanks in advance
 

Excel Facts

Create a Pivot Table on a Map
If your data has zip codes, postal codes, or city names, select the data and use Insert, 3D Map. (Found to right of chart icons).
kambing_tempur,

With your raw data in worksheet Sheet1. You can change the raw data worksheet name in the macro.

With your raw data sorted/grouped by the text in column A.

Here is a macro solution, and, Function, for you to consider, based on your flat text display, and, it will adjust to the number of raw data rows, and, columns needed for the results.

Sample raw data, and, results:


Excel 2007
ABCDEFG
11A1A1B1C
21B2A2B2C
31C3A3B3C
42A4A4B4C4D
52B
62C
73A
83B
93C
104A
114B
124C
134D
14
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, and, Function
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 ReorgData()
' hiker95, 11/25/2016, ME977400
Dim r As Long, lr As Long, n As Long, nr As Long
Application.ScreenUpdating = False
With Sheets("Sheet1")   '<-- you can change the sheet name here
  lr = .Cells(Rows.Count, 1).End(xlUp).Row
  .Range("B1").Formula = "=GetDigits(A1)"
  .Range("B1").Copy .Range("B2:B" & lr)
  nr = 0
  For r = 1 To lr
    nr = nr + 1
    n = Application.CountIf(.Columns(2), .Cells(r, 2).Value)
    .Cells(nr, 3).Resize(, n).Value = Application.Transpose(.Range("A" & r & ":A" & r + n - 1))
    .Cells(r, 2).Resize(n).ClearContents
    r = r + n - 1
Next r
  .UsedRange.Columns.AutoFit
End With
Application.ScreenUpdating = True
End Sub
Function GetDigits(ByVal Text As String) As String
' Rick Rothstein, MrExcel MVP, 08/18/2011, ME572628
' http://www.mrexcel.com/forum/excel-questions/572628-extract-numbers-string.html
Dim X As Long
For X = 1 To Len(Text)
  If Not Mid(Text, X, 1) Like "#" Then Mid(Text, X) = " "
Next
GetDigits = Replace(Text, " ", "")
End Function

Before you use the macro, and, Function, 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 ReorgData macro.
 
Upvote 0
Here is a macro solution, and, Function, for you to consider, based on your flat text display, and, it will adjust to the number of raw data rows, and, columns needed for the results.
Your macro appears to output the results transposed from what was asked for.
 
Last edited:
Upvote 0
Hi, I have a number of similarly formatted data but they are all in stacked together in 1 column, I want to move them so that each data has their own columns, it should be something like this:
Two questions...

1) Does your data really look like that (where the first character only distinguishes one group from another?

2) Do all of your groups always consist of the same number of rows (3 in the case of your example data) or can the number of rows in each group differ from the number of rows in other groups?
 
Upvote 0
Your macro appears to output the results transposed from what was asked for.

Rick Rothstein,

Thanks for that catch, and, I do not understand what I did???
 
Upvote 0
kambing_tempur,

With your raw data in worksheet Sheet1. You can change the raw data worksheet name in the macro.

With your raw data sorted/grouped by the text in column A.

Here is a corrected macro solution, and, Function, for you to consider, based on your flat text display, and, it will adjust to the number of raw data rows, and, columns needed for the results.

Sample raw data, and, results:


Excel 2007
ABCDEFG
11A1A2A3A4A
21B1B2B3B4B
31C1C2C3C4C
42A4D
52B
62C
73A
83B
93C
104A
114B
124C
134D
14
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, and, Function
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.

In your workbook, you can only have one copy of the GetDigits Function.

Code:
Sub ReorgData_V2()
' hiker95, 11/25/2016, ME977400
Dim r As Long, lr As Long, n As Long, nc As Long
Application.ScreenUpdating = False
With Sheets("Sheet1")   '<-- you can change the sheet name here
  lr = .Cells(Rows.Count, 1).End(xlUp).Row
  .Range("B1").Formula = "=GetDigits(A1)"
  .Range("B1").Copy .Range("B2:B" & lr)
  nc = 3
  For r = 1 To lr
    n = Application.CountIf(.Columns(2), .Cells(r, 2).Value)
    .Cells(1, nc).Resize(n).Value = .Range("A" & r & ":A" & r + n - 1).Value
    .Cells(r, 2).Resize(n).ClearContents
    r = r + n - 1
    nc = nc + 1
Next r
  .UsedRange.Columns.AutoFit
End With
Application.ScreenUpdating = True
End Sub
Function GetDigits(ByVal Text As String) As String
' Rick Rothstein, MrExcel MVP, 08/18/2011, ME572628
' http://www.mrexcel.com/forum/excel-questions/572628-extract-numbers-string.html
Dim X As Long
For X = 1 To Len(Text)
  If Not Mid(Text, X, 1) Like "#" Then Mid(Text, X) = " "
Next
GetDigits = Replace(Text, " ", "")
End Function

Before you use the macro, Function, 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 ReorgData_V2 macro.
 
Last edited:
Upvote 0
kambing_tempur,

With your raw data in worksheet Sheet1. You can change the raw data worksheet name in the macro.

With your raw data sorted/grouped by the text in column A.

Here is a corrected macro solution, and, Function, for you to consider, based on your flat text display, and, it will adjust to the number of raw data rows, and, columns needed for the results.
If you are correct and the first character determines the members of each "group", then this macro should produce the same results as yours but without needing your attached function procedure (note that my code assume it is being executed with the data sheet as the active sheet)...
Code:
[table="width: 500"]
[tr]
	[td]Sub ReorgData_V3()
  Dim R As Long, C As Long, X As Long, FirstRow As Long, FirstChar As String, Data As Variant
  Data = Range("A1", Cells(Rows.Count, "A").End(xlUp).Offset(1))
  FirstChar = Left(Data(1, 1), 1)
  FirstRow = 1
  C = 1
  Application.ScreenUpdating = False
  For R = 2 To UBound(Data)
    If Left(Data(R, 1), 1) <> FirstChar Then
      C = C + 1
      Cells(1, C).Resize(R - FirstRow) = Application.Index(Data, Evaluate("ROW(" & FirstRow & ":" & R & ")"), Split("1"))
      FirstRow = R
      FirstChar = Left(Data(R, 1), 1)
    End If
  Next
  Application.ScreenUpdating = True
End Sub[/td]
[/tr]
[/table]
 
Last edited:
Upvote 0

Forum statistics

Threads
1,214,548
Messages
6,120,141
Members
448,948
Latest member
spamiki

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