Hello everyone!
Here is the question I can't find an answer for and will be very thankful for any help.
Please see the attached picture.
Now I have a table without structure: in the same column there are different data "warehouse" and list of products stored in that warehouse.
How to separate it for 2 different columns, where for any product is noticed it's own warehouse? How to make correct database structure?
Any help will be highly appreciated
Solved! Go to Solution.
@D3K in transform data start a new blank query, click advanced editor and paste the following code. it will create the step and the final result is what you are looking for.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCk8sSs3ILy1OVTBU0lEyMgUScCGlWJ1opWDvULCUCRAHFOWnlCaXFMMljICC5tgkjHHpAAkaYZMA2WyBLoFwHUiPkRlO1xnich2GkTDXGWJ1Bch5pricZ4DbeSATjS1wOs8Ip/uMcbnPDJfzsBplihERsQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"WH/SKU" = _t, Stocks = _t, Status = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"WH/SKU", type text}, {"Stocks", Int64.Type}, {"Status", type text}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "WH", each if [Status] = "Warehouse" then "Warehouse" else null, type text),
#"Filled Down" = Table.FillDown(#"Added Custom",{"WH"}),
#"Filtered Rows" = Table.SelectRows(#"Filled Down", each ([Status] = "Products")),
#"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Status"}),
#"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"WH/SKU", "SKU"}})
in
#"Renamed Columns"
✨ Follow us on LinkedIn
Check my latest blog post The Power of Using Calculation Groups with Inactive Relationships (Part 1) (perytus.com) I would ❤ Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos to whoever helped to solve your problem. It is a token of appreciation!
⚡ Visit us at https://perytus.com, your one-stop-shop for Power BI-related projects/training/consultancy.⚡
Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.
Hi @D3K ,
Try to modify @parry2k 's query like so:
Here is the complete code:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCk8sSs3ILy1OVTBU0lEyMgUScCGlWJ1opWDvULCUCRAHFOWnlCaXFMMljICC5tgkjHHpAAkaYZMA2WyBLoFwHUiPkRlO1xnich2GkTDXGWJ1Bch5pricZ4DbeSATjS1wOs8Ip/uMcbnPDJfzsBplihERsQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"WH/SKU" = _t, Stocks = _t, Status = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"WH/SKU", type text}, {"Stocks", Int64.Type}, {"Status", type text}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "WH", each if [Status] = "Warehouse" then [#"WH/SKU"] else null, type text),
#"Filled Down" = Table.FillDown(#"Added Custom",{"WH"}),
#"Filtered Rows" = Table.SelectRows(#"Filled Down", each ([Status] = "Products")),
#"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Status"}),
#"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"WH/SKU", "Product"}}),
#"Reordered Columns" = Table.ReorderColumns(#"Renamed Columns",{"WH", "Product", "Stocks"})
in
#"Reordered Columns"
Best Regards,
Icey
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
@D3K in transform data start a new blank query, click advanced editor and paste the following code. it will create the step and the final result is what you are looking for.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCk8sSs3ILy1OVTBU0lEyMgUScCGlWJ1opWDvULCUCRAHFOWnlCaXFMMljICC5tgkjHHpAAkaYZMA2WyBLoFwHUiPkRlO1xnich2GkTDXGWJ1Bch5pricZ4DbeSATjS1wOs8Ip/uMcbnPDJfzsBplihERsQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"WH/SKU" = _t, Stocks = _t, Status = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"WH/SKU", type text}, {"Stocks", Int64.Type}, {"Status", type text}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "WH", each if [Status] = "Warehouse" then "Warehouse" else null, type text),
#"Filled Down" = Table.FillDown(#"Added Custom",{"WH"}),
#"Filtered Rows" = Table.SelectRows(#"Filled Down", each ([Status] = "Products")),
#"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Status"}),
#"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"WH/SKU", "SKU"}})
in
#"Renamed Columns"
✨ Follow us on LinkedIn
Check my latest blog post The Power of Using Calculation Groups with Inactive Relationships (Part 1) (perytus.com) I would ❤ Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos to whoever helped to solve your problem. It is a token of appreciation!
⚡ Visit us at https://perytus.com, your one-stop-shop for Power BI-related projects/training/consultancy.⚡
Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.
@parry2k I've tried to use you algorithm with a few warehouses and unfortunately it doesn't work.
As you can see, we need to fill the column with warehouses not just with the sentence "Warehouse", but with the particular warehouse address (WH 1, WH 2 and so on in the sample above), where particular SKU is stored at.
Can you update your code, please?
Thank you
Hi @D3K ,
Try to modify @parry2k 's query like so:
Here is the complete code:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCk8sSs3ILy1OVTBU0lEyMgUScCGlWJ1opWDvULCUCRAHFOWnlCaXFMMljICC5tgkjHHpAAkaYZMA2WyBLoFwHUiPkRlO1xnich2GkTDXGWJ1Bch5pricZ4DbeSATjS1wOs8Ip/uMcbnPDJfzsBplihERsQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"WH/SKU" = _t, Stocks = _t, Status = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"WH/SKU", type text}, {"Stocks", Int64.Type}, {"Status", type text}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "WH", each if [Status] = "Warehouse" then [#"WH/SKU"] else null, type text),
#"Filled Down" = Table.FillDown(#"Added Custom",{"WH"}),
#"Filtered Rows" = Table.SelectRows(#"Filled Down", each ([Status] = "Products")),
#"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Status"}),
#"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"WH/SKU", "Product"}}),
#"Reordered Columns" = Table.ReorderColumns(#"Renamed Columns",{"WH", "Product", "Stocks"})
in
#"Reordered Columns"
Best Regards,
Icey
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Thanks a lot! It works. The problem was in the right way of sorting Status column, cause it was filling down incorrectly, if breaking the default sorting.
User | Count |
---|---|
181 | |
78 | |
74 | |
73 | |
47 |
User | Count |
---|---|
168 | |
90 | |
89 | |
79 | |
74 |