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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply

Multiple Rows of duplicated data, compare date of each row with max date

I am sure there is an easy way to do this, but I've been looking at the data for what feels like 4 years and my head is spinning!

 

I have a table of 'issues', refreshed from excel files which are refreshed on a monthly basis.  If the issue still exists it will be added as a new row in the table.  As part of the import process, I'm grabbing the date from the filename and storing it in a column called 'FileDate'.

 

In Powerquery, the main issue I have is that I can't figure out how to get the max date from the FileDate column, which will allow me to create a new column called 'status' with 2 values:

 

Open - FileDate = MaxFileDate

Resolved - FileDate not equal to MaxFileDate

 

As the example here:  Max File Date is 01/03/2021.  ABCDE has this date, so is open.  FGHJY does not have this date so is resolved.

 

Issue RefFileDateStatus
ABCDE01/03/2021Open
ABCDE01/02/2021Open
ABCDE01/01/2021Open
ABCDE01/12/2020Open
FGHJY01/02/2021Resolved
FGHJY01/01/2021Resolved
FGHJY01/12/2020Resolved

 

Any ideas?

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

Hi @silverdale9999 ,

 

Based on your description, you can create a calculated column as follows.

Column = 

var x1=CALCULATE(MAX('Table'[FileDate]),ALL())

var x2=MAXX(FILTER(ALL('Table'),[Issue Ref]=EARLIER('Table'[Issue Ref])),[FileDate])

return

IF(x2=x1,"Open","Resolved")
Result:

v-yuaj-msft_0-1614830123052.png

 

Hope that's what you were looking for.

Best Regards,

Yuna

 

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

2 REPLIES 2
v-yuaj-msft
Community Support
Community Support

Hi @silverdale9999 ,

 

Based on your description, you can create a calculated column as follows.

Column = 

var x1=CALCULATE(MAX('Table'[FileDate]),ALL())

var x2=MAXX(FILTER(ALL('Table'),[Issue Ref]=EARLIER('Table'[Issue Ref])),[FileDate])

return

IF(x2=x1,"Open","Resolved")
Result:

v-yuaj-msft_0-1614830123052.png

 

Hope that's what you were looking for.

Best Regards,

Yuna

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

amitchandak
Super User
Super User

@silverdale9999 , Try with a date table

Open = CALCULATE(Count(Table[FileDate]),DATESMTD('Date'[Date]), Filter(Table, Table[Status] = "Open" ))

 

resolved = CALCULATE(Count(Table[FileDate]),DATESMTD('Date'[Date]), Filter(Table, Table[Status] = "Resolved" ))

+ if(isblank([Open]),1,blank())

 

 

To get the best of the time intelligence function. Make sure you have a date calendar and it has been marked as the date in model view. Also, join it with the date column of your fact/s. Refer :radacad sqlbi My Video Series Appreciate your Kudos.

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.