How to continually count if cell value(s) in a range are greater than x?

danbates

Active Member
Joined
Oct 8, 2017
Messages
377
Office Version
  1. 2016
Platform
  1. Windows
Hi,

Please can someone help me?

My range is C7:C737 and I have a value of 10 in cell C5.

What I would like is to be able to continually count if the values in the range that are greater than the value in C5 but if one value is less or equal then the count goes back to 0.

Also there will be blank cells in the range that will need to be ignored.

Any help would be appreciated.

Thanks

Dan
 
Hi,

Thank you both for your replies.

footoo:
I don't mind a couple of helper cells but I can't have that many cells.

Eric:
Your formula doesn't work exactly how I wanted but it is something I still could use.

I have been searching online for most of yesterday afternoon and again this morning and I think I have finally found a formula that works for me.
=LOOKUP(1E100,1/(1/FREQUENCY(IF(B2:R2=3,COLUMN(B2:R2)),IF(B2:R2<>3,COLUMN(B2:R2)))))

I've altered it to suit
=IFERROR(LOOKUP(1E+100,1/(1/FREQUENCY(IF(C7:C737>$C$5,ROW(C7:C737)),IF(C7:C737<=$C$5,ROW(C7:C737))))),"0")

Thanks again for your help.

Dan
 
Upvote 0

Excel Facts

Excel Wisdom
Using a mouse in Excel is the work equivalent of wearing a lanyard when you first get to college
I'm glad you found something that works for you. But in looking at the formula, I don't see how it skips empty cells, nor does it check the last value in the column to see if it's less than the value in C5. If your requirements have changed, then that's fine, otherwise, let us know if you need help updating the formula.
 
Upvote 0
Hi Eric,

Very good spot. It doesn't skip the blank cells. I was clearly getting ahead of myself when testing it.

My requirements haven't changed. I was using the last value as a helper but this code doesn't need it.

So could you update the formula so it allows the blanks cells please?

Thanks

Dan
 
Upvote 0
See if this works for you:

=IFERROR(LOOKUP(1E+100,1/(1/FREQUENCY(IF(C7:C737>$C$5,ROW(C7:C737)),IF((C7:C737<=$C$5)*(C7:C737<>""),ROW(C7:C737))))),"0")
 
Upvote 0

Forum statistics

Threads
1,213,485
Messages
6,113,931
Members
448,533
Latest member
thietbibeboiwasaco

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