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

Unorthodox Median Calculation

Hi,

 

In Direct Query mode, is there a way to calculate median numbers such that if the number of values selected is odd then the middle one will become the median. If the number of values chosen are odd, then the median would become the value of the "upper" median value instead of being an average. For instance, if the numbers chosen are : 1, 3, 4, 6. The median of this set of numbers is 4.

If the numbers chosen were 1, 3, and 4, then the 3 would be chosen/displayed as the median.Capture.PNG

In this case, the number that should be chosen is 2.333. 

1 ACCEPTED SOLUTION
Super User I
Super User I

 

Hi again,

It turns out you can do something like this, assuming you have enabled all functions in DirectQuery.

 

I have taken this code basically verbatim from

https://www.daxpatterns.com/statistical-patterns/#median22

 

Median Unorthodox =
VAR NumValuesHalved = COUNT ( YourTable[Latency] ) / 2
RETURN
    MINX (
        FILTER (
            VALUES ( YourTable[Latency] ),
            CALCULATE (
                COUNT ( YourTable[Latency] ),
                YourTable[Latency] <= EARLIER ( YourTable[Latency] )
            )
                > NumValuesHalved
        ),
        YourTable[Latency]
    )

 The code produces the "upper" median value in the case of an even number of items, otherwise produces the middle value.

 

Regards,

Owen 🙂


Owen Auger

Did I answer your question? Mark my post as a solution!

Connect on Twitter
Connect on LinkedIn

View solution in original post

2 REPLIES 2
Super User I
Super User I

 

Hi again,

It turns out you can do something like this, assuming you have enabled all functions in DirectQuery.

 

I have taken this code basically verbatim from

https://www.daxpatterns.com/statistical-patterns/#median22

 

Median Unorthodox =
VAR NumValuesHalved = COUNT ( YourTable[Latency] ) / 2
RETURN
    MINX (
        FILTER (
            VALUES ( YourTable[Latency] ),
            CALCULATE (
                COUNT ( YourTable[Latency] ),
                YourTable[Latency] <= EARLIER ( YourTable[Latency] )
            )
                > NumValuesHalved
        ),
        YourTable[Latency]
    )

 The code produces the "upper" median value in the case of an even number of items, otherwise produces the middle value.

 

Regards,

Owen 🙂


Owen Auger

Did I answer your question? Mark my post as a solution!

Connect on Twitter
Connect on LinkedIn

View solution in original post

Thanks so much for your help. I can't even begin to tell you how much time I spent trying to google the answer and find out. Cheers

Helpful resources

Announcements
secondImage

Happy New Year from Power BI

This is a must watch for a message from Power BI!

December Update

Check it Out!

Click here to read more about the December 2020 Updates!

Community Blog

Check it Out!

Click here to read the latest blog and learn more about contributing to the Power BI blog!

Get Ready for Power BI Dev Camp

Get Ready for Power BI Dev Camp

Mark your calendars and join us for our next Power BI Dev Camp!.

Top Solution Authors
Top Kudoed Authors