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

Enhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.

Reply
lipesouza12
Frequent Visitor

Group By with CountIf and SumIf

Hello everybody,

I have a question that may have a very simple solution, but I haven't found it yet. I need to group a 300k rows table and perform conditional calculations as below.

 

ProductMonthYearTotal
Item 1MAY-20222022300,00
Item 2MAY-202220221386,67
Item 3JUN-20222022333,33
Item 1JUN-20222022190,00
Item 1JUN-20222022200,00
Item 1JUL-20222022250,00
Item 4JUL-20222022400,00
Item 5AUG-202220222035,64
Item 1AUG-20222022200,00

 

I need to group by Month Column and SUM the Total Column if Product column is equal to a Name Product conditional. I always have five items. I need the result below.

 

MonthItem 1Item 2Item 3Item 4Item 5
MAY-2022300,001386,670,000,000,00
JUN-2022390,000,00333,330,000,00
JUL-2022250,000,000,00400,000,00
AUG-2022200,000,000,000,002035,64

 

As I said, there must be a better solution than creating conditional columns of 300k rows before grouping by.

1 ACCEPTED SOLUTION
Vijay_A_Verma
Super User
Super User

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test (later on when you use the query on your dataset, you will have to change the source appropriately. If you have columns other than these, then delete Changed type step and do a Changed type for complete table from UI again)

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8ixJzVUwVNJR8nWM1DUyAjKMDMCUsYGBUqwOVIERFgWGxhZmembmCEXGQEGvUD9UU4yN9YyNEWoMsagxtDTAr8DIAEOBD6oCUyQFJlgUmCCbYAoUcAx1R7PC2FTPzATVGkxFQFNiAQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Product = _t, Month = _t, Year = _t, Total = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Product", type text}, {"Month", type date}, {"Year", Int64.Type}, {"Total", type number}}),
    #"Removed Columns" = Table.RemoveColumns(#"Changed Type",{"Year"}),
    #"Pivoted Column" = Table.Pivot(#"Removed Columns", List.Distinct(#"Removed Columns"[Product]), "Product", "Total", List.Sum),
    Custom1 = Table.ReplaceValue(#"Pivoted Column",each [Month],each Text.Upper(Date.ToText([Month],"MMM-yyyy")),Replacer.ReplaceValue,{"Month"})
in
    Custom1

 

View solution in original post

2 REPLIES 2
lipesouza12
Frequent Visitor

Worked perfectly!

Vijay_A_Verma
Super User
Super User

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test (later on when you use the query on your dataset, you will have to change the source appropriately. If you have columns other than these, then delete Changed type step and do a Changed type for complete table from UI again)

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8ixJzVUwVNJR8nWM1DUyAjKMDMCUsYGBUqwOVIERFgWGxhZmembmCEXGQEGvUD9UU4yN9YyNEWoMsagxtDTAr8DIAEOBD6oCUyQFJlgUmCCbYAoUcAx1R7PC2FTPzATVGkxFQFNiAQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Product = _t, Month = _t, Year = _t, Total = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Product", type text}, {"Month", type date}, {"Year", Int64.Type}, {"Total", type number}}),
    #"Removed Columns" = Table.RemoveColumns(#"Changed Type",{"Year"}),
    #"Pivoted Column" = Table.Pivot(#"Removed Columns", List.Distinct(#"Removed Columns"[Product]), "Product", "Total", List.Sum),
    Custom1 = Table.ReplaceValue(#"Pivoted Column",each [Month],each Text.Upper(Date.ToText([Month],"MMM-yyyy")),Replacer.ReplaceValue,{"Month"})
in
    Custom1

 

Helpful resources

Announcements
August Power BI Update Carousel

Power BI Monthly Update - August 2025

Check out the August 2025 Power BI update to learn about new features.

August 2025 community update carousel

Fabric Community Update - August 2025

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

Top Solution Authors