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

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

Reply
lchirag
Frequent Visitor

Extract Alphanumeric Pattern from Text Field

Hi There!

I have a column in the PBI dataset that is TEXT and has very long text data.

Every row of this field has an Alphanumeric string added in any part of the text. However, the pattern to be extracted is always starting with ABCD0123456. 

How do I search the entire text field and extract this patterned data?

Thank you in anticipation for helping me out!

1 ACCEPTED SOLUTION

Hi @lchirag 

 

You can give this custom lookupFunction a go:

 

let
    Source = "Purchase dept ID: PURT0001894 Software License Renewals Warehouse Area: Applications Hosting Team INITIATIVE/CATEGORY: MS Teams License renewal",
    lookupFunction = ( lookIn as text, alphaCount as number, numberCount as number ) as text =>
        [
            len = alphaCount + numberCount,
            items = List.Select( Text.Split(lookIn, " "), each Text.Length(_) = len),
            find = List.Select( items, each 
                [
                    split = Splitter.SplitTextByCharacterTransition({"A".."Z"}, {"0".."9"})(_),
                    test = Text.Length( split{0} ) = alphaCount and Text.Length( split{1} ) = numberCount
                ][test]
            ),
            combi = Text.Combine( find, ", ")
        ][combi],
    result = lookupFunction(Source, 4, 7)
in
    result

 

 

 

or maybe this

 

let
    Source = "Purchase dept ID: PURT0001894 Software License Renewals Warehouse Area: Applications Hosting Team INITIATIVE/CATEGORY: MS Teams License renewal",
    lookupFunction = (lookIn as text, alphaCount as number, numberCount as number) as text =>
        let
            patternLen = alphaCount + numberCount,
            isPatternMatch = (text) => 
                ( Text.Remove(Text.Start(text, alphaCount), {"A".."Z"}) = "" and
                  Text.Remove(Text.End(text, numberCount), {"0".."9"}) = "" ),
            items = List.Select(Text.Split(lookIn, " "), each Text.Length(_) = patternLen),
            matches = List.Select(items, each isPatternMatch(_))
        in  
            Text.Combine(matches, ", "),
    Result = lookupFunction(Source, 4, 7)
in
    Result

 

 

both return this result

m_dekorte_0-1698865021107.png

 

I hope this is helplful

View solution in original post

3 REPLIES 3
BA_Pete
Super User
Super User

Hi @lchirag ,

 

Going to need some example data and expected outputs please.

 

Pete



Now accepting Kudos! If my post helped you, why not give it a thumbs-up?

Proud to be a Datanaut!




Purchase dept ID: PURT0001894 Software License Renewals Warehouse Area: Applications Hosting Team INITIATIVE/CATEGORY: MS Teams License renewal This is an example of what kind of text field I have, need code to search for "PURT0001894" it can be either in the beginning, middle or end of the text field. But it can only be once. Please help.

Hi @lchirag 

 

You can give this custom lookupFunction a go:

 

let
    Source = "Purchase dept ID: PURT0001894 Software License Renewals Warehouse Area: Applications Hosting Team INITIATIVE/CATEGORY: MS Teams License renewal",
    lookupFunction = ( lookIn as text, alphaCount as number, numberCount as number ) as text =>
        [
            len = alphaCount + numberCount,
            items = List.Select( Text.Split(lookIn, " "), each Text.Length(_) = len),
            find = List.Select( items, each 
                [
                    split = Splitter.SplitTextByCharacterTransition({"A".."Z"}, {"0".."9"})(_),
                    test = Text.Length( split{0} ) = alphaCount and Text.Length( split{1} ) = numberCount
                ][test]
            ),
            combi = Text.Combine( find, ", ")
        ][combi],
    result = lookupFunction(Source, 4, 7)
in
    result

 

 

 

or maybe this

 

let
    Source = "Purchase dept ID: PURT0001894 Software License Renewals Warehouse Area: Applications Hosting Team INITIATIVE/CATEGORY: MS Teams License renewal",
    lookupFunction = (lookIn as text, alphaCount as number, numberCount as number) as text =>
        let
            patternLen = alphaCount + numberCount,
            isPatternMatch = (text) => 
                ( Text.Remove(Text.Start(text, alphaCount), {"A".."Z"}) = "" and
                  Text.Remove(Text.End(text, numberCount), {"0".."9"}) = "" ),
            items = List.Select(Text.Split(lookIn, " "), each Text.Length(_) = patternLen),
            matches = List.Select(items, each isPatternMatch(_))
        in  
            Text.Combine(matches, ", "),
    Result = lookupFunction(Source, 4, 7)
in
    Result

 

 

both return this result

m_dekorte_0-1698865021107.png

 

I hope this is helplful

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

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

June 2025 community update carousel

Fabric Community Update - June 2025

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