Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Join us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.

Reply
Vaishali04
Helper III
Helper III

calculate running total of consecutive value

Hi,

 

I am trying to calcualte running total of only consecutive 1's value.

condition:

1. Date range is selected in date slicer. So date range is always dynamic.

2. Running total should be done in ascending order of date and should be done fir individual resources.

3. whenever 0 is encountered running total should again restart for eg. for resource "abc" for 1/5/2020 Billable value is 0. so for 1/6/2020 running total is again calculated from beginning. 

 

 

DateResourceBillablerunning total
1/2/2020abc11
1/3/2020abc12
1/4/2020abc13
1/5/2020abc00
1/6/2020abc11
1/7/2020abc12
1/2/2020xyz00
1/3/2020xyz11
1/4/2020xyz00
1/5/2020xyz11
1/6/2020xyz12
1/7/2020xyz00

 

Please help if anyone knows the logic.

Regards

Vaishali Rathi

2 ACCEPTED SOLUTIONS
Mariusz
Community Champion
Community Champion

Hi @Vaishali04 

 

Try this, I'm hoping someone will come up with a more efficient version, but for now, at least you have some solution.

Column = 
VAR __date = 'Table'[Date]
VAR __allResource = ALLEXCEPT( 'Table', 'Table'[Resource] ) 
VAR __firstZero =  
    CALCULATE(
        MAX( 'Table'[Date] ),
        __allResource,
        'Table'[Date] <= __date,
        'Table'[Billable] = 0
    )
VAR __start = 
    IF( 
        ISBLANK( __firstZero ),  
        CALCULATE(
            MIN( 'Table'[Date] ),
            __allResource
        ),
        __firstZero
    )
RETURN 
CALCULATE(
    SUM( 'Table'[Billable] ),
    FILTER(
        ALL( 'Table'[Date] ),
        'Table'[Date] >= __start && 'Table'[Date] <= __date 
    )
)

See the attached for ref as well 

 

Best Regards,
Mariusz

If this post helps, then please consider Accepting it as the solution.

Please feel free to connect with me.
LinkedIn

 

View solution in original post

Hi @Vaishali04 

 

Ok, I've added ALLSELECTED

Measure = 
VAR __date = SELECTEDVALUE( 'Table'[Date] )
VAR __allResource = 
    CALCULATETABLE(
        'Table',
        ALLSELECTED( 'Table' ),
        VALUES( 'Table'[Resource] ) 
    )
VAR __firstZero =  
    CALCULATE(
        MAX( 'Table'[Date] ),
        __allResource,
        'Table'[Date] <= __date,
        'Table'[Billable] = 0
    )
VAR __start = 
    IF( 
        ISBLANK( __firstZero ),  
        CALCULATE(
            MIN( 'Table'[Date] ),
            __allResource
        ),
        __firstZero
    )
RETURN 
CALCULATE(
    SUM( 'Table'[Billable] ),
    FILTER(
        ALL( 'Table'[Date] ),
        'Table'[Date] >= __start && 'Table'[Date] <= __date 
    )
)

 

Best Regards,
Mariusz

If this post helps, then please consider Accepting it as the solution.

Please feel free to connect with me.
LinkedIn

 

View solution in original post

6 REPLIES 6
Mariusz
Community Champion
Community Champion

Hi @Vaishali04 

 

Try this, I'm hoping someone will come up with a more efficient version, but for now, at least you have some solution.

Column = 
VAR __date = 'Table'[Date]
VAR __allResource = ALLEXCEPT( 'Table', 'Table'[Resource] ) 
VAR __firstZero =  
    CALCULATE(
        MAX( 'Table'[Date] ),
        __allResource,
        'Table'[Date] <= __date,
        'Table'[Billable] = 0
    )
VAR __start = 
    IF( 
        ISBLANK( __firstZero ),  
        CALCULATE(
            MIN( 'Table'[Date] ),
            __allResource
        ),
        __firstZero
    )
RETURN 
CALCULATE(
    SUM( 'Table'[Billable] ),
    FILTER(
        ALL( 'Table'[Date] ),
        'Table'[Date] >= __start && 'Table'[Date] <= __date 
    )
)

See the attached for ref as well 

 

Best Regards,
Mariusz

If this post helps, then please consider Accepting it as the solution.

Please feel free to connect with me.
LinkedIn

 

Mariusz
Community Champion
Community Champion

Hi @Vaishali04 

 

No problem, please see the below

 

Measure = 
VAR __date = SELECTEDVALUE( 'Table'[Date] )
VAR __allResource = ALLEXCEPT( 'Table', 'Table'[Resource] ) 
VAR __firstZero =  
    CALCULATE(
        MAX( 'Table'[Date] ),
        __allResource,
        'Table'[Date] <= __date,
        'Table'[Billable] = 0
    )
VAR __start = 
    IF( 
        ISBLANK( __firstZero ),  
        CALCULATE(
            MIN( 'Table'[Date] ),
            __allResource
        ),
        __firstZero
    )
RETURN 
CALCULATE(
    SUM( 'Table'[Billable] ),
    FILTER(
        ALL( 'Table'[Date] ),
        'Table'[Date] >= __start && 'Table'[Date] <= __date 
    )
)

 

Best Regards,
Mariusz

If this post helps, then please consider Accepting it as the solution.

Please feel free to connect with me.
LinkedIn

 

Thanku @Mariusz 

 

But I have a  concern. In measure _firstzero and _start variable are not getting adjusted with slider date selections at UI.

 

Regards

Vaishali Rathi

 

Hi @Vaishali04 

 

Ok, I've added ALLSELECTED

Measure = 
VAR __date = SELECTEDVALUE( 'Table'[Date] )
VAR __allResource = 
    CALCULATETABLE(
        'Table',
        ALLSELECTED( 'Table' ),
        VALUES( 'Table'[Resource] ) 
    )
VAR __firstZero =  
    CALCULATE(
        MAX( 'Table'[Date] ),
        __allResource,
        'Table'[Date] <= __date,
        'Table'[Billable] = 0
    )
VAR __start = 
    IF( 
        ISBLANK( __firstZero ),  
        CALCULATE(
            MIN( 'Table'[Date] ),
            __allResource
        ),
        __firstZero
    )
RETURN 
CALCULATE(
    SUM( 'Table'[Billable] ),
    FILTER(
        ALL( 'Table'[Date] ),
        'Table'[Date] >= __start && 'Table'[Date] <= __date 
    )
)

 

Best Regards,
Mariusz

If this post helps, then please consider Accepting it as the solution.

Please feel free to connect with me.
LinkedIn

 

Hi Mariusz ,

I am stuck with a similar kind of problem.

I have a table with columns (example dataset Mock_PBI (1).xlsx) - date of Purchase, Product ID, Product Price, and Product Number.

I am working on finding consecutive dates for each Product ID and then sum up the product price for those dates. The result would be something like:

rnd2789_0-1663644652953.png

It would be Really great if you can help me with the problem.

Thank You

Regards

Thanku @Mariusz for quick reply. Logic is really awsm.

 

But I  want the logic to work on dynamic date range. Can you please convert  your logic in a measure instead of a column. I am a  beginner in power bi so finding it hard to convert  as of now.

 

Thanks a ton 🙂

 

Regards

Vaishali 

 

 

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

Find out what's new and trending in the Fabric community.