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

DAX Rolling Median of a Measure by Time of Day

I'm trying to come up with a DAX measure that calculates a rolling median based on time of day (minute by minute).  I would so appreciate anyone's help.  Below is a sample table with random numbers. 

 

TimeCurrent Minute ValuePrevious Minute ValueChg PctABS Median Chg Pct
12:00:00 AM0.785711   
12:01:00 AM0.267750.78571165.92% 
12:02:00 AM0.7479330.26775179.34% 
12:03:00 AM0.5262950.74793329.63% 
12:04:00 AM0.785650.52629549.28% 
12:05:00 AM0.4577540.7856541.74% 
12:06:00 AM0.30220.45775433.98% 
12:07:00 AM0.5916530.302295.78% 
12:08:00 AM0.4735310.59165319.96% 
12:09:00 AM0.1670560.47353164.72% 
12:10:00 AM0.1651680.1670561.13% 
12:11:00 AM0.4432980.165168168.39% 
12:12:00 AM0.4298170.4432983.04% 
12:13:00 AM0.7547530.42981775.60% 
12:14:00 AM0.4052290.75475346.31% 
12:15:00 AM0.5651650.40522939.47%46.31%
12:16:00 AM0.6703370.56516518.61%41.74%
12:17:00 AM0.2740240.67033759.12%41.74%

 

First of all, I have a "Date" and "Day of Week" column that I purposely haven't added because I want to be able to add a filter visual to change to a different day of the week at will.  The time and value (current minute) columns are from the source table. The "previous minute value" is a calculated column that uses an index column with a lookup formula to display the previous minute value in the same row as the current minute value.  The "Chg Pct" is a measure that calculates the change in value from one minute to the next, and displays as an absolute number.  Here's the DAX measure:

 

CurPre =
var cur =
CALCULATE(
SUM(table[Current Minute Value]),
KEEPFILTERS(table)
)

var pre =
CALCULATE(
SUM(table[Prev Row]),
KEEPFILTERS(table)
)

return
ABS(DIVIDE(cur-pre,pre))
 
For one thing, the percentage change I get in DAX is different from the results I get in an Excel table.  I don't know if this DAX formula is set up right for this column anyway.
 
The last column in the table above are the results of a rolling median range.  "46.31%" is the median value for minutes from 12:15:00 AM back to 12:01:00 AM.  
 
The main issue is that I can't figure out how to create a minute-by-minute, rolling median column based on the "CurPre" measure in DAX.  I need to be able to calculate a rolling median of a measure that calculates minute-to-minute change percentage (15 total minutes at a time), and at the same time be able to select a different day of the week, and the times/values in the table switches to calculate the rolling median for that day of the week, and that time increment.  
 
Thank you for any advice you can provide!
1 ACCEPTED SOLUTION

Hi @jsflint ,

 

Sorry for not seeing your request clearly, this is a calculated column for rolling median.

Rolling Median =
IF (
    [Time] >= TIME ( 0, 15, 0 ),
    CALCULATE (
        MEDIAN ( 'Table'[Chg PctABS] ),
        FILTER (
            ALL ( 'Table' ),
            [Time]
                >= EARLIER ( 'Table'[Time] ) - TIME ( 0, 15, 0 )
                && [Time] <= EARLIER ( 'Table'[Time] )
        )
    )
)

25.png

 

Best Regards,

Stephen Tao

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

4 REPLIES 4
v-stephen-msft
Community Support
Community Support

Hi @jsflint ,

 

I got the Previous Minute Value column and Chg Pct ABS column by creating calculated columns.

First, I add an index column in Power Query.

Then

 

Previous Minute Value = CALCULATE(SUM('Table'[Current Minute Value]),FILTER('Table',[Index]=EARLIER('Table'[Index])-1))
Chg PctABS = ABS(DIVIDE(([Current Minute Value]-[Previous Minute Value]),[Previous Minute Value]))

 

9.png

 

The median of Chg Pct ABS, just use the MEDIAN function. Here I created the measure with MEDIAN.

10.png

 

 

Best Regards,

Stephen Tao

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Thanks, @v-stephen-msft .  It looks like your way (which is still great) comes to the same result as mine.  My goal is to generate a rolling median similar to a rolling average, and in a table and/or chart.

 

I do appreciate the application of EARLIER, though.  I've been trying to understand that particular function, and you've made it clear to me.

 

Do you know how I could add a column that will calculate a rolling median?  Thanks again!

Hi @jsflint ,

 

Sorry for not seeing your request clearly, this is a calculated column for rolling median.

Rolling Median =
IF (
    [Time] >= TIME ( 0, 15, 0 ),
    CALCULATE (
        MEDIAN ( 'Table'[Chg PctABS] ),
        FILTER (
            ALL ( 'Table' ),
            [Time]
                >= EARLIER ( 'Table'[Time] ) - TIME ( 0, 15, 0 )
                && [Time] <= EARLIER ( 'Table'[Time] )
        )
    )
)

25.png

 

Best Regards,

Stephen Tao

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

Thanks!

Helpful resources

Announcements
PBI User Groups

Welcome to the User Group Public Preview

Check out new user group experience and if you are a leader please create your group!

MBAS on Demand

Microsoft Business Applications Summit sessions

On-demand access to all the great content presented by the product teams and community members! #MSBizAppsSummit #CommunityRocks

MBAS Attendee Badge

Claim Your Badge & Digital Swag!

Check out how to claim yours today!

Top Solution Authors
Top Kudoed Authors