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
Artemis1254
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
OwenAuger
Super User
Super User

 

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!
Blog
Twitter
LinkedIn

View solution in original post

2 REPLIES 2
OwenAuger
Super User
Super User

 

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!
Blog
Twitter
LinkedIn

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
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.