Countif across multiple sheets and only on visible cells

LaurensTa

New Member
Joined
May 17, 2017
Messages
5
Hi all,

I want to create a function which counts all numbers in a column in all sheets.
I already found a function which returns all sheets names, so I have a tab which shows what sheets I have which can be found below:

Tab names:
18 Apr
10 Apr
etc....

<colgroup><col width="64" style="width:48pt"> </colgroup><tbody>
</tbody>

Then I got in my main sheet:

Letter: Appearances:
A25
B10
C8
D57
E1

<colgroup><col width="64" span="2" style="width:48pt"> </colgroup><tbody>
</tbody>

And I counted the appearances with the formula:
=SUMPRODUCT(COUNTIF(INDIRECT("'"&Tabs!$A$2:$A$41&"'!A:A"), A3))

But the thing is that in my sheets, I am hiding a lot of rows because they have to be excluded.
The formula that I use counts even the values which are filtered out and I would like to only count the visible cells.
I found some formulas about how to only count the visible cells, but I don't know how to combine them.

So what I want to see is a table which is for example like:
Letter: Appearances:
A5
B8
C3
D50
E0


<colgroup><col width="64" span="2" style="width: 48pt;"></colgroup><tbody>
</tbody>

which is almost the same, but you can see that it contains lower appearances since only the visible cells are counted.

Hope you can help me,
Laurens
 

Excel Facts

Can you sort left to right?
To sort left-to-right, use the Sort dialog box. Click Options. Choose "Sort left to right"
Hi,

Why hide them? If you mark the rows to be excluded, e.g. with an "x" in a further column, it's a simple additional clause to your current formula.

Regards
 
Upvote 0
Hi,

The thing is that the person who I want to make this for, just gets the tabs like that.
He doesn't know how to put in a "X" and I don't think I can teach him (he is old..)

Currently he even manually counts how often it appears in the tabs.
I would like to help him as much as possible by creating 1 formula which he doesn't have to do anything with.

Regards,
Laurens
 
Upvote 0
Ok, thanks.

Array formula**:

=SUM(IF(T(OFFSET(INDIRECT("'"&TRANSPOSE(Tabs!$A$2:$A$41)&"'!A1"),ROW(A1:A10)-MIN(ROW(A1:A10)),0))=A3,IF(SUBTOTAL(3,OFFSET(INDIRECT("'"&TRANSPOSE(Tabs!$A$2:$A$41)&"'!A1"),ROW(A1:A10)-MIN(ROW(A1:A10)),0)),1)))

Unfortunately you can't 'get away' with referencing an entire column (A:A) within such a construction, as you can with COUNTIF(S). Hence my choice of A1:A10, which obviously you can change, though be sure to keep as small as possible, else calculation time will be affected noticeably.

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,215,079
Messages
6,123,009
Members
449,093
Latest member
ikke

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