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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
Trebor84
Helper II
Helper II

Extract first occurring number set from text string

Hi, I'm trying to extract the first group of numbers from a text string in Power Query editor . Have seen a few tips on the this but problem is that the strings don't have any set pattern.

 

Please see examples below.

 

hello1234.  1234

hello 123    123

12 hello 21  12

 

Anu suggestions please? I have a way to do this in VBA but have been asked to recreate in Power Query now. 

Thanks 

1 ACCEPTED SOLUTION
Vijay_A_Verma
Super User
Super User

You can use below in a custom column

 

 

try Number.From(Splitter.SplitTextByCharacterTransition({"0".."9"}, (c) => not List.Contains({"0".."9"}, c))(Text.RemoveRange([Text],0,Text.PositionOfAny([Text],{"0".."9"}))){0}) otherwise null

 

Edit - another construct can be

Number.From(Text.Split(Text.Trim(Text.Combine(List.Transform(Text.ToList([Text]), (x)=> if not List.Contains({"0".."9"},x) then " " else x)))," "){0})

 

View solution in original post

3 REPLIES 3
Syndicate_Admin
Administrator
Administrator

Hi,

 

Please try the below...

 

let
Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Table", type text}}),
NumbersOnly = Table.TransformColumns(#"Changed Type", {{"Table", each Text.Select( _ , {"0".."9", " "})}}),
#"Trimmed Text" = Table.TransformColumns(NumbersOnly,{{"Table", Text.Trim, type text}}),
#"Extracted Text Before Delimiter" = Table.TransformColumns(#"Trimmed Text", {{"Table", each Text.BeforeDelimiter(_, " "), type text}})
in
#"Extracted Text Before Delimiter"

 

Basically extracting all numbers and spaces from your column (called mine Table), then only keeping numbers before the first space which I think will give you what you need.

 

Thanks,

Vijay_A_Verma
Super User
Super User

You can use below in a custom column

 

 

try Number.From(Splitter.SplitTextByCharacterTransition({"0".."9"}, (c) => not List.Contains({"0".."9"}, c))(Text.RemoveRange([Text],0,Text.PositionOfAny([Text],{"0".."9"}))){0}) otherwise null

 

Edit - another construct can be

Number.From(Text.Split(Text.Trim(Text.Combine(List.Transform(Text.ToList([Text]), (x)=> if not List.Contains({"0".."9"},x) then " " else x)))," "){0})

 

Thanks, all of these work great. I went with the top solution.

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

November Power BI Update Carousel

Power BI Monthly Update - November 2025

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

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.