Power BI is turning 10! Tune in for a special live episode on July 24 with behind-the-scenes stories, product evolution highlights, and a sneak peek at what’s in store for the future.
Save the dateEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
Hello. I am looking to create column D of the table below in power query. You can see the excel formula to the right. I need to add columns from the current row and add a previously calculated row above. I am stuck and do not know how to proceed. Any help would be appreciated.
A | B | C | D | ||
Date | Production | Demand | Final Inventory | Formula in Column D | |
1 | 5/1/2021 | 80,287 | 96,419 | 158,276 | N/A |
2 | 6/1/2021 | 77,325 | 86,650 | 148,951 | B3-C3+D2 |
3 | 7/1/2021 | 83,763 | 83,179 | 149,535 | B4-C4+D3 |
4 | 8/1/2021 | 81,890 | 74,075 | 157,350 | B5-C5+D4 |
Solved! Go to Solution.
Hi @drewswiney
Add a helpColumn and an Index column
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("bY7JDYAwDARbQXmvhO3gI7Wg9EYtVEYAKZza1zxm7HlOpCPxKCSckNZl3xAECb+4GCYund8bWAPilipaz749d2TRW99gSo1Pw38+yHDLD2Yv3YgfgxGFbjcnkOth1A0=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t, Production = _t, Demand = _t, Orignal = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Date", type date}, {"Production", Int64.Type}, {"Demand", Int64.Type}, {"Orignal", Int64.Type}}),
#"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1, Int64.Type),
#"Added Custom" = Table.AddColumn(#"Added Index", "helpColumn", each if [Index]=0 then [Orignal]
else [Production]- [Demand]),
#"Added Custom1" = Table.AddColumn(#"Added Custom", "Final Inventory", each List.Sum(List.FirstN(#"Added Custom"[helpColumn],[Index]+1)))
in
#"Added Custom1"
Hi @drewswiney
Add a helpColumn and an Index column
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("bY7JDYAwDARbQXmvhO3gI7Wg9EYtVEYAKZza1zxm7HlOpCPxKCSckNZl3xAECb+4GCYund8bWAPilipaz749d2TRW99gSo1Pw38+yHDLD2Yv3YgfgxGFbjcnkOth1A0=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t, Production = _t, Demand = _t, Orignal = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Date", type date}, {"Production", Int64.Type}, {"Demand", Int64.Type}, {"Orignal", Int64.Type}}),
#"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1, Int64.Type),
#"Added Custom" = Table.AddColumn(#"Added Index", "helpColumn", each if [Index]=0 then [Orignal]
else [Production]- [Demand]),
#"Added Custom1" = Table.AddColumn(#"Added Custom", "Final Inventory", each List.Sum(List.FirstN(#"Added Custom"[helpColumn],[Index]+1)))
in
#"Added Custom1"
This calculation should probably be done on the DAX side with a measure or a column, but here is an example of how to do it in the query editor. To see how it works, just create a blank query, open the Advanced Editor and replace the text there with the M code below.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("fY/JDcMwDARbMfhewKQkXrUI6i21pLI4fthOBAj7ms9gtnfSXfbCRQj0fn23BaOE35yGJnnx/zbRQHGjgU422dxRiz7sBlNe2FogVU6bz20VbvWHxVdtLaFVT1vMNkEkP1ob2HX19DhzxI/xAQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Date = _t, Production = _t, Demand = _t, #"Final Inventory" = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Date", type date}, {"Production", Int64.Type}, {"Demand", Int64.Type}, {"Final Inventory", Int64.Type}}),
#"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1, Int64.Type),
#"Added Custom" = Table.AddColumn(#"Added Index", "Custom", each if [Index] = 0 then null else [Production] - [Demand] + #"Changed Type"{[Index]-1}[Final Inventory], type number)
in
#"Added Custom"
Pat
To learn more about Power BI, follow me on Twitter or subscribe on YouTube.
Check out the July 2025 Power BI update to learn about new features.
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.