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

The ultimate Microsoft Fabric, Power BI, Azure AI & SQL learning event! Join us in Las Vegas from March 26-28, 2024. Use code MSCUST for a $100 discount. Register Now

Reply
Karen1015
Frequent Visitor

Sum of Value by distinct ID and Latest Date by making a new measure

https://community.fabric.microsoft.com/t5/Desktop/Sum-of-Value-by-distinct-ID-and-Latest-Date/td-p/2...
 

I have found the answer from the website above, but I can't do it by myself.

Below is my table.

IDDateTimeBalance
12023/5/17  05:00  10
12023/5/28  07:00  20
12023/5/30  14:00  30
22023/4/1  15:00  50
22023/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()?

1 ACCEPTED SOLUTION
v-yueyunzh-msft
Community Support
Community Support

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.

vyueyunzhmsft_0-1686801364998.png

 

For the 2nd variable _t, you can just see the table is the _t2 return:

vyueyunzhmsft_1-1686801407987.png

 

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!

vyueyunzhmsft_2-1686801521493.png

 

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

View solution in original post

1 REPLY 1
v-yueyunzh-msft
Community Support
Community Support

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.

vyueyunzhmsft_0-1686801364998.png

 

For the 2nd variable _t, you can just see the table is the _t2 return:

vyueyunzhmsft_1-1686801407987.png

 

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!

vyueyunzhmsft_2-1686801521493.png

 

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

Helpful resources

Announcements
Fabric Community Conference

Microsoft Fabric Community Conference

Join us at our first-ever Microsoft Fabric Community Conference, March 26-28, 2024 in Las Vegas with 100+ sessions by community experts and Microsoft engineering.

February 2024 Update Carousel

Power BI Monthly Update - February 2024

Check out the February 2024 Power BI update to learn about new features.

Fabric Career Hub

Microsoft Fabric Career Hub

Explore career paths and learn resources in Fabric.

Fabric Partner Community

Microsoft Fabric Partner Community

Engage with the Fabric engineering team, hear of product updates, business opportunities, and resources in the Fabric Partner Community.

Top Solution Authors