+ Reply to Thread
Results 1 to 10 of 10

Convert multiple columns to rows

  1. #1
    Lois Lane
    Guest

    Convert multiple columns to rows

    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!

  2. #2
    Alan Beban
    Guest

    Re: Convert multiple columns to rows

    Lois Lane wrote:
    > 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

  3. #3
    Bob Phillips
    Guest

    Re: Convert multiple columns to rows

    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)


    "Lois Lane" <Lois Lane@discussions.microsoft.com> wrote in message
    news:2446B2E3-75E1-4419-B6E6-1B5BBB6AB602@microsoft.com...
    > 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!




  4. #4
    Gary Rowe
    Guest

    RE: Convert multiple columns to rows

    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

    "Lois Lane" wrote:

    > 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!


  5. #5
    Jason Morin
    Guest

    Re: Convert multiple columns to rows

    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

    >-----Original Message-----
    >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!
    >.
    >


  6. #6
    Lois Lane
    Guest

    RE: Convert multiple columns to rows

    Thank you, Gary - I'll try it!

    "Gary Rowe" wrote:

    > 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
    >
    > "Lois Lane" wrote:
    >
    > > 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!


  7. #7
    Lois Lane
    Guest

    Re: Convert multiple columns to rows

    Worked like a charm - thank you!

    "Bob Phillips" wrote:

    > 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)
    >
    >
    > "Lois Lane" <Lois Lane@discussions.microsoft.com> wrote in message
    > news:2446B2E3-75E1-4419-B6E6-1B5BBB6AB602@microsoft.com...
    > > 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!

    >
    >
    >


  8. #8
    Lois Lane
    Guest

    Re: Convert multiple columns to rows

    Thank you, Alan!

    "Alan Beban" wrote:

    > Lois Lane wrote:
    > > 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
    >


  9. #9
    Lois Lane
    Guest

    Re: Convert multiple columns to rows

    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.

    "Jason Morin" wrote:

    > 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
    >
    > >-----Original Message-----
    > >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!
    > >.
    > >

    >


  10. #10
    Registered User
    Join Date
    10-13-2015
    Location
    Riyadh
    MS-Off Ver
    2007
    Posts
    1

    Re: Convert multiple columns to rows

    Quote Originally Posted by Bob Phillips View Post
    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)


    "Lois Lane" <Lois Lane@discussions.microsoft.com> wrote in message
    news:2446B2E3-75E1-4419-B6E6-1B5BBB6AB602@microsoft.com...
    > 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!
    -------
    I would like to thank you Bob Phillips because this answer, and i register specially for that, I faced the same Lois Lane issue but with huage columns and rows (53 columns& 6000 rows) and I customized your attached code before and its worked perfectly and i accomplished my job alhamdo le Allah, Thanks again.

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1