Check your eligibility for this 50% exam voucher offer and join us for free live learning sessions to get prepared for Exam DP-700.
Get StartedDon't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.
I have found the answer from the website above, but I can't do it by myself.
Below is my table.
ID | Date | Time | Balance |
1 | 2023/5/17 | 05:00 | 10 |
1 | 2023/5/28 | 07:00 | 20 |
1 | 2023/5/30 | 14:00 | 30 |
2 | 2023/4/1 | 15:00 | 50 |
2 | 2023/4/30 | 08:30 | 30 |
Because I sum the value by distinct ID and Latest Date, I get the number 60. (From ID:1 TIME: 2023/5/30 14:00 ,and ID:2 TIME:2023/4/30 08:30)
The measure I referred to as the answer is below.
Total Balance=
VAR tempTbl =
ADDCOLUMNS(
'Transactions',
"@IsLastDate",
CALCULATE(
MAX(CONCATENATE('Transactions'[Date],'Transactions'[Time]), 'Transactions'[ID] = EARLIER('Transactions'[ID]), ALL('Transactions')
) = CONCATENATE('Transactions'[Date],'Transactions'[Time])
)
RETURN
SUMX(
FILTER(tempTbl, [@IsLastDate]),
[Balance]
)
I also want to know the meaning of "@IsLastDate". Can I use replace it with NOW()?
Solved! Go to Solution.
Hi , @Karen1015
Thanks for your sample data first!
According to your description, you want to get the value by distinct ID and Latest Date.
First of all, your dax fails to run in my side, and this can be achieved by creating a measure for your needs.I use measure to achieve your needs.
Before providing dax, let me answer your question first: in your dax, "@IsLastDate" is a parameter of addcolumns, which means a column name of the newly created table, which cannot be changed to a dax function.
For this , you can refer to :
ADDCOLUMNS function (DAX) - DAX | Microsoft Learn
Then my Dax is as follows (create measure):
Measure = var _t = ADDCOLUMNS('Transactions', "DateTime" , [Date]+[Time])
var _t2 = ADDCOLUMNS(_t , "lastValue" , var _table = FILTER(_t ,[ID]=EARLIER([ID])) var _max_date= MAXX(_table , [DateTime]) var _value= MAXX(FILTER(_table,[DateTime]=_max_date) , [Balance])
return IF([DateTime]=_max_date , _value, BLANK()))
return
sumx(_t2, [lastValue])
We can explain the metric in an intuitive form.
For the first variable _t, you can just see the table is the _t return:
We just add a column to compare the latest datetime.
For the 2nd variable _t, you can just see the table is the _t2 return:
According to the above table, we can see that the value returned by the last line sumx(_t2,[lastValue]) is the 30+30=60 you want!
Thank you for your time and sharing, and thank you for your support and understanding of PowerBI!
Best Regards,
Aniya Zhang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly
Hi , @Karen1015
Thanks for your sample data first!
According to your description, you want to get the value by distinct ID and Latest Date.
First of all, your dax fails to run in my side, and this can be achieved by creating a measure for your needs.I use measure to achieve your needs.
Before providing dax, let me answer your question first: in your dax, "@IsLastDate" is a parameter of addcolumns, which means a column name of the newly created table, which cannot be changed to a dax function.
For this , you can refer to :
ADDCOLUMNS function (DAX) - DAX | Microsoft Learn
Then my Dax is as follows (create measure):
Measure = var _t = ADDCOLUMNS('Transactions', "DateTime" , [Date]+[Time])
var _t2 = ADDCOLUMNS(_t , "lastValue" , var _table = FILTER(_t ,[ID]=EARLIER([ID])) var _max_date= MAXX(_table , [DateTime]) var _value= MAXX(FILTER(_table,[DateTime]=_max_date) , [Balance])
return IF([DateTime]=_max_date , _value, BLANK()))
return
sumx(_t2, [lastValue])
We can explain the metric in an intuitive form.
For the first variable _t, you can just see the table is the _t return:
We just add a column to compare the latest datetime.
For the 2nd variable _t, you can just see the table is the _t2 return:
According to the above table, we can see that the value returned by the last line sumx(_t2,[lastValue]) is the 30+30=60 you want!
Thank you for your time and sharing, and thank you for your support and understanding of PowerBI!
Best Regards,
Aniya Zhang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Prices go up Feb. 11th.
Check out the January 2025 Power BI update to learn about new features in Reporting, Modeling, and Data Connectivity.
User | Count |
---|---|
144 | |
75 | |
64 | |
52 | |
47 |
User | Count |
---|---|
219 | |
89 | |
76 | |
67 | |
60 |