+ Reply to Thread
Results 1 to 13 of 13

Expanded Vlookup Issue

  1. #1
    Registered User
    Join Date
    01-16-2009
    Location
    Texas
    MS-Off Ver
    2013, 2015, 2016
    Posts
    43

    Expanded Vlookup Issue

    Ok here is the deal. I have a form I am trying to work on.

    Pretty Much, It is organized by month. I have a drop down I want to have all the months. Next to them I have cells titled Name, Anniversary, Birthday.

    So what I want, is when I pull January from the drop down, it pulls ALL the Names of people who have Birthdays or Anniversarys into the cells.

    With VLOOKUP I cannot get it to give me more than one outcome. So if i pick January, it simply Displays the first listing.

    Here is an example attached.
    Attached Files Attached Files
    Last edited by melegaunt; 01-25-2009 at 01:25 AM.

  2. #2
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492
    There's a UDF called VLOOKUPS that does what you want. I installed it into your sheet and activated it in the range.

    http://home.pacbell.net/beban/

    The code for the functions are called:

    VLookups
    ArrayCountIf
    ArrayDimensions
    MakeArray

    They are copied into a standard module. Then you enter a standard VLOOKUP type formula:

    =VLOOKUPS($H$4,$B$4:$E$17,2)

    When you press Enter, a message will appear in the cell telling you how many
    cells downward you need to select.

    Highlight the cell and drag down enough cells below to complete the requested number (or more if you want expansion room), press F2, then CTRL-SHIFT-ENTER to activate the array.
    Attached Files Attached Files
    Last edited by JBeaucaire; 01-23-2009 at 04:16 AM.
    _________________
    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!)

  3. #3
    Forum Guru DonkeyOte's Avatar
    Join Date
    10-22-2008
    Location
    Northumberland, UK
    MS-Off Ver
    O365
    Posts
    21,531
    The below is meant as an alternative to using UDF and also because I wasn't entirely sure I followed the request, ie I wasn't entirely sure if for Jan you wanted to return only those records where Anniversary occurred in Jan (per value in B) or when either of Month of Anniversary / Month of Birth equated to Jan ?

    I've attached an example file doing both... helper cells are in Green.

    I would add however that for the more complex scenario (either / or) should you have multiple records with same birthday date or same anniversary date you would still run into difficulty regards the listing of duplicates.

    EDIT: you could of course use a Pivot Table with Month as a Page Field / Report Filter (pre 07 / 07 terminology)
    Attached Files Attached Files
    Last edited by DonkeyOte; 01-23-2009 at 06:10 AM.

  4. #4
    Registered User
    Join Date
    01-16-2009
    Location
    Texas
    MS-Off Ver
    2013, 2015, 2016
    Posts
    43
    Awesome Thanks!

  5. #5
    Registered User
    Join Date
    01-16-2009
    Location
    Texas
    MS-Off Ver
    2013, 2015, 2016
    Posts
    43
    Hmm seems my example isnt working right.
    The array thing works wonderfully. But I believe i set the sheet up wrong.

    The end result I wanted, was to pick January, and all the january Birthdays appear, and all the january anniversaries appear. Either one would qualify to show up.

    But since I am using the Phrase "January" I think it doenst know how to look it up correctly. As it is omitting people who have Jan anniversaries.

  6. #6
    Forum Guru DonkeyOte's Avatar
    Join Date
    10-22-2008
    Location
    Northumberland, UK
    MS-Off Ver
    O365
    Posts
    21,531
    Quote Originally Posted by melegaunt View Post
    Hmm seems my example isnt working right.
    The array thing works wonderfully. But I believe i set the sheet up wrong.

    The end result I wanted, was to pick January, and all the january Birthdays appear, and all the january anniversaries appear. Either one would qualify to show up.

    But since I am using the Phrase "January" I think it doenst know how to look it up correctly. As it is omitting people who have Jan anniversaries.
    Did you review the file I posted -- in particular I would draw your attention to the setup in N:P which was to show how you could pull the data based on the above scenario.

  7. #7
    Registered User
    Join Date
    01-16-2009
    Location
    Texas
    MS-Off Ver
    2013, 2015, 2016
    Posts
    43
    Quote Originally Posted by DonkeyOte View Post
    Did you review the file I posted -- in particular I would draw your attention to the setup in N:P which was to show how you could pull the data based on the above scenario.


    Actually I am trying to wrap my head around this still. I honestly have the file you made and the file I am working with side by side. There is alot of stuff implemented into your example. I just recently started getting into the more advanced stuff in Excel. The Match,Index combination of things I am having some trouble following.

    Another Issue I have is that they have reformatted the file I am working on, so the information is appearing slightly different.

    Now there are columns for:
    Team Member Name
    Team Name
    Date of Birth
    Anniversary

    Here is the example of the new format attached
    Keep in mind this list of names will probably be about 1000 names long.


    By the way, thanks for all of your help already.
    Attached Files Attached Files

  8. #8
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898
    Another alternative... with no helper columns....

    This formula in F1 counts total records that have month from drop down in either the Birthday or the Anniversary or Both.

    Please Login or Register  to view this content.
    This formula in H2, begins to extract the matching information and pulls only the number of records indicated by the formula in F1:

    Please Login or Register  to view this content.
    the above formula is an array formula and must be confirmed with CTRL+SHIFT+ENTER keys instead of just ENTER.. you will see { } brackets appear around the formula...then copy it down as far as you want and across the other relevant number of columns.

    If you adjust the ranges to suit a large database, you will need to reconfirm the formula with the CSE keys and then copy down and across again.

    See attached.
    Attached Files Attached Files
    Where there is a will there are many ways.

    If you are happy with the results, please add to the contributor's reputation by clicking the reputation icon (star icon) below left corner

    Please also mark the thread as Solved once it is solved. Check the FAQ's to see how.

  9. #9
    Registered User
    Join Date
    01-16-2009
    Location
    Texas
    MS-Off Ver
    2013, 2015, 2016
    Posts
    43

    Cool

    Well thats exactly what I am after!

    Now I will have to mull over it for awhile to make sure I understand all of it and to Anniversary/Birthday cells not show a number when they dont apply to the date range.

    Thank you again for all of this. It looks like I need alot more practice with arrays.

  10. #10
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898
    Here's a thread using a similar formula and I try to explain how it works...

    http://www.excelforum.com/excel-work...ml#post1833718

    The Countif() part is replaced by the Sumproduct() function reference to F1 in your sheet... it makes for a little better efficiency to have the Counting formula in a separate cell so that it is calculated once and not every time the array formula is copied to another cell.

    The + sign between arguments is an array formula's way of saying "OR"... so if one argument or the other is true, then count.

    see if it helps..

    If you need further clarification please ask.

  11. #11
    Registered User
    Join Date
    01-16-2009
    Location
    Texas
    MS-Off Ver
    2013, 2015, 2016
    Posts
    43
    With the current setup, How do I make it so that the dates that dont apply dont show up?
    This would be similar to your original example.
    If I pick January, and a person has a birthday in January but an anniversary in March, the anniversary wont show up. It just shows the Person, Team, and Birthday, with an empty Anniversary cell.

    I was trying to think of a clever conditional formatting for it, but have had nothing but failed attempts. LOL!

  12. #12
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898
    Actually, we can use a much simplified and more efficient non-array formula to gather all the remaining data after you extract the names in column H.

    So replace the formulas in columns I, J, K with these, respectively:

    Please Login or Register  to view this content.
    Please Login or Register  to view this content.
    Please Login or Register  to view this content.
    they only need normal ENTER to confirm...

    Then copy them down.

    You should get the same info, except only show January dates in relevant columns...
    Attached Files Attached Files

  13. #13
    Registered User
    Join Date
    01-16-2009
    Location
    Texas
    MS-Off Ver
    2013, 2015, 2016
    Posts
    43

    Re: Expanded Vlookup Issue

    Amazing, thank you for all the help!

+ 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