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

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
NJ13
Helper I
Helper I

Sum of distinct Value

Hello All,

 

i am trying to sum distinct values for bikes based on their bar codes for the most recent date. is their a formula other than the belwo ?

SUMX(GROUPBY(Table1, Table1[Date], "Max Daily Target", MAXX(CURRENTGROUP(), [DailyTarget])), [Max Daily Target]) 

thank you for your help!

 

 

Bar CodeDateBikes
5771/11/20215
5771/12/20216
5771/13/20216
4441/14/20215
4441/15/20216
4441/16/20216
9991/17/20215
9991/18/20216
9991/19/20216
3 ACCEPTED SOLUTIONS
parry2k
Super User
Super User

@NJ13 try this measure:

 

Sum Recent = 
SUMX (
    GROUPBY (
        'Table', 
        'Table'[Bar Code], 
        "Max Bike", MAXX ( CURRENTGROUP(), [Bikes] ) 
    ), 
    [Max Bike]
) 

 

 

Follow us on LinkedIn and YouTube.gif to our YouTube channel

 

Learn about conditional formatting at Microsoft Reactor

My latest blog post The Power of Using Calculation Groups with Inactive Relationships (Part 1) (perytus.com) I would  Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos to whoever helped to solve your problem. It is a token of appreciation!

 

Visit us at https://perytus.com, your one-stop-shop for Power BI-related projects/training/consultancy.



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

View solution in original post

Input sample data is clear. I modified the data as below to test the combinations

 

sevenhills_0-1644451281381.png

 

Next time, provide the sample output also like What is the output you are expecting for this data?

 

It can be done using two measures...

Latest date = 
CALCULATE( Max('Table'[Date]), ALLEXCEPT('Table','Table'[Bar Code]))

 

Latest date Bikes sum = 
CALCULATE( sum('Table'[Bikes]), allexcept('Table','Table'[Date],'Table'[Bar Code]),filter('Table', 'Table'[Date] = [Latest date]))

 

output will look like

sevenhills_1-1644451402065.png

 

 

View solution in original post

parry2k
Super User
Super User

@NJ13 actually try working:

 

Sum (This Working) = 
SUMX (
    SUMMARIZE (
        'Table',
        'Table'[Bar Code],
        "@s",
         CALCULATE ( 
            SUM ( 'Table'[Bikes] ),
            TOPN ( 1, ALLEXCEPT ( 'Table', 'Table'[Bar Code]  ),  CALCULATE ( MAX ( 'Table'[Date] ) ),  DESC ) )
    ), [@s]
)

 

 

Follow us on LinkedIn and YouTube.gif to our YouTube channel

 

Learn about conditional formatting at Microsoft Reactor

My latest blog post The Power of Using Calculation Groups with Inactive Relationships (Part 1) (perytus.com) I would  Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos to whoever helped to solve your problem. It is a token of appreciation!

 

Visit us at https://perytus.com, your one-stop-shop for Power BI-related projects/training/consultancy.



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

View solution in original post

12 REPLIES 12
parry2k
Super User
Super User

@NJ13 actually try working:

 

Sum (This Working) = 
SUMX (
    SUMMARIZE (
        'Table',
        'Table'[Bar Code],
        "@s",
         CALCULATE ( 
            SUM ( 'Table'[Bikes] ),
            TOPN ( 1, ALLEXCEPT ( 'Table', 'Table'[Bar Code]  ),  CALCULATE ( MAX ( 'Table'[Date] ) ),  DESC ) )
    ), [@s]
)

 

 

Follow us on LinkedIn and YouTube.gif to our YouTube channel

 

Learn about conditional formatting at Microsoft Reactor

My latest blog post The Power of Using Calculation Groups with Inactive Relationships (Part 1) (perytus.com) I would  Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos to whoever helped to solve your problem. It is a token of appreciation!

 

Visit us at https://perytus.com, your one-stop-shop for Power BI-related projects/training/consultancy.



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

parry2k
Super User
Super User

@NJ13 try this measure:

 

Sum Recent = 
SUMX (
    GROUPBY (
        'Table', 
        'Table'[Bar Code], 
        "Max Bike", MAXX ( CURRENTGROUP(), [Bikes] ) 
    ), 
    [Max Bike]
) 

 

 

Follow us on LinkedIn and YouTube.gif to our YouTube channel

 

Learn about conditional formatting at Microsoft Reactor

My latest blog post The Power of Using Calculation Groups with Inactive Relationships (Part 1) (perytus.com) I would  Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos to whoever helped to solve your problem. It is a token of appreciation!

 

Visit us at https://perytus.com, your one-stop-shop for Power BI-related projects/training/consultancy.



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

thank you so much it worked, i shared your solution but in addition to your solution how can i get the most recent sum value for the bar code that was recently transacted ?

you are an absolute legend.. thank you!!

NJ13
Helper I
Helper I

@sevenhills thank you for your response, i am trying to find the distinct sum of all recent Bike purchases based on their bar codes. I want to create a card that displays that distinct sum value of bikes solds for all bar codes. does the below data help or still no? thank you again for your help!

 

i want the sum to show as a card 

NJ13_0-1644444569359.png

 

Bar Code Date Bikes
577 1/11/2021 5
577 1/12/2021 6
577 1/13/2021 6
444 1/14/2021 5
444 1/15/2021 6
444 1/16/2021 6
999 1/17/2021 5
999 1/18/2021 6
999 1/19/2021 6

Input sample data is clear. I modified the data as below to test the combinations

 

sevenhills_0-1644451281381.png

 

Next time, provide the sample output also like What is the output you are expecting for this data?

 

It can be done using two measures...

Latest date = 
CALCULATE( Max('Table'[Date]), ALLEXCEPT('Table','Table'[Bar Code]))

 

Latest date Bikes sum = 
CALCULATE( sum('Table'[Bikes]), allexcept('Table','Table'[Date],'Table'[Bar Code]),filter('Table', 'Table'[Date] = [Latest date]))

 

output will look like

sevenhills_1-1644451402065.png

 

 

NJ13
Helper I
Helper I

Hello ALL , can anyone please help me out with above? i have 3 columns Bar code, date and bikes... i want to calculate the distinct sum for the most recent Bike numbers for that bar code

Pls. can you go to excel,

type in sample data (input) and paste here? same with what output you want?

 

This way, you can get help faster

 

Because your post M query vs what you shared the data is out of sync

parry2k
Super User
Super User

@NJ13 you never said the most recent bike number, I thought the question was the sum of distinct value, and ofcourse that solution is not going to work.



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

my apologies for the confusion... is there a formula for it? thank you again for your help

parry2k
Super User
Super User

@NJ13 try this measure

 

Sum Distinct = 
SUMX ( VALUES ( Table[BarCode] ), CALCULATE ( MAX ( Table[Target] ) ) )

 

 

Follow us on LinkedIn and YouTube.gif to our YouTube channel

 

Learn about conditional formatting at Microsoft Reactor

My latest blog post The Power of Using Calculation Groups with Inactive Relationships (Part 1) (perytus.com) I would  Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos to whoever helped to solve your problem. It is a token of appreciation!

 

Visit us at https://perytus.com, your one-stop-shop for Power BI-related projects/training/consultancy.



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

Hello, thank you for your response but the solution Did not work..... i have 3 columns Bar code, date and bikes... i want to calculate the distinct sum for the most recent Bike numbers for that bar code

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

Find out what's new and trending in the Fabric Community.

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

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! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

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