+ Reply to Thread
Results 1 to 6 of 6

Returning Non-Zero Vlookup/match/index

  1. #1
    Registered User
    Join Date
    10-01-2018
    Location
    Orlando, Florida
    MS-Off Ver
    2016
    Posts
    3

    Returning Non-Zero Vlookup/match/index

    I have a selection of data (This is an example I'm making from thousands of lines). I'm using code to take the 'Full Value' , if it starts with some select letter combinations "PRO" "BSA" or "PQR" and then pulling the first seven characters. I did this using IF() and LEFT() functions. The problem is many of the 'Full Value' items are under the same 'Case Number.' If this is the case they should have the same 'abbreviated value', even though the 'Full Value' is something random and doesn't start with "PRO" "BSA" or "PQR."

    The formula I had for this was:

    Please Login or Register  to view this content.
    The problem with the VLOOKUP section is that is pulls the first value and I can't re-arrange the data so if the first item is "Water" as in this example it returns zero or an incorrect value.

    If the Full value does not begin with any of the three listen letters I need it to return the same "abbreviated value" for a matching "Case Number" that is non-zero. Also if there happens to be no matching "Case Number" it will return blank.

    Here is an example of some code that is having issues. Column D shows the correct values highlighted in red are the two that are having problems. The formula is in column B. It won't; it won't let me attach the file

    Excel.PNG
    Last edited by leomiah; 10-01-2018 at 03:25 PM.

  2. #2
    Forum Expert 63falcondude's Avatar
    Join Date
    08-22-2016
    Location
    USA
    MS-Off Ver
    365
    Posts
    6,266

    Re: Returning Non-Zero Vlookup/match/index

    Try this in B2:

    =LEFT(INDEX(C$2:C$23,MATCH(1,(A$2:A$23=A2)*((LEFT(C$2:C$23,3)="PRO")+(LEFT(C$2:C$23,3)="BSA")+(LEFT(C$2:C$23,3)="PQR")),0)),7) Ctrl Shift Enter

  3. #3
    Registered User
    Join Date
    10-01-2018
    Location
    Orlando, Florida
    MS-Off Ver
    2016
    Posts
    3

    Re: Returning Non-Zero Vlookup/match/index

    Quote Originally Posted by 63falcondude View Post
    Try this in B2:

    =LEFT(INDEX(C$2:C$23,MATCH(1,(A$2:A$23=A2)*((LEFT(C$2:C$23,3)="PRO")+(LEFT(C$2:C$23,3)="BSA")+(LEFT(C$2:C$23,3)="PQR")),0)),7) Ctrl Shift Enter
    This worked! Had to modify it but I tested it in the full code and it worked just fine.

    Luckily I don't need to do this, but I am curious, since this is a CSE function, how would you get it to return a value besides #N/A for cells that didn't have a return, say for instance with my original example I had some full value "water" and the case number was also random, it wouldn't pull an abbreviated value, could I get that to return something other than #N/A?

    Thank you I'll mark this as solved!

  4. #4
    Forum Expert 63falcondude's Avatar
    Join Date
    08-22-2016
    Location
    USA
    MS-Off Ver
    365
    Posts
    6,266

    Re: Returning Non-Zero Vlookup/match/index

    could I get that to return something other than #N/A?
    Sure. You can wrap it in IFERROR like this:

    =IFERROR(LEFT(INDEX(C$2:C$23,MATCH(1,(A$2:A$23=A2)*((LEFT(C$2:C$23,3)="PRO")+(LEFT(C$2:C$23,3)="BSA")+(LEFT(C$2:C$23,3)="PQR")),0)),7),"") Ctrl Shift Enter

    This will return blank instead of #N/A.

  5. #5
    Registered User
    Join Date
    10-01-2018
    Location
    Orlando, Florida
    MS-Off Ver
    2016
    Posts
    3

    Re: Returning Non-Zero Vlookup/match/index

    Quote Originally Posted by 63falcondude View Post
    This will return blank instead of #N/A.
    Could have sworn this didn't work when I tried it yesterday, might not have been hitting CSE, worked this time though! So thank you again.

  6. #6
    Forum Expert 63falcondude's Avatar
    Join Date
    08-22-2016
    Location
    USA
    MS-Off Ver
    365
    Posts
    6,266

    Re: Returning Non-Zero Vlookup/match/index

    You're welcome. Happy to help.

+ 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. Returning multiple distinct/repeating values for vlookup or index-match
    By amatvien in forum Excel Formulas & Functions
    Replies: 9
    Last Post: 08-21-2018, 01:14 PM
  2. [SOLVED] Returning Multiple Rows of Data (VLOOKUP/INDEX MATCH)
    By aglasier in forum Excel Formulas & Functions
    Replies: 7
    Last Post: 03-30-2017, 12:49 PM
  3. Index/Match or VLookup returning Multiple Results
    By Stoppeh in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 08-21-2014, 08:31 PM
  4. Replies: 6
    Last Post: 03-01-2014, 11:56 PM
  5. Replies: 0
    Last Post: 05-15-2013, 05:05 AM
  6. [SOLVED] VLOOKUP (or Index/Match) across four columns -- and returning multiple matches
    By rcasey in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 04-11-2013, 05:20 PM
  7. [SOLVED] INDEX - MATCH - VLOOKUP - returning missing reference
    By njuneardave in forum Excel General
    Replies: 2
    Last Post: 06-27-2006, 02:50 PM

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