Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more
Hi,all:
I have a warehouse,like warehouse1,get items in and out ,the amount of in item maybe different from out item ,but the material is the same.I have a table like pic left,want to get it like right,how can i do it in powerpivot or powerquery?
Solved! Go to Solution.
What is the logic behind this. Shouldn't it be A,B,C with amount of 501 rather than B,C with amount of 501 as 1 amount is left after movement of A? However assuming your output is correct
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)
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUQoHEY5AbGhgACQ985RidaKVjGAyTkBshCxjDJNxBmJjZBkTZNN0LS2BpH9piVJsLAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, WareHouse = _t, Item = _t, Amount = _t, State = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"WareHouse", type text}, {"Item", type text}, {"Amount", Int64.Type}, {"State", type text}}),
#"Grouped Rows1" = Table.Group(#"Changed Type", {"WareHouse", "Item"}, {{"Temp", each Text.Combine([State],",")
, type nullable text}}),
#"Filtered Rows" = Table.SelectRows(#"Grouped Rows1", each not Text.Contains([Temp], "Out")),
#"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Temp"}),
#"Grouped Rows2" = Table.Group(#"Removed Columns", {"WareHouse"}, {{"Item", each Text.Combine([Item],", "
), type nullable text}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"WareHouse"}, {{"Amount", each List.Sum([Amount]), type nullable number}}),
#"Merged Queries" = Table.NestedJoin(#"Grouped Rows2", {"WareHouse"}, #"Grouped Rows", {"WareHouse"}, "Grouped Rows", JoinKind.LeftOuter),
#"Expanded Grouped Rows" = Table.ExpandTableColumn(#"Merged Queries", "Grouped Rows", {"Amount"}, {"Amount"})
in
#"Expanded Grouped Rows"
after checking it,i found some problem,whe
like the pic above ,when i add an item "A" again,the output is expected up-right,there should be an "A" in cell.
but the result is bottom-right.
Use this
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUQoHEY5AbGhgACQ985RidaKVjGAyTkBshCxjDJNxBmJjZBkTZNN0LS2BpH9piVJsLAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, WareHouse = _t, Item = _t, Amount = _t, State = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"WareHouse", type text}, {"Item", type text}, {"Amount", Int64.Type}, {"State", type text}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"WareHouse"}, {{"Amount", each List.Sum([Amount]), type nullable number}}),
#"Grouped Rows1" = Table.Group(#"Changed Type", {"WareHouse", "Item", "State"}, {{"Count", each Table.RowCount(_), Int64.Type}}),
#"Added Custom" = Table.AddColumn(#"Grouped Rows1", "Custom", each if [State]="In" then [Count] else -[Count]),
#"Grouped Rows2" = Table.Group(#"Added Custom", {"WareHouse", "Item"}, {{"Count", each List.Sum([Custom]), type number}}),
#"Filtered Rows" = Table.SelectRows(#"Grouped Rows2", each [Count] > 0),
#"Grouped Rows3" = Table.Group(#"Filtered Rows", {"WareHouse"}, {{"Item", each Text.Combine([Item],", "), type nullable text}}),
#"Merged Queries" = Table.NestedJoin(#"Grouped Rows", {"WareHouse"}, #"Grouped Rows3", {"WareHouse"}, "Grouped Rows3", JoinKind.LeftOuter),
#"Expanded Grouped Rows3" = Table.ExpandTableColumn(#"Merged Queries", "Grouped Rows3", {"Item"}, {"Item"}),
#"Reordered Columns" = Table.ReorderColumns(#"Expanded Grouped Rows3",{"WareHouse", "Item", "Amount"})
in
#"Reordered Columns"
thank you very much,the output is correct,it is the require of our accountant,the value of item get in warehouse may be different from the out one ,because of the so call "depreciation",the judgement is on state column,if the item is in and out,then it's gone.
What is the logic behind this. Shouldn't it be A,B,C with amount of 501 rather than B,C with amount of 501 as 1 amount is left after movement of A? However assuming your output is correct
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)
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUQoHEY5AbGhgACQ985RidaKVjGAyTkBshCxjDJNxBmJjZBkTZNN0LS2BpH9piVJsLAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, WareHouse = _t, Item = _t, Amount = _t, State = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"WareHouse", type text}, {"Item", type text}, {"Amount", Int64.Type}, {"State", type text}}),
#"Grouped Rows1" = Table.Group(#"Changed Type", {"WareHouse", "Item"}, {{"Temp", each Text.Combine([State],",")
, type nullable text}}),
#"Filtered Rows" = Table.SelectRows(#"Grouped Rows1", each not Text.Contains([Temp], "Out")),
#"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Temp"}),
#"Grouped Rows2" = Table.Group(#"Removed Columns", {"WareHouse"}, {{"Item", each Text.Combine([Item],", "
), type nullable text}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"WareHouse"}, {{"Amount", each List.Sum([Amount]), type nullable number}}),
#"Merged Queries" = Table.NestedJoin(#"Grouped Rows2", {"WareHouse"}, #"Grouped Rows", {"WareHouse"}, "Grouped Rows", JoinKind.LeftOuter),
#"Expanded Grouped Rows" = Table.ExpandTableColumn(#"Merged Queries", "Grouped Rows", {"Amount"}, {"Amount"})
in
#"Expanded Grouped Rows"
The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!
| User | Count |
|---|---|
| 16 | |
| 16 | |
| 11 | |
| 10 | |
| 9 |