+ Reply to Thread
Results 1 to 10 of 10

Vlookup (possibly) help

  1. #1
    Registered User
    Join Date
    11-19-2020
    Location
    London, England
    MS-Off Ver
    version 1902
    Posts
    5

    Vlookup (possibly) help

    Hi,

    I am stuck on a formula and after some help please.

    I am after a table lookup based on 2 criteria, one being a date range (this is where I am having problems). Example is attached. I want column D to complete using the lookup table. The criteria is for column B to match column J and column C to be within the date range in K and L, giving the result from column M. So the result in cell D4 should be 2019. Exactly the same principle for column E.
    Capture.PNG
    How do I do this?

    Thanks.
    Attached Files Attached Files
    Last edited by benog; 11-19-2020 at 04:15 PM.

  2. #2
    Forum Expert Sam Capricci's Avatar
    Join Date
    06-14-2012
    Location
    Palm Harbor, Florida
    MS-Off Ver
    16.83 for Mac MS 365
    Posts
    8,480

    Re: Vlookup (possibly) help

    This is one way to do that, I hand entered the data into a workbook before you uploaded your workbook so I don't know if it matches your workbook but it matches the snapshot in your post...
    in cell D4 and dragged down... =SUMPRODUCT(($I$4:$I$9<=C4)*($H$4:$H$9=B4)*($J$4:$J$9>=C4),$K$4:$K$9)
    in cell E4 and dragged down... =SUMPRODUCT(($I$4:$I$9<=C4)*($H$4:$H$9=B4)*($J$4:$J$9>=C4),$L$4:$L$9)
    However if you have multiples that fit the criteria it will sum them.
    Make contributors happy, click on the "* Add Reputation" as a way to say thank you.
    Sam Capricci

  3. #3
    Registered User
    Join Date
    11-19-2020
    Location
    London, England
    MS-Off Ver
    version 1902
    Posts
    5

    Re: Vlookup (possibly) help

    Thanks Sam, that is a great help and works perfectly!

  4. #4
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    79,417

    Re: Vlookup (possibly) help

    If that takes care of your original question, please select Thread Tools from the menu link above and mark this thread as SOLVED.

    Next time, please give your thread a more detailed title. Thanks.
    Ali


    Enthusiastic self-taught user of MS Excel who's always learning!
    Don't forget to say "thank you" in your thread to anyone who has offered you help.
    You can reward them by clicking on * Add Reputation below their user name on the left, if you wish.

    Forum Rules (updated August 2023): please read them here.

  5. #5
    Registered User
    Join Date
    11-19-2020
    Location
    London, England
    MS-Off Ver
    version 1902
    Posts
    5

    Re: Vlookup (possibly) help

    Hi Sam,

    Sorry, just a quick question please. When I start the reference in column K with a letter, instead of a number, the formula isn't returning a value. Is there a way around this?

  6. #6
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    43,900

    Re: Vlookup (possibly) help

    Q1. Why would you start the DATE with a letter insted of a number?

    Q2. Post a sheet showing a representative sample of the REAL data in column K, not an oversimplified version.
    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.

    Temporary addition of accented to illustrate ongoing problem to the TT: L? fh?ile P?draig sona dhaoibh

  7. #7
    Registered User
    Join Date
    11-19-2020
    Location
    London, England
    MS-Off Ver
    version 1902
    Posts
    5

    Re: Vlookup (possibly) help

    Apologies Glenn, that is my mistake, I was meant to say column L.

    Attached sheet.
    Attached Files Attached Files

  8. #8
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    79,417

    Re: Vlookup (possibly) help

    If this is still unsolved, you need to remove the solved tag!

  9. #9
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    43,900

    Re: Vlookup (possibly) help

    OK. Here is a revised formula:

    In D4, copied across and down:

    =INDEX(K$4:K$9,MATCH(1,INDEX((($H$4:$H$9=$B4)*($K$4:$K$9=YEAR($C4))),0),0))

    see sheet.
    Attached Files Attached Files

  10. #10
    Registered User
    Join Date
    11-19-2020
    Location
    London, England
    MS-Off Ver
    version 1902
    Posts
    5

    Re: Vlookup (possibly) help

    Thanks Glenn, very helpful.

+ 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. Stuck! Unsure what I need (possibly vlookup)
    By jostre in forum Excel General
    Replies: 6
    Last Post: 03-09-2016, 04:58 PM
  2. Using vlookup and possibly if to populate cells
    By jaffacakes in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 03-09-2016, 08:27 AM
  3. If or possibly VLookup formula help
    By LRGy in forum Excel Formulas & Functions
    Replies: 7
    Last Post: 02-11-2016, 08:58 AM
  4. Vlookup possibly
    By lian.cragg in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 03-20-2011, 02:50 PM
  5. Replies: 2
    Last Post: 04-05-2010, 05:13 PM
  6. Vlookup across sheets, nested Vlookup possibly?
    By paid2mkgrlspanic in forum Excel Programming / VBA / Macros
    Replies: 16
    Last Post: 06-09-2009, 05:10 PM
  7. Possibly vlookup
    By Carleilam in forum Excel General
    Replies: 2
    Last Post: 02-03-2008, 06:03 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