Fabric is Generally Available. Browse Fabric Presentations. Work towards your Fabric certification with the Cloud Skills Challenge.
Hey Experts!
I'm stuck on the followng Power Query Problem, I would like the sum per month as a new column (see example below)...
Month | Date | Sales | What I Need |
Jan | 01/01/2022 | 5 | 10 |
Jan | 01/01/2022 | 5 | 10 |
Feb | 01/02/2023 | 1 | 2 |
Reb | 01/02/2023 | 1 | 2 |
My tables much larger than this with more columns but follows the same principle but needs to be done in Power Query.
I can't use group by aswell because I need the other columns.
How can I achieve this in Power Query? Any help would be greatly appreciated 🙂
Many Thanks,
Taylor
Solved! Go to Solution.
let
//change next lineto reflect data source
Source = Excel.CurrentWorkbook(){[Name="Table4"]}[Content],
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Month", type text}, {"Date", type date}, {"Sales", Int64.Type}}),
//Add year-month column in case sales dates are not always on same day of month
#"Added Custom" = Table.AddColumn(#"Changed Type", "YearMonth", each Date.ToText([Date],"yyyyMM"), type text),
//Group by year-month
// Then aggregate for All and Sum
#"Grouped Rows" = Table.Group(#"Added Custom", {"YearMonth"}, {
{"All", each _, type table [Month=nullable text, Date=nullable date, Sales=nullable number, YearMonth=text]},
{"Monthly Sales", each List.Sum([Sales]), type nullable number}
}),
//Remove the yearmonth column
#"Removed Columns" = Table.RemoveColumns(#"Grouped Rows",{"YearMonth"}),
//Re-expand previous columns
#"Expanded All" = Table.ExpandTableColumn(#"Removed Columns", "All", {"Month", "Date", "Sales"})
in
#"Expanded All"
Hi @Ttaylor9870 ,
Provide another way to think about it.
List.Sum(Table.SelectRows(PreviousStepName,(x)=>x[Month]=[Month])[Sales])
all steps.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8krMU9JRMtQ31DcyMDICMk2VYnVwCrulJoGFjUDCxiAmkvChBQaG+gbIUrEA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Month = _t, Date = _t, Sales = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Month", type text}, {"Date", type date}, {"Sales", Int64.Type}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "Sales Total", each List.Sum(Table.SelectRows(#"Changed Type",(x)=>x[Month]=[Month])[Sales]))
in
#"Added Custom"
Best Regards,
Gao
Community Support Team
If there is any post helps, then please consider Accept it as the solution to help the other members find it more quickly. If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!
How to get your questions answered quickly -- How to provide sample data in the Power BI Forum
Hi @Ttaylor9870 ,
Provide another way to think about it.
List.Sum(Table.SelectRows(PreviousStepName,(x)=>x[Month]=[Month])[Sales])
all steps.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8krMU9JRMtQ31DcyMDICMk2VYnVwCrulJoGFjUDCxiAmkvChBQaG+gbIUrEA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Month = _t, Date = _t, Sales = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Month", type text}, {"Date", type date}, {"Sales", Int64.Type}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "Sales Total", each List.Sum(Table.SelectRows(#"Changed Type",(x)=>x[Month]=[Month])[Sales]))
in
#"Added Custom"
Best Regards,
Gao
Community Support Team
If there is any post helps, then please consider Accept it as the solution to help the other members find it more quickly. If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!
How to get your questions answered quickly -- How to provide sample data in the Power BI Forum
let
//change next lineto reflect data source
Source = Excel.CurrentWorkbook(){[Name="Table4"]}[Content],
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Month", type text}, {"Date", type date}, {"Sales", Int64.Type}}),
//Add year-month column in case sales dates are not always on same day of month
#"Added Custom" = Table.AddColumn(#"Changed Type", "YearMonth", each Date.ToText([Date],"yyyyMM"), type text),
//Group by year-month
// Then aggregate for All and Sum
#"Grouped Rows" = Table.Group(#"Added Custom", {"YearMonth"}, {
{"All", each _, type table [Month=nullable text, Date=nullable date, Sales=nullable number, YearMonth=text]},
{"Monthly Sales", each List.Sum([Sales]), type nullable number}
}),
//Remove the yearmonth column
#"Removed Columns" = Table.RemoveColumns(#"Grouped Rows",{"YearMonth"}),
//Re-expand previous columns
#"Expanded All" = Table.ExpandTableColumn(#"Removed Columns", "All", {"Month", "Date", "Sales"})
in
#"Expanded All"
Check out the November 2023 Power BI update to learn about new features.
Read the latest Fabric Community announcements, including updates on Power BI, Synapse, Data Factory and Data Activator.
Join us for a free, hands-on Microsoft workshop led by women trainers for women where you will learn how to build a Dashboard in a Day!