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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
VV24
Helper III
Helper III

Sum value from one column checking if previous month the value was identical

Dear all,

 

In my table (see below) I have two cases, I would like to sum the cumulative days per Key over the different months, but only when the row is flagged as 1, if it reaches 0 in a certain point of time the sum starts over and stays zero until there is another flag with 1.  In the table below i also added the requested column:

 

DateYMKeyFlagDays in monthCalccalculation:
1-1-20191901A1316231+31
1-1-20191901B0310 
1-12-20181812A13131 
1-12-20181812B1316130+31
1-11-20181811A0300 
1-11-20181811B13030 
1-10-20181810A13131 
1-10-20181810B0310 

 

Can someone help me get the requested column calculation. Thanks.

 

 

1 ACCEPTED SOLUTION

Hi @VV24 

Try this for a calculated column in your table (Table1). See it at work in the attached file.

NewColumn =
VAR _PreviousZeroDate =
    LASTNONBLANK (
        CALCULATETABLE (
            DISTINCT ( Table1[Date] );
            ALLEXCEPT ( Table1; Table1[Key] );
            Table1[Flag] = 0;
            Table1[Date] < EARLIER ( Table1[Date] )
        );
        1
    )
RETURN
    IF (
        Table1[Flag] = 0;
        0;
        CALCULATE (
            SUM ( Table1[Days in month] );
            ALLEXCEPT ( Table1; Table1[Key] );
            Table1[Date] <= EARLIER ( Table1[Date] );
            Table1[Date] > _PreviousZeroDate
        )
    )

View solution in original post

4 REPLIES 4
Anonymous
Not applicable

@VV24  - 

Please try the following:

Running Total With Reset = 
var currentmonth = max(Resetting[YM])
var lastzero = CALCULATE(MAX(Resetting[YM]), ALLEXCEPT(Resetting, Resetting[Key]), Resetting[YM] <= currentmonth, Resetting[Flag] = 0)
var calc = CALCULATE(SUM(Resetting[Days in month]), filter(ALLEXCEPT(Resetting, Resetting[Key]),Resetting[YM] > lastzero && Resetting[YM] <= currentmonth))
return IF(ISBLANK(calc),0,calc)

Hope this helps,

Nathan

Hi @VV24 

Try this for a calculated column in your table (Table1). See it at work in the attached file.

NewColumn =
VAR _PreviousZeroDate =
    LASTNONBLANK (
        CALCULATETABLE (
            DISTINCT ( Table1[Date] );
            ALLEXCEPT ( Table1; Table1[Key] );
            Table1[Flag] = 0;
            Table1[Date] < EARLIER ( Table1[Date] )
        );
        1
    )
RETURN
    IF (
        Table1[Flag] = 0;
        0;
        CALCULATE (
            SUM ( Table1[Days in month] );
            ALLEXCEPT ( Table1; Table1[Key] );
            Table1[Date] <= EARLIER ( Table1[Date] );
            Table1[Date] > _PreviousZeroDate
        )
    )

@Anonymous 

I believe you need a small change in your currentmonth variable. You need the YM value for the current row rather than for the whole table, so either:

var currentmonth = CALCULATE(max(Resetting[YM]))

based on what you already have or, more straightforwardly:

var currentmonth = Resetting[YM]

With that minor modification it should work and in fact your way of getting the last zero is actually more elegant and efficient than mine.

Cheers
 
Anonymous
Not applicable

@AlB -

Thanks for the feedback. I should have clarified that I was creating a Measure. Most likely, @VV24  would prefer the Calculated Column route, unless it needs to be dynamic for some reason. 

 

@VV24  - The code I wrote was for a Measure. You could use the same code in a Calculated Column if you make the change that @AlB suggested.

 

Cheers!

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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