cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
DavidS524 Regular Visitor
Regular Visitor

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

Accepted Solutions
Community Support Team
Community Support Team

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

Hi @DavidS524

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
DavidS524 Regular Visitor
Regular Visitor

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

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

Community Support Team
Community Support Team

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

Hi @DavidS524

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

DavidS524 Regular Visitor
Regular Visitor

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

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

Helpful resources

Announcements
Can You Solve These Challenge

Challenge: Can You Solve These?

Find out how to participate in the first Power BI 'Can You Solve These?' challenge.

Community News & Announcements

Community News & Announcements

Get your latest community news and announcements.

Virtual Launch Event

Microsoft Business Applications October Virtual Launch Event

Join us for an in-depth look at the new innovations across Dynamics 365 and the Microsoft Power Platform.

Community Kudopalooza

Win Power BI Swag with Community Kudopalooza!

Each week, complete activities and be qualified in the drawing for cool Power BI Swag.

Users Online
Currently online: 41 members 972 guests
Please welcome our newest community members: