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

Be one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now

Reply
h4n1234
Frequent Visitor

DAX - How to: Identify cycles & calculated score based on pair logic

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.

h4n1234_0-1650989207764.png

 

The yellow columns are what I'd like to achieve:

Plus a measure to calculate the score difference.

h4n1234_1-1650989222210.png

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

  • Type D ends a cycle, but when their isn't a D it will take C as the end (or B if C doesn't exsit)
  • Type A starts a cycle, but when their isn't an A at the start for example for Attendee 2, B comes first which is pair with D, so this is cycle 1
  • For Attendee 1, they have x3 meeting type C consecutively, so it takes the last one of the 3
  • An attendee can have infinite cycles

Thank you!

1 ACCEPTED SOLUTION
v-eqin-msft
Community Support
Community Support

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)

Eyelyn9_0-1651212438558.png

 

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.

View solution in original post

5 REPLIES 5
v-eqin-msft
Community Support
Community Support

Hi @h4n1234 ,

 

Any updates?

 

Best Regards,
Eyelyn Qin

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. 

v-eqin-msft
Community Support
Community Support

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)

Eyelyn9_0-1651212438558.png

 

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. 

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.

ArunFabCon

Microsoft Fabric Community Conference 2025

Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.