Is there a way to count values that are of a certain criteria when they are in an array.

scowie

New Member
Joined
Jun 6, 2016
Messages
3
Hi,

I have this function, for simplicity's sake it is provided below:

=FREQUENCY(IF(A1:J1<>"", COLUMN(A1:J1)),IF(A1:J1="",COLUMN(A1:J1)))

Cells A1:Z1 are populated with a series of number with blank cells in between them, and the function above calculates how many cells are in a row until a blank cell appears. For example, [TABLE="class: grid, width: 500, align: center"]
<tbody>[TR]
[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]
[/TR]
[TR]
[TD]10[/TD]
[TD]10[/TD]
[TD][/TD]
[TD][/TD]
[TD]10[/TD]
[TD]10[/TD]
[TD]10[/TD]
[TD][/TD]
[TD][/TD]
[TD]10[/TD]
[/TR]
</tbody>[/TABLE]

So when the function above is Ctrl+Shift+Entered, the output is 2 (three successive cells populated to start), and when I F9 the formula the output is ={2;0;3;0;1}. Is there a way I can implement COUNT in order to count the number of non-zero values in {2;0;3;0;1}, so the output would be 3?

Thank you!!
 

Excel Facts

Workdays for a market open Mon, Wed, Friday?
Yes! Use "0101011" for the weekend argument in NETWORKDAYS.INTL or WORKDAY.INTL. The 7 digits start on Monday. 1 means it is a weekend.
Hi.

You could use an array formula**.

Either:

=COUNT(1/FREQUENCY(IF(A1:J1<>"",COLUMN(A1:J1)),IF(A1:J1="",COLUMN(A1:J1))))

or:

=SUM(IF(FREQUENCY(IF(A1:J1<>"",COLUMN(A1:J1)),IF(A1:J1="",COLUMN(A1:J1))),1))

Regards


**Array formulas are not entered in the same way as 'standard' formulas. Instead of pressing just ENTER, you first hold down CTRL and SHIFT, and only then press ENTER. If you've done it correctly, you'll notice Excel puts curly brackets {} around the formula (though do not attempt to manually insert these yourself).
 
Upvote 0

Forum statistics

Threads
1,223,228
Messages
6,170,875
Members
452,363
Latest member
merico17

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