+ Reply to Thread
Results 1 to 17 of 17

Sort column data separated by blanks into other column

Hybrid View

  1. #1
    Registered User
    Join Date
    11-25-2016
    Location
    london, england
    MS-Off Ver
    2007
    Posts
    8

    Question Sort column data separated by blanks into other column

    Hello experts,
    Something new !!

    The data is as follows

    aaa
    bbb
    ccc

    eee
    ffff
    ggg


    hhh
    iii
    jjj

    I would like to separate it into separate columns to perform analysis.
    like

    aaa eee hhh
    bbb ffff iiiii
    ccc ggg jjjj

    Any tip would be highly appreciated.

  2. #2
    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: Sort column data separated by blanks into other column

    Is ialways the same...

    3 items 1 gap, 3 items, 1 gap?

    if not, post some REPRESENTATIVE data. Please don't attach a picture of a sheet!!.

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

  3. #3
    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: Sort column data separated by blanks into other column

    If your post is really what you have... use this (assuming data in A1 to A11), copied across and down:

    if your data are text (as in the example) use this:

    =IFERROR(IF(ROWS($1:1)<=4,INDEX($A$1:$A$11,ROWS($1:1)+(COLUMNS($A:A)-1)*4)&"",""),"")

    if your data are numbers, use this:
    =IFERROR(1/(1/IF(ROWS($1:1)<=4,INDEX($A$1:$A$11,ROWS($1:1)+(COLUMNS($A:A)-1)*4),"")),"")
    Last edited by Glenn Kennedy; 11-25-2016 at 07:26 AM.

  4. #4
    Registered User
    Join Date
    11-25-2016
    Location
    london, england
    MS-Off Ver
    2007
    Posts
    8

    Re: Sort column data separated by blanks into other column

    Thanks for your reply.

    Unfortunately its not separated by equal blank spaces. Also, its a numerical data rather than a text.
    I am aiming to sort each individual group into separate columns. I have attached the spreadsheet.
    Attached Files Attached Files

  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: Sort column data separated by blanks into other column

    Are the texts "Group 1", "Group 2", etc, actually there in your real data?

  6. #6
    Registered User
    Join Date
    11-25-2016
    Location
    london, england
    MS-Off Ver
    2007
    Posts
    8

    Re: Sort column data separated by blanks into other column

    No, they were just to represent the data group as a whole I would like to copy into another column and next data group into separate column.

  7. #7
    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: Sort column data separated by blanks into other column

    Is there anything at all in the adjacent columns?

  8. #8
    Registered User
    Join Date
    11-25-2016
    Location
    london, england
    MS-Off Ver
    2007
    Posts
    8

    Re: Sort column data separated by blanks into other column

    No they are all blank.

  9. #9
    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: Sort column data separated by blanks into other column

    Do you need backward compatability with Excel 97-2003? I'm 99.9% there, BtW!!!

  10. #10
    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: Sort column data separated by blanks into other column

    If you do not need backward compatability with old Excel versions...

    In B2, copied down as far as the last row:

    =IF(ISNUMBER(A2),1+B1,0)

    In D2, use this array formula, copied across and down:

    =IFERROR(INDEX($A:$A,SMALL(IF(B1:$B$317=ROWS($D$1:$D1),ROW(B1:$B$317)),COLUMNS($A:A))),"")

    Array Formulae are a little different from ordinary formulae in that they MUST be confirmed by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER.

    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...
    Attached Files Attached Files

  11. #11
    Registered User
    Join Date
    11-25-2016
    Location
    london, england
    MS-Off Ver
    2007
    Posts
    8

    Re: Sort column data separated by blanks into other column

    Quote Originally Posted by Glenn Kennedy View Post
    If you do not need backward compatability with old Excel versions...

    In B2, copied down as far as the last row:

    =IF(ISNUMBER(A2),1+B1,0)

    In D2, use this array formula, copied across and down:

    =IFERROR(INDEX($A:$A,SMALL(IF(B1:$B$317=ROWS($D$1:$D1),ROW(B1:$B$317)),COLUMNS($A:A))),"")

    Array Formulae are a little different from ordinary formulae in that they MUST be confirmed by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER.

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

    The issue I am facing now is, if I don't have 7 entries in the first group (ex by deleting 986 in A32 ); the index array formula shifts the last row towards the left (filled in red). Is there any way to record them as a group they belong.
    Attached Files Attached Files

  12. #12
    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: Sort column data separated by blanks into other column

    If you do need backward compatability, use this array formula, instead:

    =IF(ISERROR(INDEX($A$1:$A$317,SMALL(IF(B2:$B$317=ROWS($D$1:$D2),ROW(B2:$B$317)),COLUMNS($A$1:A$1)))),"",INDEX($A$1:$A$317,SMALL(IF(B2:$B$317=ROWS($D$1:$D2),ROW(B2:$B$317)),COLUMNS($A$1:A$1))))
    Attached Files Attached Files

  13. #13
    Registered User
    Join Date
    11-25-2016
    Location
    london, england
    MS-Off Ver
    2007
    Posts
    8

    Re: Sort column data separated by blanks into other column

    Brilliant stuff!! Thanks a lot for this, it was really helpful.

  14. #14
    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: Sort column data separated by blanks into other column

    Heh!!! There's a minor error that I've just spotted:

    =IFERROR(INDEX($A:$A,SMALL(IF($B$1:$B$317=ROWS($D$1:$D1),ROW($B$1:$B$317)),COLUMNS($A:A))),"")

    and this applies to BOTH versions.

  15. #15
    Registered User
    Join Date
    11-25-2016
    Location
    london, england
    MS-Off Ver
    2007
    Posts
    8

    Re: Sort column data separated by blanks into other column

    Yep !! spotted and removed, its working now. Cheers !!

  16. #16
    Registered User
    Join Date
    11-25-2016
    Location
    london, england
    MS-Off Ver
    2007
    Posts
    8

    Re: Sort column data separated by blanks into other column

    The issue I am facing now is, if I don't have 7 entries in the first group (ex by deleting 986 in A32 ); the index array formula shifts the last row towards the left (filled in red). Is there any way to record them as a group they belong.

    Also posted here:

    http://www.excelguru.ca/forums/showt...o-other-column

    http://www.mrexcel.com/forum/excel-q...er-column.html
    Attached Files Attached Files
    Last edited by vivmahal; 12-01-2016 at 09:14 AM.

  17. #17
    Forum Expert Pepe Le Mokko's Avatar
    Join Date
    05-14-2009
    Location
    Belgium
    MS-Off Ver
    O365 v 2504
    Posts
    13,620

    Re: Sort column data separated by blanks into other column

    Your post does not comply with Rule 8 of our Forum RULES. Do not crosspost your question on multiple forums without including links here to the other threads on other forums.

    Cross-posting is when you post the same question in other forums on the web. The last thing you want to do is waste people's time working on an issue you have already resolved elsewhere. We prefer that you not cross-post at all, but if you do (and it's unlikely to go unnoticed), you MUST provide a link (copy the url from the address bar in your browser) to the cross-post.

    Expect cross-posted questions without a link to be closed and a message will be posted by the moderator explaining why. We are here to help so help us to help you!

    Read this to understand why we ask you to do this, and then please edit your first post to include links to any and all cross-posts in any other forums (not just this site).

    http://www.excelguru.ca/forums/showt...o-other-column

+ 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. Evaluating rows column-by-column to separate comma-separated data
    By adventurepirate in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 11-30-2014, 03:06 PM
  2. Replies: 2
    Last Post: 09-26-2014, 04:28 PM
  3. Sort multiple columns to one column, skip blanks
    By AlexCoyne in forum Excel Programming / VBA / Macros
    Replies: 10
    Last Post: 05-20-2013, 03:13 PM
  4. Scan a Column A (numbers and blanks) and copy its contents WITHOUT BLANKS into Column B
    By bighandsam in forum Excel Programming / VBA / Macros
    Replies: 1
    Last Post: 07-12-2012, 05:16 PM
  5. Replies: 2
    Last Post: 02-02-2012, 09:02 AM
  6. [SOLVED] Returning most recent daily data in a column if blanks in column
    By InnesMcc in forum Excel General
    Replies: 6
    Last Post: 11-04-2011, 09:41 AM
  7. [SOLVED] Returning most recent daily data in a column if blanks in column
    By InnesMcc in forum Excel General
    Replies: 2
    Last Post: 11-04-2011, 06:28 AM

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