Explore and share Fabric Notebooks to boost Power BI insights in the new community notebooks gallery.
Check it out now!Microsoft is giving away 50,000 FREE Microsoft Certification exam vouchers. Get Fabric certified for FREE! Learn more
Hi,
I'm trying to split a column that contains text and number components into two seperate columns, one containing the text characters and another containing the numbers.
i.e. I want to go from the single column:
AB143
A122
VHG309
X12
XX13
to two columns containing:
AB 143
A 122
VHG 309
X 12
XX 13
Is this possible within Power BI?
Thanks.
Solved! Go to Solution.
Instead I would propose Text.PositionOfAny as illustrated in this video.
Relevant parts of the code generated during video recording ("PreviousStep" is the name of your previous step):
#"Added Custom" = Table.AddColumn(PreviousStep, "Custom", each Text.PositionOfAny([Column1],{"0".."9"})), #"Inserted First Characters" = Table.AddColumn(#"Added Custom", "First Characters", each Text.Start([Column1], [Custom]), type text), #"Inserted Text Range" = Table.AddColumn(#"Inserted First Characters", "Text Range", each Text.Middle([Column1], [Custom]), type text), #"Removed Columns" = Table.RemoveColumns(#"Inserted Text Range",{"Column1", "Custom"}), #"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"Text Range", "Number"}}), #"Changed Type1" = Table.TransformColumnTypes(#"Renamed Columns",{{"Number", Int64.Type}})
You could potentially use PostionOfAny function:
List.PositionOfAny("ABCBA", {"A","B"}, Occurrence.All) equals {0,1,3,4}
You would probably have to use an M custom function or another function to return the lowest value in the list and then feed that to a Split.
Instead I would propose Text.PositionOfAny as illustrated in this video.
Relevant parts of the code generated during video recording ("PreviousStep" is the name of your previous step):
#"Added Custom" = Table.AddColumn(PreviousStep, "Custom", each Text.PositionOfAny([Column1],{"0".."9"})), #"Inserted First Characters" = Table.AddColumn(#"Added Custom", "First Characters", each Text.Start([Column1], [Custom]), type text), #"Inserted Text Range" = Table.AddColumn(#"Inserted First Characters", "Text Range", each Text.Middle([Column1], [Custom]), type text), #"Removed Columns" = Table.RemoveColumns(#"Inserted Text Range",{"Column1", "Custom"}), #"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"Text Range", "Number"}}), #"Changed Type1" = Table.TransformColumnTypes(#"Renamed Columns",{{"Number", Int64.Type}})
That works well (& video was very helpful).
Thanks.
If you could get your cell addresses as $A$1 rather that A1, you could simply split columns based on the delimiter $.