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
Simon_29
Helper II
Helper II

Sumif with condition

Hi everybody,

I have the following problem in Power Query. I would need to create a function that would add the values ​​in the Order Amount column and divide them by the value in the TD exract column (Order info). Sum ... but the addition of these two numbers will only be done if the Count column has a value of 2 or 3. So, for example, in the highlighted example on lines 21 and 22, I would need to find the value 2 in the Count column, see if the SCP Order Number column is the same number, and if that number is the same, add up their values ​​in the Order Amount column and divide them by one of the values ​​(it doesn't matter which one is the same) in column D. The result would therefore be: (21011.27 + 21011.27) /21136.903 It would be best if only one record (one SCP Order Number) is created in the end and a given calculation is created in a new column.

prob1.png


Can anyone help me? Thank you very much

1 ACCEPTED SOLUTION
v-jingzhang
Community Support
Community Support

Hi @Simon_29 

 

Use the Group by feature under Transform tab. Then select the Sum Order Amount column and divide it by TD extract Sum column. 

21122009.jpg

21122010.jpg

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("lYzBCQAhDAR7yVskuzEaaxH7b+OMcHDfewwM7LBrCbqpo7WQIkygQOW4Cut1qskuP8Jw0s0jFyRQj6ijp7PRjwdvOh0c3VXfdFjTWXV+/Pzs/QA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"SCP Order Number" = _t, Count = _t, #"Order Amount" = _t, #"TD extract (Order info).Sum" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"SCP Order Number", Int64.Type}, {"Count", Int64.Type}, {"Order Amount", type number}, {"TD extract (Order info).Sum", type number}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"SCP Order Number", "Count"}, {{"Sum Order Amount", each List.Sum([Order Amount]), type nullable number}, {"TD extract Sum", each List.Max([#"TD extract (Order info).Sum"]), type nullable number}}),
    #"Inserted Division" = Table.AddColumn(#"Grouped Rows", "Division", each [Sum Order Amount] / [TD extract Sum], type number)
in
    #"Inserted Division"

 

Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.

View solution in original post

3 REPLIES 3
v-jingzhang
Community Support
Community Support

Hi @Simon_29 

 

Use the Group by feature under Transform tab. Then select the Sum Order Amount column and divide it by TD extract Sum column. 

21122009.jpg

21122010.jpg

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("lYzBCQAhDAR7yVskuzEaaxH7b+OMcHDfewwM7LBrCbqpo7WQIkygQOW4Cut1qskuP8Jw0s0jFyRQj6ijp7PRjwdvOh0c3VXfdFjTWXV+/Pzs/QA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"SCP Order Number" = _t, Count = _t, #"Order Amount" = _t, #"TD extract (Order info).Sum" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"SCP Order Number", Int64.Type}, {"Count", Int64.Type}, {"Order Amount", type number}, {"TD extract (Order info).Sum", type number}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"SCP Order Number", "Count"}, {{"Sum Order Amount", each List.Sum([Order Amount]), type nullable number}, {"TD extract Sum", each List.Max([#"TD extract (Order info).Sum"]), type nullable number}}),
    #"Inserted Division" = Table.AddColumn(#"Grouped Rows", "Division", each [Sum Order Amount] / [TD extract Sum], type number)
in
    #"Inserted Division"

 

Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.

Thank u very much. It works! 🙂

lbendlin
Super User
Super User

In Power Query group your data by the first column, aggregate the second column as sum and the third column as max.

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