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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
acerNZ
Helper III
Helper III

How can I accomplish SUMIF and removing duplicates to create Unique in M language

Hi Experts

I did search for this solution in forum and when I do group by and sum, it is giving me additional column and sum of each number which is self 

https://community.powerbi.com/t5/Desktop/SUMIF-in-Query-Editor-on-Power-BI-Desktop/td-p/135150 

Data files here: sumifunique.xls

I could able to extract data using excel SUMIF and then I use remove duplicates to get output in the third Tab. Please may I know how to accomplish this in Query Editor?

https://github.com/acerNZ/PowerBI.git  

I tried to use list.sum but could not understand the syntax well. Please appreciate your help

 

Raw Data:

 

2020-11-18_13h59_57.png

With SumIF:

2020-11-18_14h00_13.png

 

Final Output Expected:

2020-11-18_14h00_31.png

 

1 ACCEPTED SOLUTION
Jimmy801
Community Champion
Community Champion

Hello @acerNZ 

 

your are basically grouping by Product ID and applying a sum function to the sales column. All other columns you are showing is nothing else then the first value found on each group. I don't know if you need  that information. However I'm showing you an example with Table.Group with 2 functions in it. First is sum of sales-column and the other is the first value found in the group. You can enhance it by adding a new function. Here the code

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("RcyxDQAwCAPBXVyngADTIPZfI4ldpEAvHZK74VhwM+YeM6ux5S8h3/SQ503Kg55/p+RJr7/jpkdh5gA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [S.No = _t, #"Product ID" = _t, Sales = _t, Date = _t, #"Invoice ID" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"S.No", Int64.Type}, {"Product ID", Int64.Type}, {"Sales", Int64.Type}, {"Date", type text}, {"Invoice ID", Int64.Type}}),
    #"Grouped Rows" = Table.Group
    (
        #"Changed Type", 
        {"Product ID"}, 
        {
            {
                "Sum of sales", 
                each List.Sum([Sales]), 
                type number
            },
            {
                "Invoice", 
                each List.First([Invoice ID]), 
                type number
            }
        }
    )
in
    #"Grouped Rows"

Jimmy801_0-1605680277730.png

Jimmy801_1-1605680285935.png

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

View solution in original post

2 REPLIES 2
acerNZ
Helper III
Helper III

@Jimmy801  Thank you very much, worked like charm in this sheet and I replicated this in work sheet, worked well. I made couple of mistakes. 

Jimmy801
Community Champion
Community Champion

Hello @acerNZ 

 

your are basically grouping by Product ID and applying a sum function to the sales column. All other columns you are showing is nothing else then the first value found on each group. I don't know if you need  that information. However I'm showing you an example with Table.Group with 2 functions in it. First is sum of sales-column and the other is the first value found in the group. You can enhance it by adding a new function. Here the code

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("RcyxDQAwCAPBXVyngADTIPZfI4ldpEAvHZK74VhwM+YeM6ux5S8h3/SQ503Kg55/p+RJr7/jpkdh5gA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [S.No = _t, #"Product ID" = _t, Sales = _t, Date = _t, #"Invoice ID" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"S.No", Int64.Type}, {"Product ID", Int64.Type}, {"Sales", Int64.Type}, {"Date", type text}, {"Invoice ID", Int64.Type}}),
    #"Grouped Rows" = Table.Group
    (
        #"Changed Type", 
        {"Product ID"}, 
        {
            {
                "Sum of sales", 
                each List.Sum([Sales]), 
                type number
            },
            {
                "Invoice", 
                each List.First([Invoice ID]), 
                type number
            }
        }
    )
in
    #"Grouped Rows"

Jimmy801_0-1605680277730.png

Jimmy801_1-1605680285935.png

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors
Top Kudoed Authors