The ultimate Fabric, Power BI, SQL, and AI community-led learning event. Save €200 with code FABCOMM.
Get registeredEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
Hello all,
I am a newbie in DAX and have the following question.
I have calculated correlation coefficient (r) using the below formula. It gives correct result with single quarter selected but gives wrong result with multiple quarters selected. I believe this is due to the use of MAX function in the formula. The use case is to get correct r value for multiple quarters. What other way can I achieve this? Appreciate your help!
The image below has correct r value
The image below has wrong r value
Below is the formula for r
R =
VAR Correlation_Table =
FILTER (
SUMMARIZE( FILTER(ALL(Data),Data[Segment] = MAX(Data[Segment])
&& Data[Fiscal Year] = MAX(Data[Fiscal Year])
&& Data[Fiscal Quarter] = MAX(Data[Fiscal Quarter])
&& Data[Weeks]in ALLSELECTED(Data[Weeks])),
Data[Segment],Data[Fiscal Year],Data[Fiscal Quarter],Data[Weeks],
"Value_X", sum(Data[Calls]),
"Value_Y", sum(Data[Sales])
),
AND (
NOT ( ISBLANK ( [Value_X] ) ),
NOT ( ISBLANK ( [Value_Y] ) )
)
)
VAR Count_Items =
COUNTROWS ( Correlation_Table )
VAR Sum_X =
SUMX ( Correlation_Table, [Value_X] )
VAR Sum_X2 =
SUMX ( Correlation_Table, [Value_X] ^ 2 )
VAR Sum_Y =
SUMX ( Correlation_Table, [Value_Y] )
VAR Sum_Y2 =
SUMX ( Correlation_Table, [Value_Y] ^ 2 )
VAR Sum_XY =
SUMX ( Correlation_Table, [Value_X] * [Value_Y] )
VAR Pearson_Numerator =
Count_Items * Sum_XY - Sum_X * Sum_Y
VAR Pearson_Denominator_X =
Count_Items * Sum_X2 - Sum_X ^ 2
VAR Pearson_Denominator_Y =
Count_Items * Sum_Y2 - Sum_Y ^ 2
VAR Pearson_Denominator =
SQRT ( Pearson_Denominator_X * Pearson_Denominator_Y )
RETURN
DIVIDE ( Pearson_Numerator, Pearson_Denominator )
Thank you,
Pranoti
Solved! Go to Solution.
@pranotid29 , Try with this summarize, rest same
SUMMARIZE( ALLSELECTED(Data),Data[Segment] ,Data[Fiscal Year] ,Data[Fiscal Quarter] , Data[Weeks],
"Value_X", sum(Data[Calls]),
"Value_Y", sum(Data[Sales])
)
Hi, @pranotid29 ;
Is your problem solved?? If so, Would you mind accept the helpful replies as solutions? Then we are able to close the thread. More people who have the same requirement will find the solution quickly and benefit here. Thank you.
Best Regards,
Community Support Team_ Yalan Wu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi, @pranotid29 ;
Please try it .
R =
VAR Correlation_Table =
FILTER (
SUMMARIZE (
FILTER(ALLSELECTED(Data),Data[Segment] = MAX ( Data[Segment] )
&& Data[Fiscal Year] = MAX ( Data[Fiscal Year] )),
Data[Segment],
Data[Fiscal Year],
Data[Fiscal Quarter],
Data[Weeks],
"Value_X", SUM ( Data[Calls] ),
"Value_Y", SUM ( Data[Sales] )
),
AND ( NOT ( ISBLANK ( [Value_X] ) ), NOT ( ISBLANK ( [Value_Y] ) ) )
)
VAR Count_Items =
COUNTROWS ( Correlation_Table )
VAR Sum_X =
SUMX ( Correlation_Table, [Value_X] )
VAR Sum_X2 =
SUMX ( Correlation_Table, [Value_X] ^ 2 )
VAR Sum_Y =
SUMX ( Correlation_Table, [Value_Y] )
VAR Sum_Y2 =
SUMX ( Correlation_Table, [Value_Y] ^ 2 )
VAR Sum_XY =
SUMX ( Correlation_Table, [Value_X] * [Value_Y] )
VAR Pearson_Numerator = Count_Items * Sum_XY - Sum_X * Sum_Y
VAR Pearson_Denominator_X = Count_Items * Sum_X2 - Sum_X ^ 2
VAR Pearson_Denominator_Y = Count_Items * Sum_Y2 - Sum_Y ^ 2
VAR Pearson_Denominator =
SQRT ( Pearson_Denominator_X * Pearson_Denominator_Y )
VAR _A=
DIVIDE ( Pearson_Numerator, Pearson_Denominator )
RETURN Sum_X
If not right ,can you share simple file after removing the sensetive information?
Best Regards,
Community Support Team_ Yalan Wu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
@pranotid29 , Try with this summarize, rest same
SUMMARIZE( ALLSELECTED(Data),Data[Segment] ,Data[Fiscal Year] ,Data[Fiscal Quarter] , Data[Weeks],
"Value_X", sum(Data[Calls]),
"Value_Y", sum(Data[Sales])
)
User | Count |
---|---|
79 | |
73 | |
39 | |
30 | |
28 |
User | Count |
---|---|
108 | |
99 | |
55 | |
49 | |
46 |