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

Transform Data in Power Query

Hello everyone!

Looking for a help here, cause I'm stuck 🙂
I have a table with a pretty complicated structure and need to transform it in a correct database type

In a single column we have Phone ID, Date, Order Number and SKU ID one under another.

Please the image below

2022-01-14_17-38-27.png

 

 How is it possible to transform original table to the target view?

Any help will be highly appreciated

Thanks a lot!

1 ACCEPTED SOLUTION
v-xiaotang
Community Support
Community Support

Hi @D3K 

Try this

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("rZNNboNADEavgtg2sfw7trlEDxBl13ZXVcr9F2XIEBiVLCqFFfLj8+BnuFzGN3EbyAc2Pxc5p46nkRwBsd5gMVAar6fL+H77+LwNWC8SKhTD1+3neyAFDGBkGogn44lyDnK0BoXAc8kvSQyPegI37JC4o2lOG2UG3VESw9hoyS7LaGG13DoLqG5UhFRqmRpWkF1YCnoN6yNspad1qDWLwPlHiVGINSUCmE2JTaiTljkmLc4zC32NEsxQ31HqsmTOtSx3KgyzoY7KUyqci85t5rQDnbKuuTtY1FM2nSoQ+E+driredBrUZxadMnGZhOv7rrsq8/Av+sJWncdDkwbyRrOHzfWTaHN9vCc2vru2O45+E/NPqLvO1G/icE/XXw==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Status = _t, Quantity = _t, Price = _t]),
    #"Reordered Columns" = Table.ReorderColumns(Source,{"Status", "Quantity", "Price"}),
    #"Added Custom" = Table.AddColumn(#"Reordered Columns", "Phone ID", each if Text.StartsWith([Status],"+") then [Status] else null),
    #"Added Conditional Column" = Table.AddColumn(#"Added Custom", "ORDER Number", each if Text.StartsWith([Status], "Order") then Text.Middle([Status],6,11) else null),
    #"Added Conditional Column1" = Table.AddColumn(#"Added Conditional Column", "Date", each if Text.StartsWith([Status], "Order") then Text.Middle([Status],23,10) else null),
    #"Added Conditional Column2" = Table.AddColumn(#"Added Conditional Column1", "SKU ID", each if not Text.StartsWith([Status],"+") and not Text.StartsWith([Status], "Order") then [Status] else null),
    #"Reordered Columns1" = Table.ReorderColumns(#"Added Conditional Column2",{"Status", "Date", "Phone ID", "ORDER Number", "SKU ID", "Quantity", "Price"}),
    #"Filled Down" = Table.FillDown(#"Reordered Columns1",{"Date", "Phone ID", "ORDER Number"}),
    #"Filtered Rows" = Table.SelectRows(#"Filled Down", each ([SKU ID] <> null)),
    #"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Status"})
in
    #"Removed Columns"

vxiaotang_0-1642668877175.png

 

Best Regards,

Community Support Team _Tang

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

View solution in original post

4 REPLIES 4
v-xiaotang
Community Support
Community Support

Hi @D3K 

Try this

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("rZNNboNADEavgtg2sfw7trlEDxBl13ZXVcr9F2XIEBiVLCqFFfLj8+BnuFzGN3EbyAc2Pxc5p46nkRwBsd5gMVAar6fL+H77+LwNWC8SKhTD1+3neyAFDGBkGogn44lyDnK0BoXAc8kvSQyPegI37JC4o2lOG2UG3VESw9hoyS7LaGG13DoLqG5UhFRqmRpWkF1YCnoN6yNspad1qDWLwPlHiVGINSUCmE2JTaiTljkmLc4zC32NEsxQ31HqsmTOtSx3KgyzoY7KUyqci85t5rQDnbKuuTtY1FM2nSoQ+E+driredBrUZxadMnGZhOv7rrsq8/Av+sJWncdDkwbyRrOHzfWTaHN9vCc2vru2O45+E/NPqLvO1G/icE/XXw==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Status = _t, Quantity = _t, Price = _t]),
    #"Reordered Columns" = Table.ReorderColumns(Source,{"Status", "Quantity", "Price"}),
    #"Added Custom" = Table.AddColumn(#"Reordered Columns", "Phone ID", each if Text.StartsWith([Status],"+") then [Status] else null),
    #"Added Conditional Column" = Table.AddColumn(#"Added Custom", "ORDER Number", each if Text.StartsWith([Status], "Order") then Text.Middle([Status],6,11) else null),
    #"Added Conditional Column1" = Table.AddColumn(#"Added Conditional Column", "Date", each if Text.StartsWith([Status], "Order") then Text.Middle([Status],23,10) else null),
    #"Added Conditional Column2" = Table.AddColumn(#"Added Conditional Column1", "SKU ID", each if not Text.StartsWith([Status],"+") and not Text.StartsWith([Status], "Order") then [Status] else null),
    #"Reordered Columns1" = Table.ReorderColumns(#"Added Conditional Column2",{"Status", "Date", "Phone ID", "ORDER Number", "SKU ID", "Quantity", "Price"}),
    #"Filled Down" = Table.FillDown(#"Reordered Columns1",{"Date", "Phone ID", "ORDER Number"}),
    #"Filtered Rows" = Table.SelectRows(#"Filled Down", each ([SKU ID] <> null)),
    #"Removed Columns" = Table.RemoveColumns(#"Filtered Rows",{"Status"})
in
    #"Removed Columns"

vxiaotang_0-1642668877175.png

 

Best Regards,

Community Support Team _Tang

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

@v-xiaotang 
So elegant solution! Works like a charm
Excactly what I need
Thanks a lot!

parry2k
Super User
Super User

@D3K it can be done, throw it in a sample pbix file and also share a sample file that can be used and will able to provide the solution.

 

 

Follow us on LinkedIn and YouTube.gif to our YouTube channel

 

Learn about conditional formatting at Microsoft Reactor

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.

Hey @parry2k 

Thanky you for your attention to the topic

Here is a sample pbix via the link below
https://www.dropbox.com/s/lxq7aafbel7nyoc/Transform_Data_Sample.pbix?dl=0

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.