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
v-mgonzaleza
Employee
Employee

Filtering a table by 2 different dates and then compare the same elements of both tables

Hi, I think this request is not an easy one, but lets try it.

 

I have a table that is the result of appending many similar tables, each one with its own Snapshot (which I take with a macro in Excel and then read all the snapshots and append in PBI). The result is a table like the next one. Some days new IDs can appear, some days they will disappear, some days they will remain but change the Status:

table1:

IDStatusSnapshot Date
1Won16/06/2022
2Won16/06/2022
3Lost16/06/2022
4Lost16/06/2022
5Open16/06/2022
6Open16/06/2022
1Won17/06/2022
2Lost17/06/2022
4Open17/06/2022
6Won17/06/2022
7Lost17/06/2022
1Won20/06/2022
2Won20/06/2022
3Open20/06/2022
4Open20/06/2022
5Lost20/06/2022
10Open20/06/2022

 

Once I have this table I make a filter in my dashboard, where you can select 2 dates, and both dates will be compared. This has to be dinamyc, because my first approach was creating columns instead of measures and it didn't work:

vmgonzaleza_0-1657191371358.png

For example, in this case I have selected these 2 dates and then I capture them using 2 measures:

Date MAX = MAX('Table1'[Snapshot Date])
Date MIN= MIN('Table1'[Snapshot Date])
 
Then where I'm struggling is to compare both filtered table by these 2 dates, since I have to compare them by ID and apply a logic.
Let's say that the logic is:
  1. Same ID the Status has changed="Different"
  2. Same ID, the Status remains the same="Same"
  3. There is a new ID in the latest date then="New"
 
For example, if I want to compare the selected dates the results should be:
  • Same = 2 (IDs 1, 2)
  • Different = 3 (IDs 3, 4, 5)
  • New = 1 (ID 10)
 
Do you know how to do this? or should I use a different approach? 
 
Thanks,
Miguel
1 ACCEPTED SOLUTION
amitchandak
Super User
Super User

@v-mgonzaleza , try these measures

 

Same Status on both Dates = //slicer date can be from Table too , I assumed date table
var _max = minx(allselected(Date), Date[Date])
var _min = maxx(allselected(Date), Date[Date])
var _minst =calculate(Max(Table[Status], Filter(Table,Table[Date] =_min ) )
var _maxst = calculate(Max(Table[Status], Filter(Table,Table[Date] =_max ) )
return
countx(filter(Values(Table[ID]), _minst = _maxst && not(isblank(_minst)) && not(isblank(_maxst)) ), [ID])

 


Diff Status on both Dates = //slicer date can be from Table too , I assumed date table
var _max = minx(allselected(Date), Date[Date])
var _min = maxx(allselected(Date), Date[Date])
var _minst =calculate(Max(Table[Status], Filter(Table,Table[Date] =_min ) )
var _maxst = calculate(Max(Table[Status], Filter(Table,Table[Date] =_max ) )
return
countx(filter(Values(Table[ID]), _minst <> _maxst && not(isblank(_minst)) && not(isblank(_maxst)) ), [ID])

 

 

new on max =
var _max = minx(allselected(Date), Date[Date])
var _min = maxx(allselected(Date), Date[Date])
var _minst =calculate(Max(Table[Status], Filter(Table,Table[Date] =_min ) )
var _maxst = calculate(Max(Table[Status], Filter(Table,Table[Date] =_max ) )
return
countx(filter(Values(Table[ID]), (isblank(_minst)) && not(isblank(_maxst)) ), [ID])

 

 

same as this blog, you are just using one date range

Customer Retention Part 1:
https://community.powerbi.com/t5/Community-Blog/Customer-Retention-Part-1-Month-on-Month-Retention/b...

View solution in original post

1 REPLY 1
amitchandak
Super User
Super User

@v-mgonzaleza , try these measures

 

Same Status on both Dates = //slicer date can be from Table too , I assumed date table
var _max = minx(allselected(Date), Date[Date])
var _min = maxx(allselected(Date), Date[Date])
var _minst =calculate(Max(Table[Status], Filter(Table,Table[Date] =_min ) )
var _maxst = calculate(Max(Table[Status], Filter(Table,Table[Date] =_max ) )
return
countx(filter(Values(Table[ID]), _minst = _maxst && not(isblank(_minst)) && not(isblank(_maxst)) ), [ID])

 


Diff Status on both Dates = //slicer date can be from Table too , I assumed date table
var _max = minx(allselected(Date), Date[Date])
var _min = maxx(allselected(Date), Date[Date])
var _minst =calculate(Max(Table[Status], Filter(Table,Table[Date] =_min ) )
var _maxst = calculate(Max(Table[Status], Filter(Table,Table[Date] =_max ) )
return
countx(filter(Values(Table[ID]), _minst <> _maxst && not(isblank(_minst)) && not(isblank(_maxst)) ), [ID])

 

 

new on max =
var _max = minx(allselected(Date), Date[Date])
var _min = maxx(allselected(Date), Date[Date])
var _minst =calculate(Max(Table[Status], Filter(Table,Table[Date] =_min ) )
var _maxst = calculate(Max(Table[Status], Filter(Table,Table[Date] =_max ) )
return
countx(filter(Values(Table[ID]), (isblank(_minst)) && not(isblank(_maxst)) ), [ID])

 

 

same as this blog, you are just using one date range

Customer Retention Part 1:
https://community.powerbi.com/t5/Community-Blog/Customer-Retention-Part-1-Month-on-Month-Retention/b...

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.