+ Reply to Thread
Results 1 to 7 of 7

Which is best: Formula, Pivots, VBA, or query?

  1. #1
    Registered User
    Join Date
    11-14-2018
    Location
    New Jersey
    MS-Off Ver
    365
    Posts
    4

    Which is best: Formula, Pivots, VBA, or query?

    Hi everyone, i'm having difficulty deciding how to approach my problem here. I have two colums of data, the first w/ an id, and the second having a comma-delimited string of other ids (see image w/ five rows of data). What i need to do is get get rid of the csv string, and create the data into two columns, each with no more than 1 id therein, as within the image w/ 16 rows of data.

    Basically, i need one record for each Track_id to PSplit_id relationship

    I'm getting nowhere w/ functions, as they don't seem to create rows of data, and I'm completely unfamiliar with pivots (someone tome me this could help). I'm starting to think i'll need to import the data into an Access table, and run a query to get the results how i need, then import the query results back into Excel. Is this the best approach, or is it possible without having to resort to Access?

    Any advice is appreciate, thanks!
    Chris
    Attached Images Attached Images
    Last edited by Chris802; 11-14-2018 at 01:19 PM.

  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: Formula, Pivots, VBA, or query?

    Pictures of excel sheets aren't much use... non editable. An excel sheet is strongly preferred. But... here's one i made earlier.

    In C2, copied down:
    =IFERROR(INDEX($A$2:$A$4,MATCH(0,INDEX(--(COUNTIF($C$1:C1,$A$2:$A$4)=LEN(B$2:B$4)-LEN(SUBSTITUTE(B$2:B$4,",",""))+1),0),0)),"")

    In D2, copied down:
    =IF(C2="","",TRIM(MID(SUBSTITUTE(","&VLOOKUP(C2,A$2:B$4,2,0),",",REPT(" ",99)),COUNTIF(C$2:C2,C2)*99,99)))
    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

  3. #3
    Registered User
    Join Date
    11-14-2018
    Location
    New Jersey
    MS-Off Ver
    365
    Posts
    4

    Re: Formula, Pivots, VBA, or query?

    Wow Glenn, this is almost working for me, however only for the first 3 rows in my spreadsheet. There's actually about 500 rows of data. I've tried fiddling w/ the formulas a bit to expand the ranges within the INDEX, COUNT, and SUBSTITUTE functions however when i do it just gets hung up on the Track_id in the third row of data, 1734

    I didn't know that we were allowed to attach .xlsx files to the forum but here's what i am working with so you can see the big picture. Thanks!
    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: Which is best: Formula, Pivots, VBA, or query?

    You need to adjust the ranges to suit your data!!! I only had 3 rows (A2:A4 and B2:B4). You will have to adjust it to suit you.

    HOWEVER... with a lot of rows it will be slow. So. It might make more sense to break it up into several blocks of data that will put your processors under less strain.

  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: Which is best: Formula, Pivots, VBA, or query?

    Here's your file... in one block. It took about 5 mins to run on my battered old laptop.
    Attached Files Attached Files

  6. #6
    Registered User
    Join Date
    11-14-2018
    Location
    New Jersey
    MS-Off Ver
    365
    Posts
    4

    Re: Which is best: Formula, Pivots, VBA, or query?

    Wow Glen, thank you so much - this is perfect! I'm taking a solid look at the formula (because i also want to learn, not just have someone do it for me) and while i see the expanded range of cells. I had tried to do that before but perhaps i missed one of them. Regardless, this is an amazing Formula to me. I've dabbles quite a bit with the text functions, however ones such as VLOOKUP and MATCH are really new and somewhat confusing to me. Having this example however, understanding the way it works w/ the file above and the results is certainly going to help me learn more about these functions. Thanks again!

  7. #7
    Forum Expert Olly's Avatar
    Join Date
    09-10-2013
    Location
    Darlington, UK
    MS-Off Ver
    Excel 2016, 2019, 365
    Posts
    6,284

    Re: Which is best: Formula, Pivots, VBA, or query?

    Really simple with Power Query (Get & Transform Data).

    Format your source data as a table, then use the following query:

    Please Login or Register  to view this content.
    The last step of the code looks complex, but was easily achieved by simply selecting the Pslit_ids column, and clicking Split Column > By Delimiter, selecting Cutom > ", ", and in Advanced options choose Rows

    Edit: attched example file. Never mind 5 minutes to run, this is virtually instant.
    Attached Files Attached Files
    Last edited by Olly; 12-10-2018 at 12:40 PM.
    let Source = #table({"Question","Thread", "User"},{{"Answered","Mark Solved", "Add Reputation"}}) in Source

    If I give you Power Query (Get & Transform Data) code, and you don't know what to do with it, then CLICK HERE

    Walking the tightrope between genius and eejit...

+ 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. Can I use Power Query to pull from Pivots in multiple workbooks?
    By jomili in forum Excel Programming / VBA / Macros
    Replies: 0
    Last Post: 05-31-2016, 10:24 AM
  2. Excel formula to overcome Pivots
    By Parth007 in forum Excel Programming / VBA / Macros
    Replies: 1
    Last Post: 11-20-2015, 12:04 PM
  3. Replies: 0
    Last Post: 10-18-2013, 11:35 AM
  4. [SOLVED] Insert Slicer for Pivots Only or can we use it for Charts without Pivots?
    By eldwardo in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 10-02-2013, 04:27 AM
  5. Connecting a Web Query to Pivots in Another Workbook
    By juniperjacobs in forum Excel Programming / VBA / Macros
    Replies: 0
    Last Post: 08-20-2012, 09:51 AM
  6. Replies: 2
    Last Post: 11-22-2006, 06:54 AM
  7. I would like to build macro's to do pivots or part of pivots
    By Todd F. in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 07-29-2005, 11:05 AM

Tags for this Thread

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