Check your eligibility for this 50% exam voucher offer and join us for free live learning sessions to get prepared for Exam DP-700.
Get StartedDon't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.
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,
Solved! Go to Solution.
@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)
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:
(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:
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
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:
(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:
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:
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.
@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)
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.
User | Count |
---|---|
20 | |
14 | |
11 | |
8 | |
6 |
User | Count |
---|---|
23 | |
23 | |
20 | |
15 | |
10 |