Return Consecutive Days Count or Zero

Kimberly24

New Member
Joined
Aug 20, 2015
Messages
7
Hello,
In Excel I have a Date column and a Flagged column. The flagged column is a "1" or a "0" based on information from a different source. I need to make a column that will return "0" if the flagged column is "0" BUT if the flagged column is "1" then I need it to return how many consecutive "1"'s are in that string.

DATE FLAGGED OUTPUT
1/1/2016 1 1
1/2/2016 0 0
1/3/2016 1 4
1/4/2016 1 4
1/5/2016 1 4
1/6/2016 1 4
1/7/2016 0 0
1/8/2016 0 0
1/9/2016 1 2
1/10/2016 1 2

I have reviewed some similar threads on the subject but I was not able to tweak them to match my exact needs yet. Thanks in advance for any assistance!
KC
 

Excel Facts

Bring active cell back into view
Start at A1 and select to A9999 while writing a formula, you can't see A1 anymore. Press Ctrl+Backspace to bring active cell into view.
I am not sure how to link threads on here, but I searched "Consecutive Day Count" and it returned several from the Excel Forum.
 
Upvote 0
Can you make use of a macro? If so...
Code:
[table="width: 500"]
[tr]
	[td]Sub CountFlaggedDates()
  Dim X As Long, Flags() As String, Result() As String
  Flags = Split(Join(Application.Transpose(Range("B2", Cells(Rows.Count, "B").End(xlUp))), ""), 0)
  For X = 0 To UBound(Flags)
    Flags(X) = Replace(Flags(X), 1, " " & Evaluate(Replace(StrConv(Flags(X), vbUnicode), Chr(0), "+") & 0) & " ")
  Next
  Result = Split(Application.Trim(Join(Flags, " 0 ")))
  Range("C2").Resize(UBound(Result) + 1) = Application.Transpose(Result)
End Sub[/td]
[/tr]
[/table]

HOW TO INSTALL MACROs
------------------------------------
If you are new to macros, they are easy to install and use. To install it, simply press ALT+F11 to go into the VB editor and, once there, click Insert/Module on its menu bar, then copy/paste the above code into the code window that just opened up. That's it.... you are done. To use the macro, go back to the worksheet with your data on it and press ALT+F8, select the macro name (CountFlaggedDates) from the list that appears and click the Run button. The macro will execute and perform the action(s) you asked for. If you will need to do this again in this same workbook, and if you are using XL2007 or above, make sure you save your file as an "Excel Macro-Enabled Workbook (*.xlsm) and answer the "do you want to enable macros" question as "yes" or "OK" (depending on the button label for your version of Excel) the next time you open your workbook.
 
Upvote 0
In C2 enter the following array formula, confirm with Ctrl+Shift+Enter and copy down:
Code:
=IF(B2=0,0,IFERROR(ROW()+MATCH(0,B2:INDEX(B:B,COUNTA(B:B)),0),2+COUNTA(B:B))-2-IF(COUNTIF(B$1:B2,0)=0,1,MAX(IF(B$1:B2=0,ROW(B$1:B2)))))
This formula is designed so any line deletions will not cause any ref errors.
 
Upvote 0
In C2 enter the following array formula, confirm with Ctrl+Shift+Enter and copy down:
Code:
=IF(B2=0,0,IFERROR(ROW()+MATCH(0,B2:INDEX(B:B,COUNTA(B:B)),0),2+COUNTA(B:B))-2-IF(COUNTIF(B$1:B2,0)=0,1,MAX(IF(B$1:B2=0,ROW(B$1:B2)))))
This formula is designed so any line deletions will not cause any ref errors.
Just pointing out that insertions of row(s) will cause incorrect results though.
 
Last edited:
Upvote 0
Just pointing out that insertions of row(s) will cause incorrect results though.
That's true, until the new lines are populated with data (and the formula copied down from the line above the inserted row(s)).

The background of my remark was: it is probably much easier to come up with a formula that is refering to a previous / next row, but that would cause ref errors when rows are deleted.
 
Upvote 0

Forum statistics

Threads
1,215,219
Messages
6,123,687
Members
449,117
Latest member
Aaagu

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