Microsoft Fabric Community Conference 2025, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount.
Register nowThe Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.
Hi - I have two tabels with a many to relationship by ID. In Table 1 I have Note entries and there are multiple per ID. In table 2 I want to bring in the most recent date for each ID as well as the most recent note. In my sample date you can see that I only pull in the most recent date and note into table 2. How do I code these two fields in DAX?
Table 1:
ID | Date | Note |
123 | 5/10/2020 | Note 1 |
123 | 5/15/2020 | Note 2 |
123 | 6/5/2020 | Note 3 |
123 | 6/15/2020 | Note 4 |
456 | 6/18/2020 | Note 1 |
456 | 6/24/2020 | Note 2 |
Table 2:
ID | Date | Note |
123 | 6/15/2020 | Note 4 |
456 | 6/24/2020 | Note 2 |
Solved! Go to Solution.
Hi @Anonymous
try a table
Table 2 = SUMMARIZECOLUMNS('Table 1'[ID],
"Date", MAX('Table 1'[Date]),
"Note", CALCULATE(MAX('Table 1'[Note]), FILTER('Table 1', 'Table 1'[Date]=[Date] && 'Table 1'[ID]=[ID])
))
Here are two expressions for your calculated columns
Latest Date = CALCULATE(MAX(Table1[Date]))
Latest Note = CALCULATE(MAX(Table1[Note]), Table1[Date] = Table2[Latest Date])
The 2nd one uses the result of the first one.
If this works for you, please mark it as the solution. Kudos are appreciated too. Please let me know if not.
Regards,
Pat
To learn more about Power BI, follow me on Twitter or subscribe on YouTube.
@Anonymous , I have done it using lastnonblankvalue , released in March 2020.
Check: https://www.dropbox.com/s/hkzx1lrnif38y1v/Last%20non%20blank%20loop.pbix?dl=0
Here are two expressions for your calculated columns
Latest Date = CALCULATE(MAX(Table1[Date]))
Latest Note = CALCULATE(MAX(Table1[Note]), Table1[Date] = Table2[Latest Date])
The 2nd one uses the result of the first one.
If this works for you, please mark it as the solution. Kudos are appreciated too. Please let me know if not.
Regards,
Pat
To learn more about Power BI, follow me on Twitter or subscribe on YouTube.
Hi @Anonymous
try a table
Table 2 = SUMMARIZECOLUMNS('Table 1'[ID],
"Date", MAX('Table 1'[Date]),
"Note", CALCULATE(MAX('Table 1'[Note]), FILTER('Table 1', 'Table 1'[Date]=[Date] && 'Table 1'[ID]=[ID])
))
Thanks, but I'd rather not have to have another table just for this. Table 2 already exists and has more columns in it than just my sample data. I just want to pull in the most recent note from Table 1.
User | Count |
---|---|
123 | |
69 | |
67 | |
58 | |
52 |
User | Count |
---|---|
185 | |
92 | |
67 | |
62 | |
52 |