Power BI is turning 10! Tune in for a special live episode on July 24 with behind-the-scenes stories, product evolution highlights, and a sneak peek at what’s in store for the future.
Save the dateEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
Hello all,
So I have a list of projects in a separate PowerBI Table, let's say Table 1, as the one below
Project ID | Amount | Tax |
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.
Date | Project ID | Amount | Tax |
September | 1 | 234 | 23 |
September | 2 | 343 | 34 |
September | 3 | 3 | 1 |
September | 4 | 67 | 2 |
September | 5 | 65 | 0 |
September | 6 | 45 | 3 |
September | 7 | 2 | 6 |
October | 2 | 234 | 21 |
October | 3 | 322 | 3 |
October | 4 | 34 | 4 |
October | 5 | 23 | 5 |
October | 6 | 43 | 6 |
October | 7 | 23 | 6 |
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!
Solved! Go to Solution.
@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])
@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])
Proud to be a 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])
Worked perfectly. Thanks!
User | Count |
---|---|
76 | |
75 | |
46 | |
31 | |
27 |
User | Count |
---|---|
99 | |
91 | |
51 | |
49 | |
46 |