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

Be one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now

Reply
Anonymous
Not applicable

Based on Project ID in one table, get related data from the most recent month from another table.

Hello all,

 

So I have a list of projects in a separate PowerBI Table, let's say Table 1, as the one below

 

Project IDAmountTax
1  
2  
3  
4  
5  

 

At the same time, I have a bigger table, called table 2, where data is uploaded every month and it can go for as long as 12 months. See the example below.

 

DateProject IDAmountTax
September123423
September234334
September331
September4672
September5650
September6453
September726
October223421
October33223
October4344
October5235
October6436
October7236

 

What I would like to do, is to fill in the information in Table 1, with values from the most recent month when data is available. In my case, that would be data from October. In table 2 I have a date column, so I should be able to use data formulas. Also, most of the time, the most recent month is the previous month, if that helps. So if We are now in September, the most recent month when a project from table 1 will apear in table 2, was August. I tried different Max and filter formulas but could not make it work.

 

Thanks for helping me!

 

 

 

1 ACCEPTED SOLUTION
amitchandak
Super User
Super User

@Anonymous , Try new column in table 1

new column =
var _Date = maxx(filter(Table2,Table1[project] =Table2[project] ),Table2[Date])
return
sumx(filter(Table2,Table1[project] =Table2[project] && eomonth(Table2[Date],0) = eomonth(_Date,0)),Table2[Amount])

Join us as experts from around the world come together to shape the future of data and AI!
At the Microsoft Analytics Community Conference, global leaders and influential voices are stepping up to share their knowledge and help you master the latest in Microsoft Fabric, Copilot, and Purview.
️ November 12th-14th, 2024
 Online Event
Register Here

View solution in original post

3 REPLIES 3
ryan_mayu
Super User
Super User

@Anonymous 

Please try to create two columns

AMOUNT = 
VAR _recentmonth=month(max('Table2'[Date]))-1
RETURN MAXX(FILTER(Table2,MONTH('Table2'[Date])=_recentmonth&&Table1[Project ID]=Table2[Project ID]),Table2[Amount])

TAX = 
VAR _recentmonth=month(max('Table2'[Date]))-1
RETURN MAXX(FILTER(Table2,MONTH('Table2'[Date])=_recentmonth&&Table1[Project ID]=Table2[Project ID]),Table2[Tax])

1.PNG





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




amitchandak
Super User
Super User

@Anonymous , Try new column in table 1

new column =
var _Date = maxx(filter(Table2,Table1[project] =Table2[project] ),Table2[Date])
return
sumx(filter(Table2,Table1[project] =Table2[project] && eomonth(Table2[Date],0) = eomonth(_Date,0)),Table2[Amount])

Join us as experts from around the world come together to shape the future of data and AI!
At the Microsoft Analytics Community Conference, global leaders and influential voices are stepping up to share their knowledge and help you master the latest in Microsoft Fabric, Copilot, and Purview.
️ November 12th-14th, 2024
 Online Event
Register Here
Anonymous
Not applicable

Worked perfectly. Thanks!

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.

ArunFabCon

Microsoft Fabric Community Conference 2025

Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.