Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
D3K
Advocate II
Advocate II

Changings to data structure in Power Query

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. 

2021-09-18_22-55-48 (2).png

 

 

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

2 ACCEPTED SOLUTIONS
parry2k
Super User
Super User

@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.

 



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

View solution in original post

Icey
Community Support
Community Support

Hi @D3K ,

 

Try to modify @parry2k 's query like so:

Icey_0-1632200297819.png

 

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"

Icey_1-1632200482574.png

 

 

Best Regards,

Icey

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

4 REPLIES 4
parry2k
Super User
Super User

@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.

 



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. 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

Icey
Community Support
Community Support

Hi @D3K ,

 

Try to modify @parry2k 's query like so:

Icey_0-1632200297819.png

 

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"

Icey_1-1632200482574.png

 

 

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.

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.

Top Solution Authors