Why am I getting this error? (COUNTIF with 3D reference)

Big Monkey

Active Member
Joined
Nov 5, 2005
Messages
255
I have the following formula in worksheet 2

=COUNTIF('2'!$C$2:$C$65536, 1)

I just recently discovered 3D references and tried to change it to:

=COUNTIF('1:2'!$C$2:$C$65536, 1)

When I add worksheet 1 to the equation, I get a #VALUE error.

Why is this happening? The COUNTA function seems to work fine, but COUNTIF won't

BTW, I tried the 1 with and without quotes, didn't make a difference (didn't think it would, but I gave it a shot anyway.)
 

Excel Facts

How to fill five years of quarters?
Type 1Q-2023 in a cell. Grab the fill handle and drag down or right. After 4Q-2023, Excel will jump to 1Q-2024. Dash can be any character.

Big Monkey

Active Member
Joined
Nov 5, 2005
Messages
255
Doh!

It seems that COUNTIF is not one of the supported functions using 3D references.

This really throws a kink for me.

Anyone know of any workarounds?
 

Brian from Maui

MrExcel MVP
Joined
Feb 16, 2002
Messages
8,458
Try,

=SUMPRODUCT(COUNTIF(INDIRECT("'"&sheetlist&"'!A2:A10"),B2))

Where sheetlist is a named range containing your sheet list and B2 the criteria.
 

Forum statistics

Threads
1,141,095
Messages
5,704,310
Members
421,338
Latest member
Pepess

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
Top