Convert multiple columns to rows

G

Guest

Excel's help file provides a specific formula to convert multiple rows to
columns. However, I need help in converting multiple columns to rows,
placing a blank row inbetween each set of records. Right now, the data is in
this format, representing 4 columns:

ABC Company John Doe Anytown (000)000-0000
XYZ Company Jane Smith Metropolis (000)555-5555

I need the data to be formatted as such:

ABC Company
John Doe
Anytown
(000)000-0000

XYZ Company
Jane Smith
Metropolis
(000)555-5555

I tried modifying the formula provided by Microsoft to convert rows to
columns, but it didn't work.

Thanks, in advance!
 
A

Alan Beban

Lois said:
Excel's help file provides a specific formula to convert multiple rows to
columns. However, I need help in converting multiple columns to rows,
placing a blank row inbetween each set of records. Right now, the data is in
this format, representing 4 columns:

ABC Company John Doe Anytown (000)000-0000
XYZ Company Jane Smith Metropolis (000)555-5555

I need the data to be formatted as such:

ABC Company
John Doe
Anytown
(000)000-0000

XYZ Company
Jane Smith
Metropolis
(000)555-5555
If the functions in the freely downloadable file at
http://home.pacbell.net/beban are available to your workbook, and
Tools|Options|View|Zero values is unchecked

=TRANSPOSE(MakeArray(A1:E2,1)) array entered

Alan Beban
 
B

Bob Phillips

Lois,

Try this macro

Sub Reformat()
Dim i As Long
Dim cLastRow As Long

Application.ScreenUpdating = False
With ActiveSheet
cLastRow = .Cells(Rows.Count, "A").End(xlUp).Row
For i = cLastRow To 1 Step -1
.Cells(i + 1, "A").Resize(4, 1).EntireRow.Insert
.Cells(i + 1, "A").Value = .Cells(i, "B").Value
.Cells(i + 2, "A").Value = .Cells(i, "C").Value
.Cells(i + 3, "A").Value = .Cells(i, "D").Value
.Cells(i, "B").Resize(1, 3).ClearContents
Next i
End With
Application.ScreenUpdating = True

End Sub


--

HTH

RP
(remove nothere from the email address if mailing direct)
 
G

Guest

You can accomplish with a pivot table. Set up the pivot table with your data
and put the company, person, city, telephone fields in rows and set the field
settings for each to outline. Also set the company field settings to include
a blank line after each one. Then in a cell outside of the pivot table enter
a formula to concatenate the four cells containing the data on each line such
as =B5&C5&D5&E5 where one field will have info and the three others will be
blank. The result will be the information (company, person, city, telephone)
in each row. You can then copy and paste/special and select values. Then
you can delete the pivot table.
Gary
 
J

Jason Morin

Another way would be to select the 5th col. on your data
sheet (assuming it's named "mysht"), enter ="", and press
<ctrl><enter>. Now on a new sheet in A1 put:

=OFFSET(mysht!$A$1,ROUNDUP(ROW()/5,0)-1,ROW()-(ROUNDUP(ROW
()/5,0)*5-5)-1)

and copy down as far as needed.

HTH
Jason
Atlanta, GA
 
G

Guest

Thank you, Gary - I'll try it!

Gary Rowe said:
You can accomplish with a pivot table. Set up the pivot table with your data
and put the company, person, city, telephone fields in rows and set the field
settings for each to outline. Also set the company field settings to include
a blank line after each one. Then in a cell outside of the pivot table enter
a formula to concatenate the four cells containing the data on each line such
as =B5&C5&D5&E5 where one field will have info and the three others will be
blank. The result will be the information (company, person, city, telephone)
in each row. You can then copy and paste/special and select values. Then
you can delete the pivot table.
Gary
 
G

Guest

Worked like a charm - thank you!

Bob Phillips said:
Lois,

Try this macro

Sub Reformat()
Dim i As Long
Dim cLastRow As Long

Application.ScreenUpdating = False
With ActiveSheet
cLastRow = .Cells(Rows.Count, "A").End(xlUp).Row
For i = cLastRow To 1 Step -1
.Cells(i + 1, "A").Resize(4, 1).EntireRow.Insert
.Cells(i + 1, "A").Value = .Cells(i, "B").Value
.Cells(i + 2, "A").Value = .Cells(i, "C").Value
.Cells(i + 3, "A").Value = .Cells(i, "D").Value
.Cells(i, "B").Resize(1, 3).ClearContents
Next i
End With
Application.ScreenUpdating = True

End Sub


--

HTH

RP
(remove nothere from the email address if mailing direct)
 
G

Guest

This was by far the easiest solution! Thank you very much, Jason!
Initially, it wouldn't work, but I realized your formula was on two lines
instead of one - once I pasted it all on one line, it was perfect!

Thanks again.
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top