+ Reply to Thread
Results 1 to 5 of 5

Transpose horizontal set of data with mulitple columns and rows to colums

  1. #1
    Registered User
    Join Date
    10-12-2018
    Location
    Poland
    MS-Off Ver
    Office365
    Posts
    3

    Transpose horizontal set of data with mulitple columns and rows to colums

    Hi All,
    I would like to transpose >1000 columns with various number of rows to column-based set of data. Example of the current layout:


    Row| Column A
    1 Albania
    2 5.3000

    3 35568011
    4 355680120
    5 355680121
    6 35568031
    7 355680320
    8 355680321


    Row | Column B
    1 Brazil
    2 1.1
    3 55

    The desired output would be:

    Column A | Column B | Column C
    Albania 5.3000 35568011
    Albania 5.3000 355680120
    Albania 5.3000 355680121
    Albania 5.3000 35568031
    Albania 5.3000 355680320
    Albania 5.3000 355680321
    Brazil 1.1 55

    Thanks in advance for your time and effort!

    Cheers,
    Simon

  2. #2
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (both in England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2506 (Windows 11 Home 24H2 64-bit)
    Posts
    91,395

    Re: Transpose horizontal set of data with mulitple columns and rows to colums

    Will you please attach a sample Excel workbook? We are not able to work with or manipulate a picture of one and nobody wants to have to recreate your data from scratch.

    1. Make sure that your sample data are REPRESENTATIVE of your real data. The use of unrepresentative data is very frustrating and can lead to long delays in reaching a solution.

    2. Make sure that your desired results are also shown (mock up the results manually).

    3. Make sure that all confidential data is removed or replaced with dummy data first (e.g. names, addresses, E-mails, etc.).

    4. Try to avoid using merged cells as they cause lots of problems.

    Unfortunately the attachment icon doesn't work at the moment, so to attach an Excel file you have to do the following: just before posting, scroll down to Go Advanced and then scroll down to Manage Attachments. Now follow the instructions at the top of that screen.

    Please pay particular attention to point 2 (above): without an idea of your intended outcomes, it is often very difficult to offer appropriate advice.
    Ali


    Enthusiastic self-taught user of MS Excel who's always learning!
    Don't forget to say "thank you" in your thread to anyone who has offered you help. It's a universal courtesy.
    You can reward them by clicking on * Add Reputation below their user name on the left, if you wish.

    NB:
    as a Moderator, I never accept friendship requests.
    Forum Rules (updated August 2023): please read them here.

  3. #3
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (both in England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2506 (Windows 11 Home 24H2 64-bit)
    Posts
    91,395

    Re: Transpose horizontal set of data with mulitple columns and rows to colums

    The attached is done with Power Query (Get & Transform on the Data ribbon). Shout if you need help understanding it.

    M Code:
    Please Login or Register  to view this content.
    Attached Files Attached Files

  4. #4
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2406
    Posts
    44,662

    Re: Transpose horizontal set of data with mulitple columns and rows to colums

    Here's a formula based alternative. Extend the ranges as needed.

    H3 (an array formula):
    =IF(ROWS(H$3:H3)>COUNTIF(Raw!$A$4:$D$11,"<>"),"",INDEX(Raw!$A$2:$D$2,MATCH(TRUE,MMULT(0+(TRANSPOSE(COLUMN(Raw!$A$4:$D$11))>=(COLUMN(Raw!$A$4:$D$11))),MMULT(0+TRANSPOSE(Raw!$A$4:$D$11<>""),(ROW(Raw!$A$4:$D$11)^0)))>=ROWS(H$3:H3),0)))

    I3 (similar to H3)

    and J3, an ordinary formula:
    =IF(H3="","",INDEX(INDEX(A:D,,MATCH(H3,$A$2:$D$2,0)),AGGREGATE(15,6,ROW($A$4:$A$11)/(INDEX($A$4:$D$11,,MATCH(H3,$A$2:$D$2,0))<>""),COUNTIF($H$3:H3,H3))))
    Attached Files Attached Files
    Glenn




    None of us get paid for helping you... we do this for fun. So DON'T FORGET to say "Thank You" to all who have freely given some of their time to help YOU

  5. #5
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2406
    Posts
    44,662

    Re: Transpose horizontal set of data with mulitple columns and rows to colums

    Ooops.

    Array Formulae are a little different from ordinary formulae in that they MUST be confirmed in the FIRST CELL ONLY by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER. After that, the array can be dragged down as normal, to cover the desired range.

    You will know the array is active when you see curly brackets { } - or "curly braces" for those of you in the USA, or "flower brackets" for those of you in India - appear around the outside of your formula. If you do not use CTRL+SHIFT+ENTER you will (almost always) get an error message or an incorrect answer. Press F2 on that cell and try again.

    Don't type the curly brackets yourself - it won't work...

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

Similar Threads

  1. Transpose web data from horizontal (rows) to vertical (columns) for html files
    By Dahlia in forum Excel Programming / VBA / Macros
    Replies: 1
    Last Post: 08-23-2018, 11:02 AM
  2. [SOLVED] Transpose web data from horizontal (rows) to vertical (columns)
    By Dahlia in forum Excel Programming / VBA / Macros
    Replies: 4
    Last Post: 08-13-2018, 06:10 AM
  3. [SOLVED] Macro that transposes Vertical Data to Horizontal for Mulitple rows
    By Jbets44 in forum Excel Programming / VBA / Macros
    Replies: 7
    Last Post: 08-27-2014, 05:29 PM
  4. [SOLVED] Converting Vertical Columns in to Horizontal Rows - (Better solution to Transpose)
    By ps_upasani in forum Excel Programming / VBA / Macros
    Replies: 9
    Last Post: 06-30-2013, 05:32 AM
  5. Replies: 1
    Last Post: 03-22-2013, 10:05 AM
  6. [SOLVED] Transpose rows to columns: variable amount of colums and corresponding values
    By Browser in forum Excel Programming / VBA / Macros
    Replies: 7
    Last Post: 07-10-2012, 10:40 AM
  7. Replies: 2
    Last Post: 02-19-2007, 04:53 PM

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