+ Reply to Thread
Results 1 to 6 of 6

Compile list based on drop-down menu pick

  1. #1
    Registered User
    Join Date
    10-15-2012
    Location
    Michigan, USA
    MS-Off Ver
    Excel 2010
    Posts
    22

    Compile list based on drop-down menu pick

    I would like to report data from one area of my worksheet into other separate areas of the worksheet based on the value of a drop-down menu pick. I don't want to move the data, just compile separate lists that report the data. I have attached an example to illustrate what I am looking for. Lastly, the original data has to remain unchanged and unsorted, since other users will be adding and removing lines from this list, and its order must be preserved.

    There is probably an easy way to do this, I just don't know what it is. Thanks!

    Sorting list example.xlsx

  2. #2
    Forum Guru
    Join Date
    08-05-2004
    Location
    NJ
    MS-Off Ver
    365
    Posts
    13,582

    Re: Compile list based on drop-down menu pick

    Not sure exactly what you are looking for but this will separate your data into the 3 lists.
    1. In E10 dragged down
    =D10&COUNTIF($D$10:D10,D10)
    This gives you unique identifiers for each list. You can hide this column if you like

    2. In G6 dragged down

    =IF(COUNTIF($D$10:$D$21,"A")>=ROW(A1),INDEX($B$10:$B$21,MATCH("A"&ROW(A1),$E$10:$E$21,0)),"")

    The COUNTIF> ROW(1) just counts how many are in list A and as you drag that down, it'll put blanks ("")
    INDEX(.... returns a value from Col B that is the same # of rows down as "A" &ROW(A1) or "A1"

    3. In H6 dragged down
    =IF(COUNTIF($D$10:$D$21,"A")>=ROW(A1),INDEX($C$10:$C$21,MATCH("A"&ROW(A1),$E$10:$E$21,0)),"")
    same as above except looking at Col C

    The equations in the other tables are similar.

    Questions?
    Attached Files Attached Files
    ChemistB
    My 2?

    substitute commas with semi-colons if your region settings requires
    Don't forget to mark threads as "Solved" (Edit First post>Advanced>Change Prefix)
    If I helped, Don't forget to add to my reputation (click on the little star at bottom of this post)

    Forum Rules: How to use code tags, mark a thread solved, and keep yourself out of trouble

  3. #3
    Registered User
    Join Date
    10-15-2012
    Location
    Michigan, USA
    MS-Off Ver
    Excel 2010
    Posts
    22

    Re: Compile list based on drop-down menu pick

    Thanks! That is precisely what I am looking for. Just out of curiosity, did you use "ROW(A1)" because it was blank? The COUNTIF is counting every cell in the range that is greater than the blank cell A1, right?

  4. #4
    Forum Guru
    Join Date
    08-05-2004
    Location
    NJ
    MS-Off Ver
    365
    Posts
    13,582

    Re: Compile list based on drop-down menu pick

    Nope, it works like this
    (COUNTIF($D$10:$D$21,"A")>=ROW(A1)
    COUNTIF counts every cell in D10:D20 that equals A. That's a constant
    ROW(A1) = 1. However, since I didn't apply an anchor (i.e $A$1) it changes as we copy it down so ROW(A2) = 2 and so forth

    =IF(COUNTIF($D$10:$D$21,"A")>=ROW(A1),INDEX($B$10:$B$21,MATCH("A"&ROW(A1),$E$10:$E$21,0)),"")
    So as soon as the ROW portion becomes greater than the # of "A's" in your range, it starts to populate your cell with blanks ("")
    This is done to prevent errors when applying your INDEX formula.
    Did that answer your question?

  5. #5
    Registered User
    Join Date
    10-15-2012
    Location
    Michigan, USA
    MS-Off Ver
    Excel 2010
    Posts
    22

    Re: Compile list based on drop-down menu pick

    Yep, thanks for the lesson, I appreciate it!

  6. #6
    Forum Expert Cutter's Avatar
    Join Date
    05-24-2004
    Location
    Ontario,Canada
    MS-Off Ver
    Excel 2010
    Posts
    6,451

    Re: Compile list based on drop-down menu pick

    @ Excel white-belt

    Welcome to the forum.

    Based on your last post it seems that you are satisfied with the solution(s) you've received but you haven't marked your thread as SOLVED. I'll do that for you now but please keep in mind for your future threads that Rule #9 requires you to do that yourself. If your problem has not been solved you can use Thread Tools (located above your first post) and choose "Mark this thread as unsolved".
    Thanks.

    Also, as a new member of the forum, you may not be aware that you can thank those who have helped you by clicking the small star icon located in the lower left corner of the post in which the help was given. By doing so you can add to the reputation(s) of those who helped.

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

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