Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.
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
Solved! Go to Solution.
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})
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,
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.
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
15 | |
12 | |
8 | |
8 | |
7 |
User | Count |
---|---|
15 | |
13 | |
9 | |
7 | |
6 |