Return Cells in a Sequence that's Greater then Zero

Johnboy1

New Member
Joined
Jun 26, 2019
Messages
6
Hi All,

I'm trying to find a solution to my predicament and having attempted a number of ways (fuelled by similar older posts on here), I'm still not getting completely the right result.

In short if I had six columns of random numbers: 10 | 0 | 0 | 10 | 0 | 5
How do I get Excel to return all numbers greater than Zero: 10 | 10 | 5

The Formula should ignore all Zero cells and must not repeat cells, the latter being the problem with the below type of formula
=IF(A2>0,A2,IF(B2>0,B”,IF(C2>0,C2,IF(D2>0,D2,IF(E2>0,E2,IF(F2>0,F2,""))))))

<img src="//www.bannerboy.co.uk/graphics/Example.JPG" width="465" height="184" alt="Example" />

Thanks in advance and I look forward to your suggestions.

J
 

Excel Facts

How to change case of text in Excel?
Use =UPPER() for upper case, =LOWER() for lower case, and =PROPER() for proper case. PROPER won't capitalize second c in Mccartney
in H2
=IFERROR(INDEX($A2:$F2,1,AGGREGATE(15,6,COLUMN($A2:$F2)/(($A2:$FZ2>0)),COLUMNS($A1:A1))),"")
and copy across the columns and down for each row
 
Upvote 0
Try this array formula


<table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:35.17px;" /><col style="width:35.17px;" /><col style="width:35.17px;" /><col style="width:35.17px;" /><col style="width:35.17px;" /><col style="width:35.17px;" /><col style="width:76.04px;" /><col style="width:46.57px;" /><col style="width:46.57px;" /><col style="width:46.57px;" /><col style="width:46.57px;" /><col style="width:46.57px;" /><col style="width:46.57px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td><td >D</td><td >E</td><td >F</td><td >G</td><td >H</td><td >I</td><td >J</td><td >K</td><td >L</td><td >M</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td >Data</td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td >Formula result</td><td > </td><td > </td><td > </td><td > </td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td style="text-align:right; ">10</td><td style="text-align:right; ">0</td><td style="text-align:right; ">0</td><td style="text-align:right; ">10</td><td style="text-align:right; ">0</td><td style="text-align:right; ">5</td><td > </td><td style="text-align:right; ">10</td><td style="text-align:right; ">10</td><td style="text-align:right; ">5</td><td > </td><td > </td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td style="text-align:right; ">10</td><td style="text-align:right; ">0</td><td style="text-align:right; ">1</td><td style="text-align:right; ">12</td><td style="text-align:right; ">0</td><td style="text-align:right; ">5</td><td > </td><td style="text-align:right; ">10</td><td style="text-align:right; ">1</td><td style="text-align:right; ">12</td><td style="text-align:right; ">5</td><td > </td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td style="text-align:right; ">0</td><td style="text-align:right; ">0</td><td style="text-align:right; ">8</td><td style="text-align:right; ">0</td><td style="text-align:right; ">0</td><td style="text-align:right; ">0</td><td > </td><td style="text-align:right; ">8</td><td > </td><td > </td><td > </td><td > </td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td style="text-align:right; ">7.5</td><td style="text-align:right; ">11</td><td style="text-align:right; ">4.5</td><td style="text-align:right; ">7.5</td><td style="text-align:right; ">0</td><td style="text-align:right; ">5</td><td > </td><td style="text-align:right; ">7.5</td><td style="text-align:right; ">11</td><td style="text-align:right; ">4.5</td><td style="text-align:right; ">7.5</td><td style="text-align:right; ">5</td><td > </td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b></b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td >Formula</td></tr><tr><td >H2</td><td >{=IFERROR(INDEX($A2:$F2,0,SMALL(IF($A2:$F2>0,COLUMN($A2:$F2)),COLUMNS($H$1:H$1))),"")}</td></tr></table></td></tr></table>


Array formulas
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself
 
Upvote 0

Forum statistics

Threads
1,213,543
Messages
6,114,237
Members
448,555
Latest member
RobertJones1986

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