Google Groups no longer supports new Usenet posts or subscriptions. Historical content remains viewable.
Dismiss

Counting Zeros in a row until encounter first non-zero value

3,224 views
Skip to first unread message

Bubba

unread,
Oct 12, 2009, 12:05:02 PM10/12/09
to
Is there a function, or combination of nested functions to count the number
of zeros in a row up until the first non-zero valued cell?

For Example

0 0 0 0 0 35 0 50 60
0 0 0 0 0 0 40 10 0 0 30

For the First Row I want the function to return the value 6 and the second
row to return the value '7'

I do not want to know the total number of zeros in a row, I want to know the
number of zeros in a row until I encounter the first nonzero cell.

Glenn

unread,
Oct 12, 2009, 12:16:15 PM10/12/09
to


Try the following array formula (commit with CTRL+SHIFT+ENTER):

=MATCH(1,--(A1:K1>0),0)

That will return the result you specified, but not the answer to your original
question. Subtract one to answer that question.

Jacob Skaria

unread,
Oct 12, 2009, 12:15:01 PM10/12/09
to
Try
=MATCH(0.0001,1:1)
OR
=MATCH(0.0001,A1:J1)

If this post helps click Yes
---------------
Jacob Skaria

T. Valko

unread,
Oct 12, 2009, 12:19:44 PM10/12/09
to
Will there *always* be a non-zero entry to find? Are the non-zero numbers
*always* positive numbers greater than 0? Are there any TEXT entries in the
range? Are there any formula blanks in the range?

--
Biff
Microsoft Excel MVP


"Bubba" <Bu...@discussions.microsoft.com> wrote in message
news:92DC5D10-4A32-403A...@microsoft.com...

Bubba

unread,
Oct 12, 2009, 1:21:01 PM10/12/09
to
There will always be a non-zero number that is positive (greater than zero).
There are no text entries and no formula blanks.

I have tried:

=IF(J6=0,MATCH(0.0001,J6:BM6),0)

but the result is not always correct. Sometimes the formula counts
correctly, other times it returns a number equal to the range aka if data is
in columns J:BM it might sometimes returns '56' even though a nonzero number
was encountered before Column BM

Jacob Skaria

unread,
Oct 12, 2009, 1:32:01 PM10/12/09
to
The ealier formula works only if the 1st cell starts with zero...If the 1st
cell do not have a zero then try the below

=MATCH(0.1,A6:J6)-MATCH(0,A6:J6,0)+1

If this post helps click Yes
---------------
Jacob Skaria

T. Valko

unread,
Oct 12, 2009, 1:37:37 PM10/12/09
to
Ok, based on this:

>0 0 0 0 0 35 0 50 60
>0 0 0 0 0 0 40 10 0 0 30
>For the First Row I want the function to return the value
>6 and the second row to return the value '7'

What you want to do is find the position of the first non-zero entry. In row
1 the first non-zero entry is located at position 6 and for row 2 the first
non-zero entry is located at position 7.

Try this:

=MATCH(TRUE,INDEX(J1:BM1>0,0),0)


--
Biff
Microsoft Excel MVP


"Bubba" <Bu...@discussions.microsoft.com> wrote in message

news:23C76E0A-0FDB-449B...@microsoft.com...

Bubba

unread,
Oct 12, 2009, 5:39:01 PM10/12/09
to
Perfect, thank you very much!

T. Valko

unread,
Oct 12, 2009, 6:24:34 PM10/12/09
to
You're welcome. Thanks for the feedback!

--
Biff
Microsoft Excel MVP


"Bubba" <Bu...@discussions.microsoft.com> wrote in message

news:40FEFBCB-28A4-4044...@microsoft.com...

Ashish Mathur

unread,
Oct 12, 2009, 11:42:05 PM10/12/09
to
Hi,

Try this

=MATCH(TRUE,INDEX(E29:L29>0,,),0)-1

--
Regards,

Ashish Mathur
Microsoft Excel MVP
www.ashishmathur.com

"Bubba" <Bu...@discussions.microsoft.com> wrote in message
news:92DC5D10-4A32-403A...@microsoft.com...

0 new messages