Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
Hi - I am looking for some advice / guidance on how to solve the following DAX challenge
Goal: To group the meetings by cycle to find the difference between the score of their first meeting of the cycle and their last.
The yellow columns are what I'd like to achieve:
Plus a measure to calculate the score difference.
Include = only includes cycle's where there is a pair
Cycle = The meeting type needs to be part of one of the following pairs:
A & D
A & B
A & C
B & D
Thank you!
Solved! Go to Solution.
Hi @h4n1234 ,
I have created many measures to achieve such output, please follow:
Rank by Type = RANKX(FILTER(ALL('Table'),[AttendeeID]=MAX('Table'[AttendeeID])),CALCULATE(MAX('Table'[Meeting Type])),,ASC,Dense)
Start Flag =
var _pre= MAXX(FILTER(ALL('Table'),[AttendeeID]=MAX('Table'[AttendeeID]) && [AttendeeIndex]=MAX('Table'[AttendeeIndex])-1),[Rank by Type])
return
SWITCH(TRUE(), MAX('Table'[AttendeeIndex])=1,1, _pre>[Rank by Type],1)
each pair start rank =
var _rank=RANKX(FILTER(ALL('Table'),[AttendeeID]=MAX('Table'[AttendeeID]) && [Start Flag]=1),CALCULATE( MAX('Table'[AttendeeIndex])),,ASC,Dense)
return IF([Start Flag]<>BLANK(),_rank,BLANK())
End Flag =
var _next= MAXX(FILTER(ALL('Table'),[AttendeeID]=MAX('Table'[AttendeeID]) && [AttendeeIndex]=MAX('Table'[AttendeeIndex])+1),[Rank by Type])
return
SWITCH(TRUE(), _next<>BLANK()&& _next<[Rank by Type],1 , _next=BLANK(),1)
each pair end rank =
var _rank=RANKX(FILTER(ALL('Table'),[AttendeeID]=MAX('Table'[AttendeeID]) && [End Flag]=1),CALCULATE( MAX('Table'[AttendeeIndex])),,ASC,Dense)
return IF([End Flag]<>BLANK(),_rank,BLANK())
Now we could calcualte the Cycle and Include:
Cycle = IF([each pair start rank]<>BLANK(),[each pair start rank],IF([each pair end rank]<>BLANK(),[each pair end rank]))
Include = IF( OR([each pair start rank],[each pair end rank])=FALSE() || [each pair start rank]=[each pair end rank] ,BLANK(),1)
Best Regards,
Eyelyn Qin
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @v-eqin-msft
I still need to add in some more logic to get the whole solution working but your DAX helped me to develop the foundation DAX - really appreciate your help.
Hi @h4n1234 ,
I have created many measures to achieve such output, please follow:
Rank by Type = RANKX(FILTER(ALL('Table'),[AttendeeID]=MAX('Table'[AttendeeID])),CALCULATE(MAX('Table'[Meeting Type])),,ASC,Dense)
Start Flag =
var _pre= MAXX(FILTER(ALL('Table'),[AttendeeID]=MAX('Table'[AttendeeID]) && [AttendeeIndex]=MAX('Table'[AttendeeIndex])-1),[Rank by Type])
return
SWITCH(TRUE(), MAX('Table'[AttendeeIndex])=1,1, _pre>[Rank by Type],1)
each pair start rank =
var _rank=RANKX(FILTER(ALL('Table'),[AttendeeID]=MAX('Table'[AttendeeID]) && [Start Flag]=1),CALCULATE( MAX('Table'[AttendeeIndex])),,ASC,Dense)
return IF([Start Flag]<>BLANK(),_rank,BLANK())
End Flag =
var _next= MAXX(FILTER(ALL('Table'),[AttendeeID]=MAX('Table'[AttendeeID]) && [AttendeeIndex]=MAX('Table'[AttendeeIndex])+1),[Rank by Type])
return
SWITCH(TRUE(), _next<>BLANK()&& _next<[Rank by Type],1 , _next=BLANK(),1)
each pair end rank =
var _rank=RANKX(FILTER(ALL('Table'),[AttendeeID]=MAX('Table'[AttendeeID]) && [End Flag]=1),CALCULATE( MAX('Table'[AttendeeIndex])),,ASC,Dense)
return IF([End Flag]<>BLANK(),_rank,BLANK())
Now we could calcualte the Cycle and Include:
Cycle = IF([each pair start rank]<>BLANK(),[each pair start rank],IF([each pair end rank]<>BLANK(),[each pair end rank]))
Include = IF( OR([each pair start rank],[each pair end rank])=FALSE() || [each pair start rank]=[each pair end rank] ,BLANK(),1)
Best Regards,
Eyelyn Qin
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
So now I want to find the difference between the first score of a cycle and the last (where include = 1). And then plot the values on a graph.
Any ideas how I'd go about this?
I've tried switch statements to get the first and last scores but this will not format in a graph (it is also very slow) - thanks in advance!
8. First Score =
VAR _score =
SWITCH (
TRUE (),
[2. Start Flag] = 1
&& [7. Include] = 1, SUM ( 'Table'[Score] ),
BLANK ()
)
RETURN
_score
wow - thank you Eyelyn! I'll take a look at this today.
Check out the September 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
109 | |
97 | |
95 | |
38 | |
36 |
User | Count |
---|---|
150 | |
124 | |
76 | |
74 | |
53 |