The ultimate Fabric, Power BI, SQL, and AI community-led learning event. Save €200 with code FABCOMM.
Get registeredEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
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.
Product | Month | Year | Total |
Item 1 | MAY-2022 | 2022 | 300,00 |
Item 2 | MAY-2022 | 2022 | 1386,67 |
Item 3 | JUN-2022 | 2022 | 333,33 |
Item 1 | JUN-2022 | 2022 | 190,00 |
Item 1 | JUN-2022 | 2022 | 200,00 |
Item 1 | JUL-2022 | 2022 | 250,00 |
Item 4 | JUL-2022 | 2022 | 400,00 |
Item 5 | AUG-2022 | 2022 | 2035,64 |
Item 1 | AUG-2022 | 2022 | 200,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.
Month | Item 1 | Item 2 | Item 3 | Item 4 | Item 5 |
MAY-2022 | 300,00 | 1386,67 | 0,00 | 0,00 | 0,00 |
JUN-2022 | 390,00 | 0,00 | 333,33 | 0,00 | 0,00 |
JUL-2022 | 250,00 | 0,00 | 0,00 | 400,00 | 0,00 |
AUG-2022 | 200,00 | 0,00 | 0,00 | 0,00 | 2035,64 |
As I said, there must be a better solution than creating conditional columns of 300k rows before grouping by.
Solved! Go to Solution.
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
Worked perfectly!
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