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

Calling all Data Engineers! Fabric Data Engineer (Exam DP-700) live sessions are back! Starting October 16th. Sign up.

Reply
Anonymous
Not applicable

Moving average calculation with sum of two columns, excluding zeros.

Hi everyone,

 

I am pretty new to PowerBI and DAX, so I really appreciate the help here. I did a search, and while there were many examples of moving averages I did not see anything that matched my situation exactly.

 

Basically I have two values in two different columns that I want to add together, and then calculate an average based on the last three months. To do this I am currently using this formula to create the measure, which seems to be working:

 

3M_AVG_Count = CALCULATE(SUM(Table[Count1]) + SUM(Table[Count2]),DATESINPERIOD(Table[DataPeriod], LASTDATE([DataPeriod]),-3,MONTH))/3

 

The problem is that this method includes months with 0 sums of Count1 and Count2. The data looks something like this:

 

SampleData.PNG

 

In cases where the SUM of Count1 and Count2 for a given month equal 0, I want to exclude this month/record from the average calculation. For example in the data above, rather than calculating the average for the last three months for Client1, I want to pretend that Month 2 does not exist. Averaging Months 1 & 3 instead. This will still be considered the average for the last three months.

 

I think what I need here is some kind of IF statement that will determine whether to divide by 1, 2, 3, etc, but I'm not sure how to implement that correctly.

 

Hopefully that makes sense. If more clarification is needed please just let me know.

 

Thank you!!

1 ACCEPTED SOLUTION
v-juanli-msft
Community Support
Community Support

Hi @Anonymous

Measures

sum = SUM(Sheet2[count1])+SUM(Sheet2[count2])

total = CALCULATE([sum],ALLEXCEPT(Sheet2,Sheet2[client]),DATESINPERIOD(Sheet2[dateperiod],MAX(Sheet2[dateperiod]),-3,MONTH))

without0 = IF([sum]<>0,[sum])

countrows = CALCULATE(COUNT(Sheet2[dateperiod]),FILTER(ALLEXCEPT(Sheet2,Sheet2[client]),[without0]<>BLANK()),DATESINPERIOD(Sheet2[dateperiod],MAX(Sheet2[dateperiod]),-3,MONTH))

final results = IF([total]<>0,[total]/[countrows],0)

1.png

 

 

Best Regards

Maggie

View solution in original post

3 REPLIES 3
v-juanli-msft
Community Support
Community Support

Hi @Anonymous

Measures

sum = SUM(Sheet2[count1])+SUM(Sheet2[count2])

total = CALCULATE([sum],ALLEXCEPT(Sheet2,Sheet2[client]),DATESINPERIOD(Sheet2[dateperiod],MAX(Sheet2[dateperiod]),-3,MONTH))

without0 = IF([sum]<>0,[sum])

countrows = CALCULATE(COUNT(Sheet2[dateperiod]),FILTER(ALLEXCEPT(Sheet2,Sheet2[client]),[without0]<>BLANK()),DATESINPERIOD(Sheet2[dateperiod],MAX(Sheet2[dateperiod]),-3,MONTH))

final results = IF([total]<>0,[total]/[countrows],0)

1.png

 

 

Best Regards

Maggie

Anonymous
Not applicable

Hi @v-juanli-msft

 

Thank you so much for this! I was able to get it working with my data. I really appreciate the help!

 

Thanks again,

David

Anonymous
Not applicable

It took a day for my post/account to be approved, so I'm just bumping this for visibility. Thanks, everyone!

Helpful resources

Announcements
FabCon Global Hackathon Carousel

FabCon Global Hackathon

Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes!

October Power BI Update Carousel

Power BI Monthly Update - October 2025

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

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.