Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
AdamWhittaker
Helper I
Helper I

Flag outliers in table visulization (one column of values)

Hello,

I am trying to flag outliers in a single column to determine which ones are different (on average) to the others. I have a column which would look similar to this:

2.979167
2.957222
2.993056
2.983056
2.988889
2.961389
2.982361
2.982778
2.985
2.968611
2.969167
2.996667
2.981111
-0.02056
2.979444
15.57361
2.984167
2.998611
2.999444
2.993889
2.974167
2.983611
2.970833
2.9775
2.993333
2.974167
2.965278
2.996667
2.993333

Here I would want to flag:

5.964722222

-0.020555556

15.57361111

 

I tired the following formulae, but it only seems to flag the 5.x value:

 

Outliers =

var avera = CALCULATE(AVERAGEX('Time Info','Time Info'[time difference]),'Time Info'[time difference] <> Blank())

var stdv = CALCULATE(STDEVX.P('Time Info','Time Info'[time difference]),'Time Info'[time difference] <> Blank())

return (SUMX('Time Info','Time Info'[time difference])- avera)/stdv

 

I want to use the measure in 1 table to flag the outliers and in another to just show the outliers.

Thanks,

2 ACCEPTED SOLUTIONS
Greg_Deckler
Super User
Super User

@AdamWhittaker Try:

Flag = 
    VAR __Avg = AVERAGEX(ALL('Table'),[Value])
    VAR __StdDev = STDEVX.P(ALL('Table'),[Value])
    VAR __Value = MAX('Table'[Value])
    VAR __High = __Avg + __StdDev
    VAR __Low = __Avg - __StdDev
RETURN
    IF(__Value > __High || __Value < __Low,1,0)

@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
Mastering Power BI 2nd Edition

DAX is easy, CALCULATE makes DAX hard...

View solution in original post

v-yueyunzh-msft
Community Support
Community Support

Hi, @AdamWhittaker 

According to your description,you want to mark values that deviate from the mean. As for your way of judging cheap, my idea is that you can find the value closest to the mean and then define a rule (like deviating from that value by more than 10% mark it as a deviating value). Right?

Here are the steps you can follow:

(1)This is my test data:

vyueyunzhmsft_0-1663306793878.png

 

vyueyunzhmsft_1-1663306793880.png

 

(2)We can create a measure : “flag”

flag = var _average=CALCULATE( AVERAGEX('test',[value]),'test'[value]<>BLANK(),ALL('test'))

var _table = SUMMARIZE( ALL('test') , 'test'[value] ,"abs", ABS( _average-[value]))

var _min_abs = MINX(_table , [abs])

var _t_min_value =SELECTCOLUMNS( FILTER( _table , [abs] =_min_abs ) ,"value" , [value] )

var _close_value = AVERAGEX(_t_min_value , [value])

return

IF( MAX('test'[value]) < _close_value*1.1 &&MAX('test'[value])> _close_value * 0.9 ,1,0)

 

(3) Then we can meet your need , the result is as follows:

vyueyunzhmsft_2-1663306793882.png

 

If this method does not meet your needs, you can provide us with your special sample data and the desired output sample data in the form of tables, so that we can better help you solve the problem.

 

Best Regards,

Aniya Zhang

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

5 REPLIES 5
v-yueyunzh-msft
Community Support
Community Support

Hi, @AdamWhittaker 

According to your description,you want to mark values that deviate from the mean. As for your way of judging cheap, my idea is that you can find the value closest to the mean and then define a rule (like deviating from that value by more than 10% mark it as a deviating value). Right?

Here are the steps you can follow:

(1)This is my test data:

vyueyunzhmsft_0-1663306793878.png

 

vyueyunzhmsft_1-1663306793880.png

 

(2)We can create a measure : “flag”

flag = var _average=CALCULATE( AVERAGEX('test',[value]),'test'[value]<>BLANK(),ALL('test'))

var _table = SUMMARIZE( ALL('test') , 'test'[value] ,"abs", ABS( _average-[value]))

var _min_abs = MINX(_table , [abs])

var _t_min_value =SELECTCOLUMNS( FILTER( _table , [abs] =_min_abs ) ,"value" , [value] )

var _close_value = AVERAGEX(_t_min_value , [value])

return

IF( MAX('test'[value]) < _close_value*1.1 &&MAX('test'[value])> _close_value * 0.9 ,1,0)

 

(3) Then we can meet your need , the result is as follows:

vyueyunzhmsft_2-1663306793882.png

 

If this method does not meet your needs, you can provide us with your special sample data and the desired output sample data in the form of tables, so that we can better help you solve the problem.

 

Best Regards,

Aniya Zhang

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

Hello,

I am trying to flag outliers in a single column to determine which ones are different (on average) from the others. I have a column that would look similar to this:

 

Sawood_0-1692944591386.png

 

the highlighted ones are the outliners, kindly help with a solution.

 

 

 

 

 

Hi Aniya, thank you very much for the explaination and code, i ended up using both yours and @Greg_Deckler with a bit more summarizing and got what i needed.  Not sure who's to accept 🙂 Thanks again.

Greg_Deckler
Super User
Super User

@AdamWhittaker Try:

Flag = 
    VAR __Avg = AVERAGEX(ALL('Table'),[Value])
    VAR __StdDev = STDEVX.P(ALL('Table'),[Value])
    VAR __Value = MAX('Table'[Value])
    VAR __High = __Avg + __StdDev
    VAR __Low = __Avg - __StdDev
RETURN
    IF(__Value > __High || __Value < __Low,1,0)

@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
Mastering Power BI 2nd Edition

DAX is easy, CALCULATE makes DAX hard...

Hi Greg, thank you very much for the code, i ended up using both yours and @v-yueyunzh-msft with a bit more summarizing and got what i needed.  Not sure who's to accept 🙂 Thanks again.

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

Find out what's new and trending in the Fabric Community.

Top Solution Authors