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

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
RL1
Frequent Visitor

Split column based on text and numerical characters

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.

1 ACCEPTED 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}})
Specializing in Power Query Formula Language (M)

View solution in original post

4 REPLIES 4
Greg_Deckler
Super User
Super User

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.

 

 



Follow on LinkedIn
@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
Power BI Cookbook Third Edition (Color)

DAX is easy, CALCULATE makes DAX hard...

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}})
Specializing in Power Query Formula Language (M)

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

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

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

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

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