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

Calling all Data Engineers! Fabric Data Engineer (Exam DP-700) live sessions are back! Starting October 16th. Sign up.

Reply
kimloh_p
Frequent Visitor

DAX lookupvalue

Hi Community,

 

I have a single table that contains the following columns [Date], [ID], [Product].

I would like to add [Removed] and [New] calculated columns with the results below and as per logic:

  if ID is not found in previous month, mark product as New.

  if ID is not found in next month, mark product as Removed.

 

I'm still new and struggling with using DAX for this, appreciate some help. Thank you.

 

DateIDProductRemovedNew
1/1/201912345Policy_AYY
1/1/201923456Policy_B Y
1/1/201934567Policy_C Y
2/1/201945678Policy_D Y
2/1/201923456Policy_B  
2/1/201934567Policy_CY 
3/1/201945678Policy_DY 
3/1/201923456Policy_BY 
3/1/201956789Policy_E Y
4/1/201967890Policy_F Y
4/1/201956789Policy_E  
1 ACCEPTED SOLUTION
Anonymous
Not applicable

@kimloh_p Not sure about granularity of the data but you can use the max date condition in if condition.

 

Removed_ = 
VAR _nextMonth = MONTH(NEXTMONTH('Table'[Date]))
VAR _maxmonth = MONTH(MAX('Table'[Date]))
VAR _table = CALCULATETABLE(VALUES('Table'[ID]),FILTER(ALL('Table'),'Table'[Date].[MonthNo]=_nextMonth))
RETURN IF('Table'[ID] IN _table||'Table'[Date]=MAX('Table'[Date]),BLANK(),"Y")

View solution in original post

3 REPLIES 3
Anonymous
Not applicable

@kimloh_p Please use below calculated column for new and removed

New = 
VAR _prevMonth = MONTH(PREVIOUSMONTH('Table'[Date]))
VAR _table = CALCULATETABLE(VALUES('Table'[ID]),FILTER(ALL('Table'),'Table'[Date].[MonthNo]=_prevMonth))
RETURN IF('Table'[ID] IN _table,BLANK(),"Y")

Removed = 
VAR _nextMonth = MONTH(NEXTMONTH('Table'[Date]))
VAR _table = CALCULATETABLE(VALUES('Table'[ID]),FILTER(ALL('Table'),'Table'[Date].[MonthNo]=_nextMonth))
RETURN IF('Table'[ID] IN _table,BLANK(),"Y")

You might want to modify removed definition as per your need. Currently I'm assuming that by default product is considered as removed for latest month. Please let me know if you have any question. If it help accept solution.

hi @Anonymous 

Thank you for the solution, it's so well written, i wouldn't have figured out this method alone.

As for products in the latest month, it should not reflect in the [Removed] column if there is no match in the nextMonth. How do I incorporate this exeptional condition?

 

Thank you in advance.

 

Anonymous
Not applicable

@kimloh_p Not sure about granularity of the data but you can use the max date condition in if condition.

 

Removed_ = 
VAR _nextMonth = MONTH(NEXTMONTH('Table'[Date]))
VAR _maxmonth = MONTH(MAX('Table'[Date]))
VAR _table = CALCULATETABLE(VALUES('Table'[ID]),FILTER(ALL('Table'),'Table'[Date].[MonthNo]=_nextMonth))
RETURN IF('Table'[ID] IN _table||'Table'[Date]=MAX('Table'[Date]),BLANK(),"Y")

Helpful resources

Announcements
FabCon Global Hackathon Carousel

FabCon Global Hackathon

Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes!

September Power BI Update Carousel

Power BI Monthly Update - September 2025

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

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.