+ Reply to Thread
Results 1 to 12 of 12

Copying inconsistent header fields to matching rows

  1. #1
    Registered User
    Join Date
    01-01-2013
    Location
    United States
    MS-Off Ver
    Excel 2007
    Posts
    7

    Copying inconsistent header fields to matching rows

    I have a large Excel spreadsheet which is an export of a report from an Accounting software with over 10,000 customer records. I need to get this spreadsheet converted so every record has it's matching customer ID in each customer record/row. Unfortunately this report is formatted where it list the customer ID as a header and above an inconsistent number of records. Sometimes there is 1 record, other times there could be 30. To give you an example of the format, the first customer shows up in row 4 and in cell A4 it list the customer title "Customer:" and then list the Customer ID in cell D4 "123456". Then the first customer record is always listed 3 rows down where it always has the title "Record:" in this case the title in cell A7 and the first data showing in D7 with several more columns of data in that row 7 where I would like to add the Customer ID from cell D4 in each row that has the title "Record:" which for 1st customer only has 2 records, so rows 7 and 8. The next customer starts again in row 9 and has only one record in row 12. So the 3rd customer then shows in row 13 and it happens to have 17. So the next customer starts again in row 31, and first record in row 34. The pattern repeats. I'm at a lost here on what I could do outside of alot of manual work. Any ideas?

  2. #2
    Administrator FDibbins's Avatar
    Join Date
    12-29-2011
    Location
    Duncansville, PA USA
    MS-Off Ver
    Excel 7/10/13/16/365 (PC ver 2310)
    Posts
    52,929

    Re: Copying inconsistent header fields to matching rows

    Hi ed and welcome to the forum.

    Thats quite a mouthful there
    i would suggest you upload a sample work book, (all sensitive data removed), showing what data you are working with, a few examples of what your expected outcome is, and how you arrived at that
    To attach a file to your post,
    click advanced (next to quick post),
    scroll down until you see "manage file",
    click that and select "add files" (top right corner).
    click "select files" find your file, click "open" click "upload" click 'done" bottom right. click "submit reply"

    Once the upload is completed the file name will appear below the input boxes in this window.
    You can then close the window to return to the new post screen.
    1. Use code tags for VBA. [code] Your Code [/code] (or use the # button)
    2. If your question is resolved, mark it SOLVED using the thread tools
    3. Click on the star if you think someone helped you

    Regards
    Ford

  3. #3
    Registered User
    Join Date
    01-01-2013
    Location
    United States
    MS-Off Ver
    Excel 2007
    Posts
    7

    Re: Copying inconsistent header fields to matching rows

    I've attached an example file with only 3 customers. My expected outcome is at the bottom below my comments in yellow. Let me know if there are any questions on this. You will see I added another level of complexity than what is described below with a "Location" row that needs to have the Customer ID number tied to it as well.

    Quote Originally Posted by edkirk View Post
    I have a large Excel spreadsheet which is an export of a report from an Accounting software with over 10,000 customer records. I need to get this spreadsheet converted so every record has it's matching customer ID in each customer record/row. Unfortunately this report is formatted where it list the customer ID as a header and above an inconsistent number of records. Sometimes there is 1 record, other times there could be 30. To give you an example of the format, the first customer shows up in row 4 and in cell A4 it list the customer title "Customer:" and then list the Customer ID in cell D4 "123456". Then the first customer record is always listed 3 rows down where it always has the title "Record:" in this case the title in cell A7 and the first data showing in D7 with several more columns of data in that row 7 where I would like to add the Customer ID from cell D4 in each row that has the title "Record:" which for 1st customer only has 2 records, so rows 7 and 8. The next customer starts again in row 9 and has only one record in row 12. So the 3rd customer then shows in row 13 and it happens to have 17. So the next customer starts again in row 31, and first record in row 34. The pattern repeats. I'm at a lost here on what I could do outside of alot of manual work. Any ideas?
    Attached Files Attached Files

  4. #4
    Administrator FDibbins's Avatar
    Join Date
    12-29-2011
    Location
    Duncansville, PA USA
    MS-Off Ver
    Excel 7/10/13/16/365 (PC ver 2310)
    Posts
    52,929

    Re: Copying inconsistent header fields to matching rows

    wow that is quite a mess how are you importing/downloading the data in teh 1st place?

    If that is the only way you cat get the data, you will need some VBA code (which i suck at), to untagle the info.

    also, you dont need to use "reply with quote", just scroll down until you see the "quick reply" box

  5. #5
    Registered User
    Join Date
    01-01-2013
    Location
    United States
    MS-Off Ver
    Excel 2007
    Posts
    7

    Re: Copying inconsistent header fields to matching rows

    It's the only report and thus format we can get out the software it comes from. Yes, it is a mess. I have done some Python before in Excel so maybe there is something I can do with it. But still don't know how I'm going to deal with the indeterminate number of records for each customer.

  6. #6
    Administrator FDibbins's Avatar
    Join Date
    12-29-2011
    Location
    Duncansville, PA USA
    MS-Off Ver
    Excel 7/10/13/16/365 (PC ver 2310)
    Posts
    52,929

    Re: Copying inconsistent header fields to matching rows

    I'll see if some of the VBA experts can offer anything?

  7. #7
    Forum Expert mike7952's Avatar
    Join Date
    12-17-2011
    Location
    Florida
    MS-Off Ver
    Excel 2007, Excel 2016
    Posts
    3,520

    Re: Copying inconsistent header fields to matching rows

    Give this a try

    Please Login or Register  to view this content.
    Last edited by mike7952; 01-01-2013 at 07:20 PM.
    Thanks,
    Mike

    If you are satisfied with the solution(s) provided, please mark your thread as Solved.
    Select Thread Tools-> Mark thread as Solved.

  8. #8
    Forum Guru Pete_UK's Avatar
    Join Date
    12-31-2011
    Location
    Warrington, England
    MS-Off Ver
    Office 2019 (still learning)
    Posts
    24,723

    Re: Copying inconsistent header fields to matching rows

    Here's a manual/formula based method:

    Insert 3 new columns, A, B, C
    Put formulae in A2, B2, C2:
    A2: =IF(C2="","Delete","")
    B2: =IF(D1="Customer:",G1,B1)
    C2: =IF(D2="Location:",D2,IF(E2="Record:",E2,""))
    Copy formulae down to bottom of data
    Fix values of formulae in A, B, C
    Apply autofilter to column A, select "Delete"
    Highlight visible rows - click <Delete>
    Select All in filter Drop-down
    Delete columns D:E
    Delete column A
    Save As... to give file a different name

    This should be easy to record as a macro and then you can re-run it as often as you need.

    Hope this helps.

    Pete

  9. #9
    Registered User
    Join Date
    01-01-2013
    Location
    United States
    MS-Off Ver
    Excel 2007
    Posts
    7

    Re: Copying inconsistent header fields to matching rows

    Thanks Pete, that totally worked great. I have one issue still that I'm thinking I'm just going to ignore. Some of the names of the Records are too long and thus get put in the next row. In this current format, these will get deleted out but they should be added on to the name of cell above it. So in the example file I sent, the work "CORNERS" in row 31 should be added on the cell above in row 30 after the "LOCATORS5,6&". I'm guessing there really isn't a way to deal with this. Let me know if you have any ideas. Thanks again for the tip on the other.

  10. #10
    Forum Guru Pete_UK's Avatar
    Join Date
    12-31-2011
    Location
    Warrington, England
    MS-Off Ver
    Office 2019 (still learning)
    Posts
    24,723

    Re: Copying inconsistent header fields to matching rows

    Yes, it also happens on row 7. You can amend the formula in C2 to this:

    =IF(D2="Location:",D2,IF(E2="Record:",E2,IF(AND(E1="Record:",E2=""),"Check","")))

    Then you will have the word "Check" if that occurs, and this row would not be marked for deletion. You could then scan for that word and manually adjust the cells in column G on the rows above where it occurs (could be tedious), or you could introduce this formula in F2:

    =IF(C2="","",IF(C3="Check",G2&" "&G3,IF(C2="Check","",G2)))

    which will add the offending word(s) back in, although you might also like to amend the formula in A2 to this:

    =IF(OR(C2="",C2="Check"),"Delete","")

    so that the "Check" rows are marked for deletion. You will need to fix the values in column F at the same time as A:C, and then afterwards you can copy/paste Special values from F to G to retain the formats, and then delete the contents of column F.

    Hope this helps.

    Pete

  11. #11
    Registered User
    Join Date
    01-01-2013
    Location
    United States
    MS-Off Ver
    Excel 2007
    Posts
    7

    Re: Copying inconsistent header fields to matching rows

    Thanks again Pete, those additons worked great.

  12. #12
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Copying inconsistent header fields to matching rows

    If that takes care of your original query, please select Thread Tools from the menu above and mark the thread as solved. Thanks.
    _________________
    Microsoft MVP 2010 - Excel
    Visit: Jerry Beaucaire's Excel Files & Macros

    If you've been given good help, use the icon below to give reputation feedback, it is appreciated.
    Always put your code between code tags. [CODE] your code here [/CODE]

    ?None of us is as good as all of us? - Ray Kroc
    ?Actually, I *am* a rocket scientist.? - JB (little ones count!)

+ 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