Count Consecutive Cells Above/Below a Value

chicubs

New Member
Joined
Aug 10, 2016
Messages
8
I am trying to count the consecutive weeks an item is below its average for a given period of time. Not sure how to do this. Item 123 should have an output of 3 and item 1234 should have an output of 1.

Item10/2010/2711/311/10AvgConsecutive WK Below Avg
123158769???
1234151415813???

<tbody>
</tbody>
 

Excel Facts

Using Function Arguments with nested formulas
If writing INDEX in Func. Arguments, type MATCH(. Use the mouse to click inside MATCH in the formula bar. Dialog switches to MATCH.
That works for items where Column E is a value less than the average. However, it does not return a 0 for items where Column E is above the average. See the link below for the example.

I'm not sure what you mean. I took the example that you posted in post #4 and it seems to work fine. It results in the maximum number of consecutive weeks where the number is higher than the average. Is this not what you are looking for?


Excel 2010
ABCDEFGHIJK
19/17/20169/24/201610/1/201610/8/201610/15/201610/22/201610/29/201611/5/2016
2ItemSales UnitsSales UnitsSales UnitsSales UnitsSales UnitsSales UnitsSales UnitsSales UnitsAvg Sales UnitsConsecutive WK Below Avg
32033352882992342202391941881782486
42007981291281271421431471511501333
Sheet1
Cell Formulas
RangeFormula
K3{=MAX(FREQUENCY(IF(B3:I3B3:I3)),IF(B3:I3>=J3,COLUMN(B3:I3))))}
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Last edited:
Upvote 0
This is what I'm looking for! What formula would I use if I wanted to count the consecutive weeks ABOVE the average?
 
Upvote 0
This is what I'm looking for! What formula would I use if I wanted to count the consecutive weeks ABOVE the average?

Just reverse the inequalities. < becomes > and >= becomes <=.

Formula would then become

=MAX(FREQUENCY(IF(B3:I3>J3,COLUMN(B3:I3)),IF(B3:I3<=J3,COLUMN(B3:I3)))) Ctrl Shift Enter
 
Last edited:
Upvote 0

Forum statistics

Threads
1,215,470
Messages
6,124,992
Members
449,201
Latest member
Lunzwe73

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