Results 1 to 2 of 2

Thread: Extract list of non-zero cell values from a list AND whether Estimate or Actual AND the name of the product
Thanks Thanks: 0 Likes Likes: 0

  1. #1
    New Member
    Join Date
    Oct 2019
    Location
    Australia
    Posts
    1
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Extract list of non-zero cell values from a list AND whether Estimate or Actual AND the name of the product

    I have a list that I need to remove the zero value items from via formula to create a new list (imagine an order form).

    Because people will be using this second form without much excel knowledge, I need it 100% formula driven.


    Qty Item Estimate or Actual?
    - Apples Actual
    16 Bananas Estimate
    15 Oranges Actual
    Strawberries Actual
    10 Blueberries Estimate


    I need it to look like this (with a dollar symbol aligned to the left):

    Bananas $ (E) 16
    Oranges $ (A) 15
    Blueberries $ (E) 10


    I have found this formula to return the non-zero values (when dragged down the column): {=IF(ROWS(F$2:F2)>COUNTIF(A$2:A$1201,">0"),"",INDEX(A$2:A$1201,SMALL(IF(A$2:A$1201>0,ROW(A$2:A$1201)-ROW(A$2)+1),ROWS(F$2:F2))))}

    But I'm not sure how to concatenate the estimate or $ symbol into that formula.

    Also, not sure how to extract the label in the cell beside the non-zero value.

    Any ideas please?

  2. #2
    MrExcel MVP Eric W's Avatar
    Join Date
    Aug 2015
    Location
    Bountiful, UT
    Posts
    8,730
    Post Thanks / Like
    Mentioned
    45 Post(s)
    Tagged
    5 Thread(s)

    Default Re: Extract list of non-zero cell values from a list AND whether Estimate or Actual AND the name of the product

    Welcome to MrExcel!

    Try:

    ABCDEF
    1QtyItemEstimate or Actual?ItemResult
    2ApplesActualBananas$ (E) 16
    316BananasEstimateOranges$ (A) 15
    415OrangesActualBlueberries$ (E) 10
    5StrawberriesActual
    610BlueberriesEstimate

    Sheet9



    Worksheet Formulas
    CellFormula
    E2=IFERROR(INDEX(B:B,AGGREGATE(15,6,ROW($B$2:$B$6)/($A$2:$A$6>0),ROWS(E$2:E2))),"")
    F2=IF(E2="","","$ ("&LEFT(INDEX($C$2:$C$6,MATCH(E2,$B$2:$B$6,0)))&") "&INDEX($A$2:$A$6,MATCH(E2,$B$2:$B$6,0)))

    Cheers,
    Eric

    When you eliminate the impossible, whatever remains, however improbable, must be the truth.

    -Posting guidelines, forum rules, terms of use, FAQs, BB codes, See how to search the forum
    -Post a screen shot with the HTML Maker

Some videos you may like

User Tag List

Tags for this Thread

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •