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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
WillemC
Resolver I
Resolver I

rolling sum: empty values in groups

Hi all,

 

I got a problem I can't wrap my head around.

I'm trying to create a rolling sum for the past 12 weeks.

I got sales data, which consists out of salesdate, productgroup, amount etc.

 

I created a datetable, which contains year-week numbers, first day of the week for a date, last date of the week for a date etc.

This datetable is over the same period as the salesdates, so that I have ALL the dates available.

In the salesdata, dates may be missing due to no sales, weekends etc.

 

My datatable:

Datumtabel = ADDCOLUMNS(
    CALENDAR( min(OMZETFEED[LEVDAT]) ; DATE( YEAR(TODAY() );12;31) ) ;
    "Jaar";year( [Date] );
    "Maandomschr."; FORMAT( [Date] ; "mmm");
    "Maandnr" ; month( [Date] );
    "Kwartaal-Jaar"; format( [Date] ; "\QQ") & "-" & year([Date]);
    "ISOWeeknr" ; WEEKNUM([Date];21);
    "ThisYear" ; if ([Date] >= DATE(YEAR(TODAY());1;1) && [Date] <= TODAY(); 1; 0);
    "Weekend/werkdag" ; if(WEEKDAY([Date];2)<6;"Werkdag" ; "Weekend");
    "Iso Year" ; IF( AND(WEEKNUM([Date];21) < 5;WEEKNUM([Date];2) > 50);year([Date])+1;IF(AND(WEEKNUM([Date];21) > 50;WEEKNUM([Date];2) < 5);year([Date])-1;year([Date])));
    "Week-Jaar"; IF( AND(WEEKNUM([Date];21) < 5;WEEKNUM([Date];2) > 50);year([Date])+1;IF(AND(WEEKNUM([Date];21) > 50;WEEKNUM([Date];2) < 5);year([Date])-1;year([Date]))) & 
    if(
    Weeknum([Date];21)<10;"0";blank())&WEEKNUM([Date];21);
    "WeekEndDate";[Date]-MOD([Date]-1;7)+7;
    "WeekStartDate";[Date]-MOD([Date]-1;7)+1
     )

 

When I create a rolling sum over the past 12 weeks (7x12=84 days) and I split these up in the productGroups, some groups show empty values in a matrix for the week in which they haven't been sold.

 

So for example, in week 12 there has been no sales for productgroup D. The matrix and graphs show a blank value.

But instead I want to show the sum of the weeks 1-12 (as soon as one week has a sale, during the next 12 weeks there should always be a value).

Only if a productgroup hasn't been sold during 12 weeks, then it's allowed to show blank or null, because sum sales over the last 12 weeks have indeed been none.

 

How should I do this? I tried different DAX formulas, but I'm not able to get this working.

I prefer to use full weeks, that's why I added the lastdate (of the week that date is in).

 

 

1 ACCEPTED SOLUTION
WillemC
Resolver I
Resolver I

Okay, seems that I found the solution.

I was using a column value to calculate instead of a measure...

 

The following measure did what I wanted (except it allready creates a sum for the future 12 weeks)
But this I could solve by filtering the matrix/graph to end at the current week.

SUM Last 3M = 
CALCULATE (
    SUM( Sales[WEIGHT] );
    FILTER(ALL(Datumtabel[Date]);
          Datumtabel[Date] <= MAX(Datumtabel[Date]) 
          &&  
          DATEADD(Datumtabel[Date];84;DAY) >= MAX(Datumtabel[Date]      
    )
     )
      )

 

Little side note, it's posible to use MIN instead of MAX, then it shows the sum of the previous 12 weeks instead of current + 11 weeks earlier.

View solution in original post

2 REPLIES 2
WillemC
Resolver I
Resolver I

Okay, seems that I found the solution.

I was using a column value to calculate instead of a measure...

 

The following measure did what I wanted (except it allready creates a sum for the future 12 weeks)
But this I could solve by filtering the matrix/graph to end at the current week.

SUM Last 3M = 
CALCULATE (
    SUM( Sales[WEIGHT] );
    FILTER(ALL(Datumtabel[Date]);
          Datumtabel[Date] <= MAX(Datumtabel[Date]) 
          &&  
          DATEADD(Datumtabel[Date];84;DAY) >= MAX(Datumtabel[Date]      
    )
     )
      )

 

Little side note, it's posible to use MIN instead of MAX, then it shows the sum of the previous 12 weeks instead of current + 11 weeks earlier.

Just one more note. Because of the extra weeks added, which I didn't want, I altered my calendar code and SUM-code.

The datetable code has been altered, so the last day created in this datatable, is the last weekday of the maximum salesdate:

 

 

Datumtabel = ADDCOLUMNS(
    CALENDAR( min(OMZETFEED[LEVDAT]) ; max(OMZETFEED[LEVDAT])-MOD(max(OMZETFEED[LEVDAT])-1;7)+7 ) ;
    "Jaar";year( [Date] );
    "Maandomschr."; FORMAT( [Date] ; "mmm");
    "Maandnr" ; month( [Date] );
    "Kwartaal-Jaar"; format( [Date] ; "\QQ") & "-" & year([Date]);
    "ISOWeeknr" ; WEEKNUM([Date];21);
    "ThisYear" ; if ([Date] >= DATE(YEAR(TODAY());1;1) && [Date] <= TODAY(); 1; 0);
    "Weekend/werkdag" ; if(WEEKDAY([Date];2)<6;"Werkdag" ; "Weekend");
    "Iso Year" ; IF( AND(WEEKNUM([Date];21) < 5;WEEKNUM([Date];2) > 50);year([Date])+1;IF(AND(WEEKNUM([Date];21) > 50;WEEKNUM([Date];2) < 5);year([Date])-1;year([Date])));
    "Week-Jaar"; IF( AND(WEEKNUM([Date];21) < 5;WEEKNUM([Date];2) > 50);year([Date])+1;IF(AND(WEEKNUM([Date];21) > 50;WEEKNUM([Date];2) < 5);year([Date])-1;year([Date]))) & 
    if(
    Weeknum([Date];21)<10;"0";blank())&WEEKNUM([Date];21);
    "WeekEndDate";[Date]-MOD([Date]-1;7)+7;
    "WeekStartDate";[Date]-MOD([Date]-1;7)+1
     )

 

 

I've altered the measure to the following code, to get the correct sum values of that week and previous 12 weeks (so 13 weeks in total):

 

SUM Last 13WKS = 
CALCULATE (
    SUM( OMZETFEED[GEWICHT] );
          DATESBETWEEN(Datumtabel[Date];FIRSTDATE(DATEADD(Datumtabel[Date];-84;DAY));LASTDATE(Datumtabel[Date])
    ))

 

 
This is the result of the start & end period created with this formula:
To create this table create 2 measures:

FirstDate = FIRSTDATE(DATEADD(Datumtabel[Date];-84;DAY))
and a measure:
LastDate = LASTDATE(Datumtabel[Date])
 

Periods.JPG

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.