Advance your Data & AI career with 50 days of live learning, dataviz contests, hands-on challenges, study groups & certifications and more!
Get registeredGet Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Request now
Hello fellows,
I have a data table looks like this
| Sales | 1:3 |
| Cost | 4 |
| Tax | 5:6 |
I want to convert them into:
| Sales | 1 |
| Sales | 2 |
| Sales | 3 |
| Cost | 4 |
| Tax | 5 |
| Tax | 6 |
Anyone has some ideas?
Best Regards,
Solved! Go to Solution.
Here's a (somewhat pedestrian) way of doing that in Power Query. I am sure there are more elegant solutions.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCk7MSS1W0lEytDJWitWJVnLOLy4Bck3AnJDECiDb1MpMKTYWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Transaction Type" = _t, Range = _t]),
#"Added Custom" = Table.AddColumn(Source, "Custom", each let
d= Text.PositionOf([Range],":"),
r= if d = -1 then List.Numbers(Number.FromText([Range]),1)
else List.Numbers(Number.FromText(Text.Start([Range],d)),1+Number.FromText(Text.End([Range],Text.Length([Range])-d-1))-Number.FromText(Text.Start([Range],d)))
in
r
),
#"Expanded Custom" = Table.ExpandListColumn(#"Added Custom", "Custom")
in
#"Expanded Custom"
@Anonymous it is pretty straight forward, start new blank query and click advanced editor and paste the following code
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCk7MSS1W0lEytDJWitWJVnLOLy4Bck3AnJDECiDb1MpMKTYWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [A = _t, B = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"A", type text}, {"B", type text}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "Pos", each Text.PositionOf([B],":")),
#"Added Custom1" = Table.AddColumn(#"Added Custom", "List", each if [Pos]=-1 then {Number.FromText([B])} else
{Number.FromText(Text.Middle([B],0,[Pos]))..Number.FromText(Text.Middle([B],[Pos]+1))}),
#"Expanded List" = Table.ExpandListColumn(#"Added Custom1", "List"),
#"Removed Columns" = Table.RemoveColumns(#"Expanded List",{"Pos"})
in
#"Removed Columns"
. The main logic is in step #"Added Custom1"
I would ❤ Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos 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.
Here's a (somewhat pedestrian) way of doing that in Power Query. I am sure there are more elegant solutions.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCk7MSS1W0lEytDJWitWJVnLOLy4Bck3AnJDECiDb1MpMKTYWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Transaction Type" = _t, Range = _t]),
#"Added Custom" = Table.AddColumn(Source, "Custom", each let
d= Text.PositionOf([Range],":"),
r= if d = -1 then List.Numbers(Number.FromText([Range]),1)
else List.Numbers(Number.FromText(Text.Start([Range],d)),1+Number.FromText(Text.End([Range],Text.Length([Range])-d-1))-Number.FromText(Text.Start([Range],d)))
in
r
),
#"Expanded Custom" = Table.ExpandListColumn(#"Added Custom", "Custom")
in
#"Expanded Custom"
@Anonymous it is pretty straight forward, start new blank query and click advanced editor and paste the following code
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCk7MSS1W0lEytDJWitWJVnLOLy4Bck3AnJDECiDb1MpMKTYWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [A = _t, B = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"A", type text}, {"B", type text}}),
#"Added Custom" = Table.AddColumn(#"Changed Type", "Pos", each Text.PositionOf([B],":")),
#"Added Custom1" = Table.AddColumn(#"Added Custom", "List", each if [Pos]=-1 then {Number.FromText([B])} else
{Number.FromText(Text.Middle([B],0,[Pos]))..Number.FromText(Text.Middle([B],[Pos]+1))}),
#"Expanded List" = Table.ExpandListColumn(#"Added Custom1", "List"),
#"Removed Columns" = Table.RemoveColumns(#"Expanded List",{"Pos"})
in
#"Removed Columns"
. The main logic is in step #"Added Custom1"
I would ❤ Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos 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.
Thank you @edhans for the inspiration:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCk7MSS1W0lEytDJWitWJVnLOLy4Bck3AnJDECiDb1MpMKTYWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Transaction Type" = _t, Range = _t]),
#"Added Custom1" = Table.AddColumn(Source, "Custom.1", each Expression.Evaluate("{" & Text.Replace([Range],":","..") & "}")),
#"Expanded Custom.1" = Table.ExpandListColumn(#"Added Custom1", "Custom.1")
in
#"Expanded Custom.1"
I transfromed the table into
| min | max | |
| Sales | 1 | 3 |
| Cost | 4 | 4 |
| Tax | 5 | 6 |
Still not sure how can I use it to mapping though...
Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!
Check out the October 2025 Power BI update to learn about new features.