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

Power BI is turning 10! Let’s celebrate together with dataviz contests, interactive sessions, and giveaways. Register now.

Reply
you7777
Frequent Visitor

How to return distinct labels when comparing months?

I have a trending dataset where I'm trying to show which labels were added or removed by each month. Basically, I take a snapshot of an environment every month and store the data into a DB. Can someone write an example of a query that will show you distinct values when it compares one month to another? Here is an example of my data:

 

November:

Screenshot 2025-01-07 at 11.29.31 AM.png

 

December:

Screenshot 2025-01-07 at 11.28.44 AM.png

January:

Screenshot 2025-01-07 at 12.02.46 PM.png

 

Please write a query that shows me the unique labels for each month. Ideally states which ones were added and which ones were removed. Thanks!

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @you7777 ,

 

Thanks lbendlin for the quick answer and solution. I have some other ideas to add:

(1) This is my test data.  

vtangjiemsft_5-1736329565499.png

 

(2) We can create tables.

 

Table 2 = 
var _min_date=MINX(ALL('Table'),[DB Loading Date])
var _table1= SELECTCOLUMNS('Table',[App Label],[DB Loading Date],[Status])
RETURN ADDCOLUMNS(FILTER('Table',[DB Loading Date] <> _min_date),"pre_date",EDATE([DB Loading Date],-1))
Table 3 = 
var _table1= SELECTCOLUMNS('Table',[App Label],[Status],"Date",[DB Loading Date])
var _table2= SELECTCOLUMNS('Table 2',[App Label],[Status],"Date",[pre_date])

var _cancelled=ADDCOLUMNS( EXCEPT(_table1,_table2),"_status","cancelled","DB Loading Date",EDATE([Date],1))
var _add=ADDCOLUMNS(EXCEPT(_table2,_table1),"_status","add","DB Loading Date",EDATE([Date],1))
var _table3=SELECTCOLUMNS(_cancelled,[App Label],"Status",[_status],[DB Loading Date])
var _table4=SELECTCOLUMNS(_add,[App Label],"Status",[_status],[DB Loading Date])

var _table5= SELECTCOLUMNS(FILTER(UNION(_table3,_table4,'Table'),[Status]="active"),[App Label],[DB Loading Date])
var _table6= SELECTCOLUMNS(FILTER(UNION(_table3,_table4,'Table'),[Status]="add"),[App Label],[DB Loading Date]) 
var _table7= UNION(SELECTCOLUMNS(ADDCOLUMNS(EXCEPT(_table5,_table6),"Status","active"),[App Label],[status],[DB Loading Date]),_table4,_table3)
var _max_date=MAXX(_table7,[DB Loading Date])
RETURN
    FILTER(_table7,[DB Loading Date]<>_max_date)

 

(3) Then the result is as follows. December saw a decrease of one compared to November, and January saw three new additions compared to December.

vtangjiemsft_4-1736328332264.png

 

vtangjiemsft_3-1736328312763.png

 

Best Regards,

Neeko Tang

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
Anonymous
Not applicable

Hi @you7777 ,

 

Thanks lbendlin for the quick answer and solution. I have some other ideas to add:

(1) This is my test data.  

vtangjiemsft_5-1736329565499.png

 

(2) We can create tables.

 

Table 2 = 
var _min_date=MINX(ALL('Table'),[DB Loading Date])
var _table1= SELECTCOLUMNS('Table',[App Label],[DB Loading Date],[Status])
RETURN ADDCOLUMNS(FILTER('Table',[DB Loading Date] <> _min_date),"pre_date",EDATE([DB Loading Date],-1))
Table 3 = 
var _table1= SELECTCOLUMNS('Table',[App Label],[Status],"Date",[DB Loading Date])
var _table2= SELECTCOLUMNS('Table 2',[App Label],[Status],"Date",[pre_date])

var _cancelled=ADDCOLUMNS( EXCEPT(_table1,_table2),"_status","cancelled","DB Loading Date",EDATE([Date],1))
var _add=ADDCOLUMNS(EXCEPT(_table2,_table1),"_status","add","DB Loading Date",EDATE([Date],1))
var _table3=SELECTCOLUMNS(_cancelled,[App Label],"Status",[_status],[DB Loading Date])
var _table4=SELECTCOLUMNS(_add,[App Label],"Status",[_status],[DB Loading Date])

var _table5= SELECTCOLUMNS(FILTER(UNION(_table3,_table4,'Table'),[Status]="active"),[App Label],[DB Loading Date])
var _table6= SELECTCOLUMNS(FILTER(UNION(_table3,_table4,'Table'),[Status]="add"),[App Label],[DB Loading Date]) 
var _table7= UNION(SELECTCOLUMNS(ADDCOLUMNS(EXCEPT(_table5,_table6),"Status","active"),[App Label],[status],[DB Loading Date]),_table4,_table3)
var _max_date=MAXX(_table7,[DB Loading Date])
RETURN
    FILTER(_table7,[DB Loading Date]<>_max_date)

 

(3) Then the result is as follows. December saw a decrease of one compared to November, and January saw three new additions compared to December.

vtangjiemsft_4-1736328332264.png

 

vtangjiemsft_3-1736328312763.png

 

Best Regards,

Neeko Tang

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

lbendlin
Super User
Super User

You can study the approach here :  https://www.daxpatterns.com/new-and-returning-customers/

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

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

Top Solution Authors