Extracting non-zero values

Tweetie85

New Member
Joined
Feb 26, 2009
Messages
10
Hi

A previous thread explained how to pull non-zero values from a column of values
http://www.mrexcel.com/forum/showthread.php?p=1862091#post1862091

The code I then used from this thread is as follows:
=IF(ROWS(B$1:B1)>COUNTIF(A$1:A$1200,">0"),"",INDEX(A$1:A$1200,SMALL(IF(A$1:A$1200>0,ROW(A$1:A$1200)-ROW(A$1)+1),ROWS(B$1:B1))))
The logic behind it is explained in the thread....

This code works great but I need it to apply to negative numbers as well. I posted the question there but have not got a reply as yet.

Would anyone be able to figure this out for me? I would be very grateful!
 

Excel Facts

VLOOKUP to Left?
Use =VLOOKUP(A2,CHOOSE({1,2},$Z$1:$Z$99,$Y$1:$Y$99),2,False) to lookup Y values to left of Z values.
Untested

=IF(ROWS(B$1:B1)>COUNTIF(A$1:A$1200,"<>0"),"",INDEX(A$1:A$1200,SMALL(IF(A$1:A$1200>0,ROW(A$1:A$1200)-ROW(A$1)+1),ROWS(B$1:B1))))
 
Upvote 0
Hi

Assuming there may be blanks, use in B1:

=IF(ROWS(B$1:B1)>SUMPRODUCT(--(A$1:A$1200<>0),--ISNUMBER($A$1:$A$1200)),"",INDEX(A$1:A$1200,SMALL(IF((A$1:A$1200<>0)*ISNUMBER(A$1:A$1200),ROW(A$1:A$1200)-ROW(A$1)+1),ROWS(B$1:B1))))

This in an array formula, you have to confirm it with CTRL+SHIFT+ENTER.

Copy down
 
Upvote 0
Thanks guys

Both lines of code work. But to avoid a #NUM! error at the very end of the formula (for xld's code), change the it to the following:

=IF(ROWS(B$1:B1)>COUNTIF(A$1:A$1200,"<>0"),"",INDEX(A$1:A$1200,SMALL(IF(A$1:A$1200<>0,ROW(A$1:A$1200)-ROW(A$1)+1),ROWS(B$1:B1))))

Thanks guys, really appreciate it!!:LOL:
 
Upvote 0

Forum statistics

Threads
1,213,497
Messages
6,113,999
Members
448,543
Latest member
MartinLarkin

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