Countif with array formula and greather than?

filarap

New Member
Joined
May 15, 2015
Messages
33
Hello everybody,

I am trying to make a formula that will count each result of array formula when that result is greater than ...

This is what i am trying =COUNTIF(E2:E8/C2:C8,">0.49")
I managed to achieve it by making additional column and counting that one then hiding it, but i would like to achieve it without additional column

Sample data.

6
3
2318
41
194
3733
238
245
Thank you

<tbody>
</tbody><colgroup><col><col></colgroup>
 

Excel Facts

Convert text numbers to real numbers
Select a column containing text numbers. Press Alt+D E F to quickly convert text to numbers. Faster than "Convert to Number"
Control+shift+enter, not just enter:

=SUM(IF(ISNUMBER(1/C2:C8),IF(E2:E8/C2:C8>0.49,1)))

While this checks for possible 0's and non-numbers in C2:C8, it does not check for non-numbers in E2:E8 though.
 
Upvote 0
Thank you very much

Both of it works like a charm.

If i can just ask a question about =SUMPRODUCT(--(E2:E8/C2:C8>0.49)) formula.
What does -- stand for and what is it used for?
 
Upvote 0
Change C2 to 0. What happens?

I am not getting a count of c2, so result is minus 1. On sumproduct formula i am getting error in calculation for whole array.
I will need to investigate it, to learn the calculations behind it. Thank you one more time

[See the link: Find last cell with data - as formular if it helps./QUOTE]
Thank you for this, i will dig in to get to know this better
 
Upvote 0
Thank you very much

Both of it works like a charm.

If i can just ask a question about =SUMPRODUCT(--(E2:E8/C2:C8>0.49)) formula.
What does -- stand for and what is it used for?

Him

in that formula SUMPRODUCT returns an array of TRUE or FALSE depending on whether the division is > 0.49 like this

=SUMPRODUCT(--{TRUE;TRUE;FALSE;FALSE;TRUE;FALSE;FALSE})

SUMPRODUCT can't evaluate that because it likes to work with numbers and what the -- does is coerce the TRUE and FALSE into 1 and zero like this which the function can then add up

=SUMPRODUCT({1;1;0;0;1;0;0})

In Excel TRUE and FALSE can be coerced into 1 and zero in cells with any mathematical operation. Try this. Put TRUE in A1 and (say) 5 in B1 and then the formula =A1*B1 and you'll see it returns 5.
 
Upvote 0
Hmm, i got it now :)
Quite a simple and excelent explanation

One more time, thank you both very much
 
Upvote 0

Forum statistics

Threads
1,213,501
Messages
6,114,010
Members
448,543
Latest member
MartinLarkin

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