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
adrianonannini
Frequent Visitor

Standard Deviation - last 7 days

I have a Sales table that is on an Order/Product level. This is the essential information:

Receipt_DateOrder_idSKU_CodeRegionCountryChannelUnits
01/01/2023XYZ123AsiaJapanRetail3
01/01/2023XYZ878AsiaJapanRetail1
01/01/2023ABC123EuropeUKDigital2
02/01/2023PQP420EuropeGermanyRetail5

 

As you can see:

- Each row of my table represents a product present in one order. So if a transaction (XYZ, on my example above) had more than 1 product, there will be one row for each product.

- If there was more than one unit of a product being sold on the transaction, it will be populated on the Units column (like orders XYZ, ABC and PQP).

 

On PowerBI, I am trying to sum the units for the last 7 days (which I had no trouble doing), and I want to get a standard deviation of units sold in the past 7 days (current day + 6 days prior to current day).

With that information, I will use different visualisation tools - line charts, tables, etc.

My problem with using STDEV.P(Units) is that it will calculate the standard deviation on a row level. And I need to do that on a daily level + considering the last 7 days as the population.

I also need to allow my users to filter this information by region, channel, country, etc, so I cannot work with daily aggregations.

 

Any ideas?

2 REPLIES 2
adrianonannini
Frequent Visitor

Whilst it didn't completely solved my challenge, your post did spark some inspiration that helped me getting there:

 

7D StDev =
VAR CurrentDate = MAX('Date Dim'[Report Date])
RETURN
    STDEVX.P(
        FILTER(
            ALL('Date Dim'),
            'Date Dim'[Report Date] >= CurrentDate - 6 && 'Date Dim'[Report Date] <= CurrentDate
        ),
        CALCULATE(SUM('--Sales'[sales_units]))
    )
 
It's working perfectly. Thank you!
OwenAuger
Super User
Super User

Hi @adrianonannini 

You can use STDEVX.P for this, iterating over dates.

I'm going to assume you have a Date table (marked as a Date table) created with relationship to Sales[Receipt_Date].

Also say you have a measure

Units Sum = 
SUM ( Sales[Units] )

Then create a measure like this:

Units Standard Deviation (7 days) = 
CALCULATE (
    STDEVX.P (
        VALUES ( 'Date'[Date] ),
        [Units Sum]
    ),
    DATESINPERIOD ( 'Date'[Date], TODAY (), -7, DAY )
)

A shortened version that would also work:

Units Standard Deviation (7 days) v2 = 
STDEVX.P (
    DATESINPERIOD ( 'Date'[Date], TODAY (), -7, DAY ),
    [Units Sum]
)

 

Does this method work for you?

Regards


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

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