+ Reply to Thread
Results 1 to 10 of 10

extracting multiple 46 rows of data from a single column of over 2500 rows

  1. #1
    Registered User
    Join Date
    11-10-2015
    Location
    Victoria, Australia
    MS-Off Ver
    2010
    Posts
    4

    extracting multiple 46 rows of data from a single column of over 2500 rows

    Hi,
    Ok, the title might sound simple and it is quite easy to do manually, but it takes for ever to do. I am trying to sort the data from a horse racing form list for 13 horses. (and before you ask, the selection programme I've already written might fail totally, It's about the journey) So there is up to 24 lots of horse form data, each lot starting with 1 then 2 then 3 for each horse etc etc up to a possible 24 horses for the Melbourne Cup. So we know the start of each lot of data (1,2,3,4 etc) and we know the data for each horse finishes 46 rows later. The catch 22 is that, between each lot of 46 rows of data I require for each horse, the number of rows in between is a variable. could be 20 rows, could be 30 rows??
    So, If I have the column of 2500+ rows of data in column A, I want to extract the 46 rows of data for each horse to start at column B1 for 46 rows, then C1 same, then D1, E1, F1, G1, etc etc etc. Hope this makes sense and hope someone can help. Thanks in advance. attachment for example "Horse form data"
    Attached Files Attached Files

  2. #2
    Forum Expert
    Join Date
    05-05-2015
    Location
    UK
    MS-Off Ver
    Microsoft Excel for Microsoft 365 MSO (Version 2402 Build 16.0.17328.20068) 64-bit
    Posts
    28,206

    Re: extracting multiple 46 rows of data from a single column of over 2500 rows

    You cannot use 1,2,3 etc as start of data because these numbers appear in many rows which are not the "Start" of data for a given horse. Unless there is data which will always find the start of the data for a given horse, it's mission impossible.

  3. #3
    Registered User
    Join Date
    11-10-2015
    Location
    Victoria, Australia
    MS-Off Ver
    2010
    Posts
    4

    Re: extracting multiple 46 rows of data from a single column of over 2500 rows

    Thanks for the reply. Not exactly what I wanted to hear. Would it be possible if next to the column of data I listed the horses in the race. Could it be done for the 44 rows down from each horses name?? This would give a fixed starting point.

  4. #4
    Forum Expert bebo021999's Avatar
    Join Date
    07-22-2011
    Location
    Vietnam
    MS-Off Ver
    Excel 2016
    Posts
    9,466

    Re: extracting multiple 46 rows of data from a single column of over 2500 rows

    I would suggest to stick starting points to negative numbers in A column.
    For example, -7 is found in A233, moving up 3 cells is A230=1 to be set as starting point.
    Is it reasonable?
    Quang PT

  5. #5
    Forum Expert bebo021999's Avatar
    Join Date
    07-22-2011
    Location
    Vietnam
    MS-Off Ver
    Excel 2016
    Posts
    9,466

    Re: extracting multiple 46 rows of data from a single column of over 2500 rows

    OK, follow my logic in #3, try as follow step by step:
    C1 to the right is consecutive running list from 1 to 24
    C1=column(A:A)
    From C2 and drag to C46:
    =INDEX($A$1:$A$2396,MATCH(C$1,INDEX(($A$4:$A$239<0)*$A$1:$A$236,),0)+ROWS($1:1))
    Drag C1:C46 accross.
    Does it help?

  6. #6
    Forum Expert
    Join Date
    05-05-2015
    Location
    UK
    MS-Off Ver
    Microsoft Excel for Microsoft 365 MSO (Version 2402 Build 16.0.17328.20068) 64-bit
    Posts
    28,206

    Re: extracting multiple 46 rows of data from a single column of over 2500 rows

    The following code will extract data based on name of horse. It currently takes the names from column C onwards and retrieves the 46 rows you required.

    The output is to Sheet3.

    Change highlighted code to suit


    Please Login or Register  to view this content.
    Attached Files Attached Files

  7. #7
    Registered User
    Join Date
    11-10-2015
    Location
    Victoria, Australia
    MS-Off Ver
    2010
    Posts
    4

    Re: extracting multiple 46 rows of data from a single column of over 2500 rows

    Thanks. Both worked although the Macro was a little harder to adapt. The formula from bebo seems the best although I had to increase the ranges. Can you explain it to me in plain English. I think I have most f it worked out but couldn't figure why the 2nd part indexed was from A4?? I changed it a few times up and down and it only worked on A4. Why??? Thanks again

    =INDEX($A$1:$A$2396,MATCH(C$1,INDEX(($A$4:$A$239<0)*$A$1:$A$236,),0)+ROWS($1:1))

  8. #8
    Forum Expert
    Join Date
    05-05-2015
    Location
    UK
    MS-Off Ver
    Microsoft Excel for Microsoft 365 MSO (Version 2402 Build 16.0.17328.20068) 64-bit
    Posts
    28,206

    Re: extracting multiple 46 rows of data from a single column of over 2500 rows

    A4 is used to determine where the start of data is:

    Take first horse:

    Negative number in A22 which is cell 19 starting from 4 : the $A$4:$A$239<0 test will return 1 (TRUE) at A22 (0 for all others).

    The A1:A236 multiplies all the results by the contents in A which result in 0/1 if A contains a number, #value if text. The MATCH then matches value in (say) C1 and in this case finds a match at A19.

    The ROWS($1:1) adds 1 to start the data following the "1": copying down simply increments ROWS

    Make sense??

  9. #9
    Forum Expert bebo021999's Avatar
    Join Date
    07-22-2011
    Location
    Vietnam
    MS-Off Ver
    Excel 2016
    Posts
    9,466

    Re: extracting multiple 46 rows of data from a single column of over 2500 rows

    @John, thanks for your support.
    @Spekky2, glad to hear it works.
    Anyway, after checking again, my formula should be:

    =INDEX($A$1:$A$2396,MATCH(C$1,INDEX(($A$4:$A$2396<0)*$A$1:$A$2393,),0)+ROWS($1:1))

    The second INDEX, to avoid array formula, INDEX(array...,) converts array formula (confirmed by Ctrl-Shift-Enter) to non array formula (Enter only).

    Refer to INDEX starts from cell A4: to locate the starting point (1,2,3,4), I found down that there always be a negative value 3 cells after. For example A19=1, A22=-9. Since it is hard to locate "1", so locate -9 by (A4:A2396<0) returns 1 where a negative value exist (position 19 in the array). To get value 1 in A19, use (A4:A2396<0)*(A1:A2393) equals A4*A1, A5*A2,...,A22*A19,...

    Hope it is clear for you.

  10. #10
    Registered User
    Join Date
    11-10-2015
    Location
    Victoria, Australia
    MS-Off Ver
    2010
    Posts
    4

    Re: extracting multiple 46 rows of data from a single column of over 2500 rows

    All good Thanks

+ 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. Replies: 6
    Last Post: 08-18-2012, 05:00 AM
  2. Replies: 4
    Last Post: 07-03-2012, 08:01 PM
  3. Merging multiple rows and column data for each unique ID into single row
    By skilaru in forum Excel Programming / VBA / Macros
    Replies: 4
    Last Post: 02-22-2012, 11:59 AM
  4. Replies: 5
    Last Post: 02-07-2012, 04:55 PM
  5. Transposing single column data to multiple rows
    By AudreyWalsh in forum Excel General
    Replies: 5
    Last Post: 01-02-2012, 09:09 PM
  6. Inserting Blank rows after every row upto 2500 rows
    By Manju in forum Excel Formulas & Functions
    Replies: 8
    Last Post: 08-22-2006, 08:00 AM
  7. Replies: 1
    Last Post: 01-11-2006, 11:30 PM
  8. Help!!! I have problem deleting 2500 rows of filtered rows
    By shirley_kee in forum Excel Programming / VBA / Macros
    Replies: 1
    Last Post: 01-11-2006, 11:20 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