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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
ryan_b_123
Frequent Visitor

Power M - Find Numbers Before Specific Text

Hello, I am looking to extract numbers before specific text ("BUP").  I think it is possible we may need to address " BUP" specifically, as users would likely put a space between number and "BUP".  Example below:

 

1. "40 BUP" = 40

2. "@LOCATION 25 BUP" = 25

3. "hello_world" = 0

 

Appreciate the help.  

 

1 ACCEPTED SOLUTION

Use this in a custom column

= if Text.End([Data],3)="BUP" then Text.Replace(List.Last(Text.Split(Text.Select(Text.Replace([Data]," BUP","BUP"),{"0".."9"," ","B","U","P"})," ")),"BUP","") else 0

Full test code

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjFQcAoNUIrViVZy8PF3dgzx9PdTMDKFC2ak5uTkx5fnF+WkoCoyMoUpMTGNKTUwMDKDkHDNsQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Data = _t]),
    #"Added Custom" = Table.AddColumn(Source, "Custom", each if Text.End([Data],3)="BUP" then Text.Replace(List.Last(Text.Split(Text.Select(Text.Replace([Data]," BUP","BUP"),{"0".."9"," ","B","U","P"})," ")),"BUP","") else 0, type number)
in
    #"Added Custom"

View solution in original post

3 REPLIES 3
Vijay_A_Verma
Super User
Super User

In a custom column, put following formula

= Text.Select(List.First(Text.Split(Text.Replace([Data]," ","")&"0BUP","BUP")),{"0".."9"})

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjFQcAoNUIrViVZy8PF3dgzx9PdTMDKFC2ak5uTkx5fnF+WkoCoyMgUriQUA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Data = _t]),
    #"Added Custom" = Table.AddColumn(Source, "Custom", each Text.Select(List.First(Text.Split(Text.Replace([Data]," ","")&"0BUP","BUP")),{"0".."9"}), type number)
in
    #"Added Custom"

@Vijay_A_Verma  - This solution works perfectly (per my description) but it encounters an issue that I didn't anticipate:

 

"45&& 25 BUP" = "4525 BUP" (with your solution).  Ideally it would return "25 BUP".

 

Is there a way to ammend the code so it will only capture numbers before the string "BUP"?  Once a non-number field is encountered, it will not return subsequent characters.

 

Thank you so much for your help!  You're a life saver : )

Use this in a custom column

= if Text.End([Data],3)="BUP" then Text.Replace(List.Last(Text.Split(Text.Select(Text.Replace([Data]," BUP","BUP"),{"0".."9"," ","B","U","P"})," ")),"BUP","") else 0

Full test code

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjFQcAoNUIrViVZy8PF3dgzx9PdTMDKFC2ak5uTkx5fnF+WkoCoyMoUpMTGNKTUwMDKDkHDNsQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Data = _t]),
    #"Added Custom" = Table.AddColumn(Source, "Custom", each if Text.End([Data],3)="BUP" then Text.Replace(List.Last(Text.Split(Text.Select(Text.Replace([Data]," BUP","BUP"),{"0".."9"," ","B","U","P"})," ")),"BUP","") else 0, type number)
in
    #"Added Custom"

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors
Top Kudoed Authors