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
NicoleApple
New Member

7 day moving average

I am trying to urgently calculate a 7 day moving a average but im having issues. I could do it in Excel but i want to use Power BI to present the data instead and my DAX is a little rusty as i havent used it for 4 years!

I have created a formula as follows:

7 day moving average =
CALCULATE (
SUM ( 'PCR TEsting Data'[Total Volume of Tests (Excl. work in progress or tests referred out) (No.)] ) / 7,
DATESINPERIOD (
'PCR TEsting Data'[Relevant Date],
LASTDATE ( 'PCR TEsting Data'[Relevant Date] ),
-7,
DAY
) but it is coming up with an error saying "Argument 3 in Calculate function is required. Am i missing something here? 
1 ACCEPTED SOLUTION
Jihwan_Kim
Super User
Super User

Hi,

I do not fully understand the DAX formula, but I think it has to have one more  )  at the end of the formula.

 

 

7 day moving average =
CALCULATE (
    SUM ( 'PCR TEsting Data'[Total Volume of Tests (Excl. work in progress or tests referred out) (No.)] ) / 7,
    DATESINPERIOD (
        'PCR TEsting Data'[Relevant Date],
        LASTDATE ( 'PCR TEsting Data'[Relevant Date] ),
        -7,
        DAY
    )
)

 

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Go to My LinkedIn Page


View solution in original post

2 REPLIES 2
v-shex-msft
Community Support
Community Support

Hi @NicoleApple,

It seems like a DAX syntax issue that loses the right brackets at the end of your formula.  You can add it to the end to fix this issue.

7 day moving average =
CALCULATE (
    SUM ( 'PCR TEsting Data'[Total Volume of Tests (Excl. work in progress or tests referred out) (No.)] ) / 7,
    DATESINPERIOD (
        'PCR TEsting Data'[Relevant Date],
        LASTDATE ( 'PCR TEsting Data'[Relevant Date] ),
        -7,
        DAY
    )
)

If the above expression does not work, you can also try to use the date function to manually calculate the moving average.

7 day moving average =
VAR currDate =
    MAX ( 'PCR TEsting Data'[Relevant Date] )
VAR prevDate =
    DATE ( YEAR ( currDate ), MONTH ( currDate ), DAY ( currDate ) - 7 )
VAR summary =
    SUMMARIZE (
        FILTER (
            ALLSELECTED ( 'PCR TEsting Data' ),
            [Relevant Date] >= prevDate
                && [Relevant Date] <= currDate
        ),
        [Relevant Date],
        "Total", SUM ( 'PCR TEsting Data'[Total Volume of Tests] )
    )
RETURN
    AVERAGEX ( summary, [Total] )

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.
Jihwan_Kim
Super User
Super User

Hi,

I do not fully understand the DAX formula, but I think it has to have one more  )  at the end of the formula.

 

 

7 day moving average =
CALCULATE (
    SUM ( 'PCR TEsting Data'[Total Volume of Tests (Excl. work in progress or tests referred out) (No.)] ) / 7,
    DATESINPERIOD (
        'PCR TEsting Data'[Relevant Date],
        LASTDATE ( 'PCR TEsting Data'[Relevant Date] ),
        -7,
        DAY
    )
)

 

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Go to My LinkedIn Page


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.

Top Solution Authors