Lookup but ignore zero values

drluke

Active Member
Joined
Apr 17, 2014
Messages
314
Office Version
  1. 365
Platform
  1. Windows
[TABLE="width: 282"]
<colgroup><col width="62" style="width: 47pt;" span="6"> <tbody>[TR]
[TD="width: 62, bgcolor: transparent"]Sheet 1[/TD]
[TD="width: 62, bgcolor: transparent"][/TD]
[TD="width: 62, bgcolor: transparent"][/TD]
[TD="width: 62, bgcolor: transparent"][/TD]
[TD="width: 62, bgcolor: transparent"][/TD]
[TD="width: 62, bgcolor: transparent"][/TD]
[/TR]
[TR]
[TD="bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"]A[/TD]
[TD="bgcolor: transparent"]B[/TD]
[TD="bgcolor: transparent"]C[/TD]
[TD="bgcolor: transparent"]D[/TD]
[TD="bgcolor: transparent"]E[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]1[/TD]
[TD="bgcolor: transparent"]North[/TD]
[TD="bgcolor: transparent, align: right"]8[/TD]
[TD="bgcolor: transparent, align: right"]10.00[/TD]
[TD="bgcolor: transparent"]A001[/TD]
[TD="bgcolor: transparent, align: right"]9[/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]2[/TD]
[TD="bgcolor: transparent"]North[/TD]
[TD="bgcolor: transparent, align: right"]9[/TD]
[TD="bgcolor: transparent, align: right"]0.00[/TD]
[TD="bgcolor: transparent"]A001[/TD]
[TD="bgcolor: transparent"] [/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]3[/TD]
[TD="bgcolor: transparent"]North[/TD]
[TD="bgcolor: transparent, align: right"]7[/TD]
[TD="bgcolor: transparent, align: right"]30.00[/TD]
[TD="bgcolor: transparent"]A002[/TD]
[TD="bgcolor: transparent"] [/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]4[/TD]
[TD="bgcolor: transparent"]West[/TD]
[TD="bgcolor: transparent, align: right"]9[/TD]
[TD="bgcolor: transparent, align: right"]50.00[/TD]
[TD="bgcolor: transparent"]A006[/TD]
[TD="bgcolor: transparent"] [/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]5[/TD]
[TD="bgcolor: transparent"]West[/TD]
[TD="bgcolor: transparent, align: right"]8[/TD]
[TD="bgcolor: transparent, align: right"]80.00[/TD]
[TD="bgcolor: transparent"]A012[/TD]
[TD="bgcolor: transparent"] [/TD]
[/TR]
[TR]
[TD="bgcolor: transparent, align: right"]6[/TD]
[TD="bgcolor: transparent"]West[/TD]
[TD="bgcolor: transparent, align: right"]9[/TD]
[TD="bgcolor: transparent, align: right"]0.00[/TD]
[TD="bgcolor: transparent"]A004[/TD]
[TD="bgcolor: transparent"] [/TD]
[/TR]
[TR]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[TD="bgcolor: transparent"][/TD]
[/TR]
</tbody>[/TABLE]
In sheet 2 at A1 I need a formula that will give me all the values in col D of shee1 where col B = E1 but ignoring rows that are zero in col C.

Any advice would be much appreciated.
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
Copy down as need


Book1
A
150
Sheet2
Cell Formulas
RangeFormula
A1{=IF(ROWS(A$1:A1)>COUNTIFS(Sheet1!$C$1:$C$7,Sheet1!$F$1,Sheet1!$D$1:$D$7,">0"),"",INDEX(Sheet1!$D$1:$D$7,SMALL(IF(Sheet1!$C$1:$C$7=Sheet1!$F$1,IF(Sheet1!$D$1:$D$7>0,ROW(Sheet1!$D$1:$D$7)-ROW(Sheet1!$D$1)+1)),ROWS(A$1:A1))))}
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Upvote 0
Thank you for this. My bad as I didn't explain properly. I need a list in sheet 2 starting from A1 that will give me all the values in sheet 1 col D where col B = E1 but skip zero values in col C. So I would expect to see the following in sheet 2 A1-A2

A001
A006
 
Upvote 0
Why A001 ?

Sheet2

A1=IFERROR(INDEX(Sheet1!$D$1:$D$6,SMALL(IF(Sheet1!$B$1:$B$6=Sheet1!$E$1,IF(Sheet1!$C$1:$C$6<>Sheet1!$C$2,ROW(Sheet1!$D$1:$D$6)-ROW(Sheet1!$D$1)+1)),ROWS(Sheet1!$D$1:Sheet1!D1))),"") control +shift+enter copy down
 
Upvote 0
In A1 of Sheet2 control+shift+enter, not just enter, and copy down:

=IFERROR(INDEX(Sheet1!$D$1:$D$6,SMALL(IF(Sheet1!$B$1:$B$6=Sheet1!$E$1,IF(ISNUMBER(1/Sheet1!$C$1:$C$6),ROW(Sheet1!$D$1:$D$6)-ROW(Sheet1!$D$1)+1)),ROWS($A$1:A1))),"")
 
Upvote 0

Forum statistics

Threads
1,223,911
Messages
6,175,324
Members
452,635
Latest member
laura12345

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top