Extending Formula: Counting days back to last value

samcoarse

Board Regular
Joined
Jun 16, 2016
Messages
63
Hi All,

I am trying to extend a formula that I've written that would allow me to count the days including & before the last date in a column where there was last a value above 0 in a column. Eg: If the last date was 1-Apr-13, in the below table, the number of days before there was a value in column B would be 2.

To note; I will be importing a list with dates that vary in length, due to public holidays/ weekends/ differing start & end dates, so the range cannot be fixed, it will have to find the last value in the list and work backwards from there.

AB
128-Mar-1322000
229-Mar-130
31-Apr-130

<tbody>
</tbody>

I've found half a solution, in that a formula I have created will show me if there has been no occurrence on the last & second last day on a column, with no range constraints.

The formula will show me a result of '0' if the last date (A3) in Column A has any corresponding value above 0 in B.

It will show me '1' if there was a 0 value in B3, but a value above 0 in the corresponding cell in column B for date before the last date (A2) exists.

It will show a '2+' if the formula returns a 0 value in B3 & B2.

I'm unsure how to extend this for one more day without the formula tripping up over itself and only presenting '2+' despite there being values in B to the end of the column, or in other words, against the last date. Optimally, I would like to run the formula back to the last time there was a value in column B that was greater than 0. If this is too time consuming, reaching 5+ days would be acceptable.

Here's my rather inelegant formula - "=IFERROR(IF(1=(IF(0<(LOOKUP(2,1/(B:B<>""),B:B))/((LOOKUP(2,1/(B:B<>"")))), 0,1)),(IF(1=(LOOKUP((SUM((MAX(A:A))-1)),A:A,B:B)/(LOOKUP(SUM((MAX(A:A))-1),A:A,B:B))),1,0)),0),"+2")"

If anyone has a more streamlined way of coming to the same conclusion, or would know how to build on this, let me know.

Thanks in advance.
 

Excel Facts

Best way to learn Power Query?
Read M is for (Data) Monkey book by Ken Puls and Miguel Escobar. It is the complete guide to Power Query.
Eg: If the last date was 1-Apr-13, in the below table, the number of days before there was a value in column B would be 2.
Do you mean the number of days as stated, or the number of rows in the table. The number of days from 28 Mar to 1 Apr would be more than 2 by may calculation.
 
Last edited:
Upvote 0
Do you mean the number of days as stated, or the number of rows in the table. The number of days from 28 Mar to 1 Apr would be more than 2 by may calculation.

Rows in the table. The days in column A are the days that are not weekends/public holidays, during which, a value in B can occur.
 
Upvote 0
Is this what you mean then? Formula in C2 is copied down.

Excel Workbook
ABC
1
228-Mar-13220000
329-Mar-1301
41-Apr-1302
52-Apr-1303
63-Apr-131000
74-Apr-132000
85-Apr-1320000
98-Apr-1301
109-Apr-1302
1110-Apr-1303
1211-Apr-1304
1312-Apr-1330000
1415-Apr-1301
Days since
 
Upvote 0
Is this what you mean then? Formula in C2 is copied down.

Days since

ABC
1
228-Mar-13220000
329-Mar-1301
41-Apr-1302
52-Apr-1303
63-Apr-131000
74-Apr-132000
85-Apr-1320000
98-Apr-1301
109-Apr-1302
1110-Apr-1303
1211-Apr-1304
1312-Apr-1330000
1415-Apr-1301

<colgroup><col style="font-weight:bold; width:30px; "><col style="width:77px;"><col style="width:54px;"><col style="width:33px;"></colgroup><tbody>
</tbody>

Spreadsheet Formulas
CellFormula
C2=ROWS(B$2:B2)-AGGREGATE(14,6,(ROW(B$2:B2)-ROW(B$2)+1)/(B$2:B2>0),1)

<tbody>
</tbody>

<tbody>
</tbody>


Excel tables to the web >> Excel Jeanie HTML 4

This worked as requested.

Thanks for your assistance on this one, Peter_SSs
 
Upvote 0

Forum statistics

Threads
1,216,087
Messages
6,128,740
Members
449,466
Latest member
Peter Juhnke

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