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
descalabro
Frequent Visitor

Dax to compare records in adjacent rows.

Hello,

 

I'm working on a system to report Outlook calendar events, mainly the type of event, the total time spent on each type of event and the total working hours of each team member. I use an add-in to export all the data into an Access file.

 

My problem is with overlapping events. Here is an example:

 

overlapping tasks.png

 

 

What I have in PBI is a query to combine reports from several team-members into a table and sort all events by 'Start'. I also have a calculated column named 'Day' to get only the date from the 'Start' datetime (example in Excel):

 

Excel.png

 

So, I would need something like:

 

 

WorkTime = IF( Event[End] > nextEvent[Start]); [Duration] - ((Event[End] - nextEvent[Start]) / 2); [Duration])

 

 

This is meant to subtract half of the overlapping time to both overlapping events.

And this would have to be filtered by 'Day' and 'EmployeeID'.

 

I am aware this would have to be completed with further conditions to account for other overlapping situations, but at this point I'm concerned with the method to compare adjacent records.

 

Can someone get me started on this?

 

Thank you,

 

 

Tiago Jordão

 

 

 

1 ACCEPTED SOLUTION

The FILTER expression would look like this (you can only pass one predicate to the function, so you will have to use the && operator)

 

FILTER(Table1 , [EmployeeName]= EARLIER( [EmployeeName] ) && [Day]=EARLIER([Day]))

 

From what I understand, you are primarily interested in getting the value in the [Start] column for the next row.

 

I would write something like this:

 

CALCULATE( MIN(Table1[Start]) 
     , ALLEXCEPT(Table1, Table1[EmployeeName])
     , FILTER( ALL(Table1[Start]), [Start] > EARLIER([Start]) )
)

 

CALCULATE( MIN(Table1[Start]) 
     , FILTER(Table1
, [EmployeeName]= EARLIER( [EmployeeName] )
&& [Day]=EARLIER([Day])
)
, FILTER( ALL(Table1[Start]), [Start] > EARLIER([Start]) )
)

 

Note that EARLIER does not mean what most people think it means when starting with DAX.

View solution in original post

6 REPLIES 6
v-caliao-msft
Employee
Employee

Hi @descalabro,

 

To get the End time of previous subject, you need to create a rank column by using RANKX function, and then use LOOKUPVALUE function to get that value.

Rank = RANKX(FILTER(Table1,Table1[Day]=EARLIER(Table1[Day])),Table1[Start],,ASC)
PreviousSubjectEnd = LOOKUPVALUE(Table1[End],Table1[Rank],Table1[Rank]-1,Table1[Day],Table1[Day])
Capture.PNGCapture1.PNG

 

Reference
https://msdn.microsoft.com/en-us/library/gg492185.aspx?f=255&MSPPError=-2147217396
https://msdn.microsoft.com/en-us/library/gg492170.aspx

 

Regards,

Charlie Liao

Thank you for all your replies.

 

@v-caliao-msft, Thank you. I've successfully applied your method, but I've looked everywhere for a way to add a second criteria so that the ranking can be done by the daily tasks of each team-member. I don't want to rank the times between team-members, I just need to provide an indication so the DAX will not compare between datetimes of diferent people within the same day. I can't seem to find a filtering option that doesn't require some kind of evaluation; something like:

 

 Rank = RANKX(FILTER(Table1, Table1[EmployeeName]= 'EachEmployee'; Table1[Day]=EARLIER(Table1[Day])),Table1[Start],,ASC)

I know the syntax doesn't make sense, it's just an idea of what I want to do.

 

Thanks,

 

Tiago Jordão

The FILTER expression would look like this (you can only pass one predicate to the function, so you will have to use the && operator)

 

FILTER(Table1 , [EmployeeName]= EARLIER( [EmployeeName] ) && [Day]=EARLIER([Day]))

 

From what I understand, you are primarily interested in getting the value in the [Start] column for the next row.

 

I would write something like this:

 

CALCULATE( MIN(Table1[Start]) 
     , ALLEXCEPT(Table1, Table1[EmployeeName])
     , FILTER( ALL(Table1[Start]), [Start] > EARLIER([Start]) )
)

 

CALCULATE( MIN(Table1[Start]) 
     , FILTER(Table1
, [EmployeeName]= EARLIER( [EmployeeName] )
&& [Day]=EARLIER([Day])
)
, FILTER( ALL(Table1[Start]), [Start] > EARLIER([Start]) )
)

 

Note that EARLIER does not mean what most people think it means when starting with DAX.

@LaurentCouartou, thank you, this is excellent help!

 

Before you edited your answer, I changed it a little bit:

 

NextTaskStart = CALCULATE(MIN('TeamReport'[Start]);
     ALLEXCEPT('TeamReport'; 'TeamReport'[TeamMember]; 'TeamReport'[Day]);
	 FILTER(ALL('TeamReport'[Start]); [Start] > EARLIER([Start]))
)

It seems to be working perfectly (different names here):

 

DAX overlapping tasks.png

Would you recommend doing it as you posted?

 

 

TJ

I recommend you use the formula that returns the expected results. Smiley Happy

 

 

Greg_Deckler
Super User
Super User

Generally when doing things of this nature, you want to use the EARLIER function.

https://msdn.microsoft.com/en-us/library/ee634551.aspx

 


@ 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...

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.