What is wrong with this as an array formula?

TomCon

Active Member
Joined
Mar 31, 2011
Messages
381
Office Version
  1. 365
Platform
  1. Windows
  2. Mobile
To start with, an array formula that works as expected.
{=COUNT(ABS(Alg.Oth!$AO$602:$AO$4592))}
Of course it gives result same as a non-array formula without ABS.
=COUNT(Alg.Oth!$AO$602:$AO$4592)

So, i tried to modify it to COUNTIF and Excel won't let me enter it, gives the "there is an error with this formula" dialog.

{=COUNTIF(ABS(Alg.Oth!$AO$602:$AO$4592),">20")}

Of course i could do it by adding another column to the worksheet with the ABS() of column $AO, but would like to do it with an array formula to save clutter on the worksheet (its already 18MB!), and also to understand more about array formulas and why this would not work as an array formula.

Thanks!
 

Excel Facts

Format cells as currency
Select range and press Ctrl+Shift+4 to format cells as currency. (Shift 4 is the $ sign).
It seems to me that COUNTIF does not work with an internal formula

Try this "regular" formula

=SUMPRODUCT(--(ABS(Alg.Oth!$AO$602:$AO$4592)>20))

Or this array formula


{=COUNT(IF(ABS(Alg.Oth!$AO$602:$AO$4592)>20,1))}
 
Last edited:
Upvote 0
Thanks!

I used the latter formula, as it makes intuitive sense to me...the SUMPRODUCT one...thats a mystery!

I will have to try to "reparameterize" in these cases where array formulas don't work for some odd or inconsistent or unknown reason (maybe its just a bug!).

Thanks for the formula...it solves it!
 
Upvote 0

Forum statistics

Threads
1,223,228
Messages
6,170,871
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