+ Reply to Thread
Results 1 to 15 of 15

Formula returning first entry only

  1. #1
    Registered User
    Join Date
    02-06-2018
    Location
    London, England
    MS-Off Ver
    2007
    Posts
    22

    Formula returning first entry only

    Hi,

    I have the following formula

    =IFERROR(INDEX(Backorders!$G$2:$G$1000,MATCH(D10&F10,Backorders!$B$2:$B$1000&Backorders!$H$2:$H$1000,0)),"")

    which returns the "Quantity" based on column B (Job No) and column H (Part Number)

    This works great if there is only 1 in the list but if there is 2 it only returns the first entry and not the second

    If I enter the first job number and part number my formula returns ok, but I then want to return the same part number on the same job (a 2nd entry) my formula only returns the same 1st entry

    is there a way to adapt and be able to return both lines (or more)

    hope that makes more sense

    Thanks

  2. #2
    Forum Expert ben_hensel's Avatar
    Join Date
    01-26-2012
    Location
    Northeast USA
    MS-Off Ver
    Office 365
    Posts
    2,043

    Re: Formula returning first entry only

    Quote Originally Posted by dotxls View Post
    ...MATCH(D10&F10, Backorders!$B$2:$B$1000&Backorders!$H$2:$H$1000, 0)...
    Doesn't this return the #VALUE! error...? Specifically the part where MATCH is looking in two ranges concatenated together.

    I mean, if it's not, I'd be curious to see that spreadsheet.


    More generally,
    INDEX(MATCH), like all lookup operations, returns one-and-only-one result. That's how they are designed. Doing something else requires fundamentally a different formula construction -- and you need to know before hand what the upper limit of your results are (eg, 10 or less).

    But usually for this kind of operation, you're better off just pulling into a Pivot Table, and filtering.
    Click the [* Add Reputation] Button to thank people for help!
    Post Attachment: Click [Go Advanced] under the reply box; then click [Manage Attachments] to launch the attachments dialogue.
    Mark Thread Solved: Go to the top of the first post; Select [Thread Tools] dropdown; Pick the [Mark thread as Solved] option.

  3. #3
    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,407

    Re: Formula returning first entry only

    MATCH can be used like this, Ben.

    Dotxls - will you please attach a sample Excel workbook?

    1. Make sure that your sample data are REPRESENTATIVE of your real data. The use of unrepresentative data is very frustrating and can lead to long delays in reaching a solution.

    2. Make sure that your desired results are also shown (mock up the results manually).

    3. Make sure that all confidential data is removed or replaced with dummy data first (e.g. names, addresses, E-mails, etc.).

    4. Try to avoid using merged cells as they cause lots of problems.

    Unfortunately the attachment icon doesn't work at the moment, so to attach an Excel file you have to do the following: just before posting, scroll down to Go Advanced and then scroll down to Manage Attachments. Now follow the instructions at the top of that screen.

    Please pay particular attention to point 2 (above): without an idea of your intended outcomes, it is often very difficult to offer appropriate advice.
    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.

  4. #4
    Administrator FDibbins's Avatar
    Join Date
    12-29-2011
    Location
    Duncansville, PA USA
    MS-Off Ver
    Excel 7/10/13/16/365 (PC ver 2310)
    Posts
    52,917

    Re: Formula returning first entry only

    @ Ben, that is probably ARRAY entered (at least, it should be)

    @ dot - the MATCH part is what is finding what you are looking for (the INDEX just returns the data from the relevant row), and MATCH will always only ever return the 1st match it finds - it then stops looking.

    You will need something like the INDEX/SMALL/IF array combo for this, but, as Ali suggested, we would need to see some sample data (and expected outcome) to help further
    1. Use code tags for VBA. [code] Your Code [/code] (or use the # button)
    2. If your question is resolved, mark it SOLVED using the thread tools
    3. Click on the star if you think someone helped you

    Regards
    Ford

  5. #5
    Forum Expert ben_hensel's Avatar
    Join Date
    01-26-2012
    Location
    Northeast USA
    MS-Off Ver
    Office 365
    Posts
    2,043

    Re: Formula returning first entry only

    Quote Originally Posted by FDibbins View Post
    @ Ben, that is probably ARRAY entered (at least, it should be)
    ugh, of course. I should have figured that!

  6. #6
    Registered User
    Join Date
    02-06-2018
    Location
    London, England
    MS-Off Ver
    2007
    Posts
    22

    Re: Formula returning first entry only

    Hi all,

    yes indeed it is an array formula

    Not sure how to show more detail?

  7. #7
    Registered User
    Join Date
    02-06-2018
    Location
    London, England
    MS-Off Ver
    2007
    Posts
    22

    Re: Formula returning first entry only

    HA275931 ABC Cars YX62 AAA 8583 20/02/18 2 95200156 Adhesive,
    HA275931 ABC Cars YX62 AAA 8583 22/02/18 4 95200156 Adhesive,
    HA275931 ABC Cars YX62 AAA 8583 23/02/18 4 95200156 Adhesive,
    HA275931 ABC Cars YX62 AAA 8583 23/02/18 2 66902027 Battery Flap Lock
    HA275931 ABC Cars YX62 AAA 8583 23/02/18 1 93112302 Battery Flap Hinge

    this is a shortened version of a long list

    by typing
    HA275931 in (column B) and 95200156 in (column H) I would like the formula to return the first "quantity" ie "2"
    but then if I type
    HA275931 in (column B) and 95200156 in (column H) I would like the formula to return the second "quantity" ie "4"
    but then if I type
    HA275931 in (column B) and 95200156 in (column H) I would like the formula to return the third "quantity" ie "4"

    etc etc

    many thanks

  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,407

    Re: Formula returning first entry only

    Where is the sample file? Attach that here, please.

  9. #9
    Registered User
    Join Date
    02-06-2018
    Location
    London, England
    MS-Off Ver
    2007
    Posts
    22

    Re: Formula returning first entry only

    please find attached
    Last edited by dotxls; 03-02-2018 at 03:51 PM.

  10. #10
    Registered User
    Join Date
    02-06-2018
    Location
    London, England
    MS-Off Ver
    2007
    Posts
    22

    Re: Formula returning first entry only

    Hi AliGW,

    was you able to look at my sample file?

    if possible can you remove this from the thread after you have seen it please

    Many thanks

  11. #11
    Forum Guru
    Join Date
    08-28-2014
    Location
    USA
    MS-Off Ver
    Excel 2019
    Posts
    17,428

    Re: Formula returning first entry only

    I believe that this array entered formula* will do what you want.
    1) Select cell E10 on the 'Chase Details' sheet,
    2) Paste the following formula into the formula bar:
    Formula: copy to clipboard
    Please Login or Register  to view this content.

    3) Simultaneously press the Ctrl, Shift and Enter keys,
    4) Copy down the column.
    Let us know if you have any questions.
    Consider taking the time to add to the reputation of everybody that has taken the time to respond to your query.

  12. #12
    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,407

    Re: Formula returning first entry only

    @Dotxls - you can remove attachments from your post yourself by editing the post and going advanced to manage attachments.

    Never post sample files containing sensitive data: always desensitise first. If there is no sensitive data, then leave the attachment for others to look at. This forum is a database of help which will be rendered incomplete if you remove vital bits of the problem and solution.

  13. #13
    Registered User
    Join Date
    02-06-2018
    Location
    London, England
    MS-Off Ver
    2007
    Posts
    22

    Re: Formula returning first entry only

    Hi JeteMc,

    that works perfectly, many thanks

    Is it possible to run through the logic on this formula so I can understand a bit more

    Many thanks for your help

  14. #14
    Forum Guru
    Join Date
    08-28-2014
    Location
    USA
    MS-Off Ver
    Excel 2019
    Posts
    17,428

    Re: Formula returning first entry only

    Inside the SMALL function the first IF checks to for values in column B of the 'Update' sheet that match the corresponding value, to the cell with the formula, in column D. The second IF checks to for values in column H of the 'Update' sheet that match the corresponding value in column F. Once that is done the COUNTIFS counts the times that all of the values (down to that point) in column D are the same as the corresponding value in column D and the times that all of the values (down to that point) in column F are the same as the corresponding value in column F. That count is passed as the K argument value to the SMALL function and in turn the INDEX function picks the nth smallest ROW from column G on the 'Update' sheet. I hope that makes sense.
    One good way to see what the formula is doing is to select cell E12 and use the 'Evaluate Formula' tool found on the 'Formulas' tab. Notice that just before yielding the value of 4, the formula displays it is INDEXing the 2nd row of the range G2:G1000 on the 'Update' sheet. When you check the value in that second row, cell G3, you see that it is 4.
    If you are satisfied with the outcome of this thread, please take a moment to mark it as 'Solved' using the thread tools drop down in the ribbon above your first post.
    Let us know if you have any questions.
    I hope that you have a blessed day.

  15. #15
    Registered User
    Join Date
    02-06-2018
    Location
    London, England
    MS-Off Ver
    2007
    Posts
    22

    Re: Formula returning first entry only

    That's great many thanks JeteMc

+ 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. [SOLVED] VLOOKUP - returning value with last entry in a table
    By nielsb in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 11-15-2015, 04:33 AM
  2. [SOLVED] Sumproduct Formula - Returning result in two diffent places for same entry?
    By SVTF in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 09-09-2015, 10:23 AM
  3. [SOLVED] LookUp skipping empty cells and returning first entry
    By Colin Smit in forum Excel Formulas & Functions
    Replies: 8
    Last Post: 01-28-2015, 05:51 AM
  4. curser not returning to next row entry cell
    By Faye Oharra in forum Excel General
    Replies: 1
    Last Post: 10-08-2012, 05:43 PM
  5. Returning an entry from a table based on the current date
    By jshaw82 in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 08-14-2012, 12:37 PM
  6. Replies: 3
    Last Post: 12-12-2008, 07:02 AM
  7. returning previous entry in list based on a value
    By scottwilsonx in forum Excel Formulas & Functions
    Replies: 0
    Last Post: 02-24-2005, 11:32 AM

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