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

KarenAus

New Member
Joined
Oct 2, 2019
Messages
1
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.


QtyItemEstimate or Actual?
- ApplesActual
16BananasEstimate
15OrangesActual
StrawberriesActual
10BlueberriesEstimate

<colgroup><col><col><col></colgroup><tbody>
</tbody>


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

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

<tbody>
</tbody>


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?
 

Eric W

MrExcel MVP
Joined
Aug 18, 2015
Messages
8,801
Welcome to MrExcel!

Try:

<b></b><table cellpadding="2.5px" rules="all" style=";background-color: rgb(255,255,255);border: 1px solid;border-collapse: collapse; border-color: rgb(187,187,187)"><colgroup><col width="25px" style="background-color: rgb(218,231,245)" /><col /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: rgb(218,231,245);text-align: center;color: rgb(22,17,32)"><th></th><th>A</th><th>B</th><th>C</th><th>D</th><th>E</th><th>F</th></tr></thead><tbody><tr ><td style="color: rgb(22,17,32);text-align: center;">1</td><td style="font-weight: bold;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;color: #333333;background-color: #FAFAFA;;">Qty</td><td style="font-weight: bold;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;color: #333333;background-color: #FAFAFA;;">Item</td><td style="font-weight: bold;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;color: #333333;background-color: #FAFAFA;;">Estimate or Actual?</td><td style="text-align: right;border-right: 1px solid black;border-left: 1px solid black;;"></td><td style="font-weight: bold;border-right: 1px solid black;border-left: 1px solid black;color: #333333;background-color: #FAFAFA;;">Item</td><td style="font-weight: bold;border-left: 1px solid black;color: #333333;background-color: #FAFAFA;;">Result</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">2</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;color: #333333;background-color: #FAFAFA;;"></td><td style="border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;color: #333333;background-color: #FAFAFA;;">Apples</td><td style="border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;color: #333333;background-color: #FAFAFA;;">Actual</td><td style="text-align: right;border-left: 1px solid black;;"></td><td style=";">Bananas</td><td style=";">$ (E) 16</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">3</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;color: #333333;background-color: #FAFAFA;;">16</td><td style="border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;color: #333333;background-color: #FAFAFA;;">Bananas</td><td style="border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;color: #333333;background-color: #FAFAFA;;">Estimate</td><td style="text-align: right;border-left: 1px solid black;;"></td><td style=";">Oranges</td><td style=";">$ (A) 15</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">4</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;color: #333333;background-color: #FAFAFA;;">15</td><td style="border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;color: #333333;background-color: #FAFAFA;;">Oranges</td><td style="border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;color: #333333;background-color: #FAFAFA;;">Actual</td><td style="text-align: right;border-left: 1px solid black;;"></td><td style=";">Blueberries</td><td style=";">$ (E) 10</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">5</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;color: #333333;background-color: #FAFAFA;;"></td><td style="border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;color: #333333;background-color: #FAFAFA;;">Strawberries</td><td style="border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;color: #333333;background-color: #FAFAFA;;">Actual</td><td style="text-align: right;border-left: 1px solid black;;"></td><td style=";"></td><td style=";"></td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">6</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;color: #333333;background-color: #FAFAFA;;">10</td><td style="border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;color: #333333;background-color: #FAFAFA;;">Blueberries</td><td style="border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;color: #333333;background-color: #FAFAFA;;">Estimate</td><td style="text-align: right;border-left: 1px solid black;;"></td><td style=";"></td><td style=";"></td></tr></tbody></table><p style="width:4.8em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid rgb(187,187,187);border-top:none;text-align: center;background-color: rgb(218,231,245);color: rgb(22,17,32)">Sheet9</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: rgb(255,255,255)" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: rgb(255,255,255);border-collapse: collapse; border-color: rgb(187,187,187)"><thead><tr style=" background-color: rgb(218,231,245);color: rgb(22,17,32)"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: rgb(218,231,245);color: rgb(22,17,32)">E2</th><td style="text-align:left">=IFERROR(<font color="Blue">INDEX(<font color="Red">B:B,AGGREGATE(<font color="Green">15,6,ROW(<font color="Purple">$B$2:$B$6</font>)/(<font color="Purple">$A$2:$A$6>0</font>),ROWS(<font color="Purple">E$2:E2</font>)</font>)</font>),""</font>)</td></tr><tr><th width="10px" style=" background-color: rgb(218,231,245);color: rgb(22,17,32)">F2</th><td style="text-align:left">=IF(<font color="Blue">E2="","","$ ("&LEFT(<font color="Red">INDEX(<font color="Green">$C$2:$C$6,MATCH(<font color="Purple">E2,$B$2:$B$6,0</font>)</font>)</font>)&") "&INDEX(<font color="Red">$A$2:$A$6,MATCH(<font color="Green">E2,$B$2:$B$6,0</font>)</font>)</font>)</td></tr></tbody></table></td></tr></table><br />
 

Forum statistics

Threads
1,078,243
Messages
5,339,048
Members
399,276
Latest member
BlueCheetah

Some videos you may like

This Week's Hot Topics

Top