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, the Microsoft Fabric Community team will be offering free DP-600 exam vouchers. Prepare now

Reply
BizyB
Regular Visitor

Extract every string occurrence with additional characters

hello experts

have just begun having fun with the powerBI and have hit the below roadblock although sounds simple. please guide me where am going wrong!

 

problem statement: 

am trying to extract a set of strings based on a common pattern with no specific delimiter in place from a column within a table separated by columns

 

example:

Column1Expected result
AD1234 AD9833: This is sample dataAD1234, AD9833
AD6835,AD0978 This is sample dataAD6835, AD0978

 

Formula am trying to use:

 

Text.Combine(
  List.Select(
    Text.PositionOf([Column1], "AD", Occurrence.All),
    each Text.Middle([Column1], _, 6)
  ),
  ", "
)

 

Am receiving the following error

 

Expression.Error: We cannot apply field access to the type Number.
Details:
    Value=0
    Key=summary

 

 

1 ACCEPTED SOLUTION
ronrsnfld
Super User
Super User

I suggest:

in the Advanced Editor:

#"Added Custom" = Table.AddColumn(Source, "Extract", each Text.Combine(
                List.Accumulate(
                    Text.PositionOf([Column1], "AD", Occurrence.All),
                    {},
                    (s,c)=> s & {Text.Middle([Column1],c,6)}),", "), type text)

 

or in the UI:

Text.Combine(
    List.Accumulate(
        Text.PositionOf([Column1], "AD", Occurrence.All),
        {},
        (s,c)=> s & {Text.Middle([Column1],c,6)}),
    ", ")

 

ronrsnfld_0-1709479976188.png

 

 

View solution in original post

4 REPLIES 4
watkinnc
Super User
Super User

Why not just use this in your Table.AddColumn:

 

each Text.Combine({Text.Range([Column1], 0, 6), Text.Range([Column1], 8, 6)}, ", ")

 

Simpler, plus what if it's ever something besides "AD"?

 

--Nate


I’m usually answering from my phone, which means the results are visualized only in my mind. You’ll need to use my answer to know that it works—but it will work!!

thanks @watkinnc and apologies for coming back to you late on this. 

the trouble with the Column1 data is that it is manually documented by hundreds of users with just a guideline and no control. So the position of "AD" is not static. Also the delimiter is not constant as well because of the varying user inputs.

 

Because of the above conditions, think the solution from @ronrsnfld works better. Also currently we are just focused on getting AD. Anything besides "AD" that comes in later will have to be dealt with it accordingly later on.. so not worries about it now 🙂

 

thank you!

BizyB
Regular Visitor

wonderful.. thanks a lot for the tip.. that worked like a charm!

ronrsnfld
Super User
Super User

I suggest:

in the Advanced Editor:

#"Added Custom" = Table.AddColumn(Source, "Extract", each Text.Combine(
                List.Accumulate(
                    Text.PositionOf([Column1], "AD", Occurrence.All),
                    {},
                    (s,c)=> s & {Text.Middle([Column1],c,6)}),", "), type text)

 

or in the UI:

Text.Combine(
    List.Accumulate(
        Text.PositionOf([Column1], "AD", Occurrence.All),
        {},
        (s,c)=> s & {Text.Middle([Column1],c,6)}),
    ", ")

 

ronrsnfld_0-1709479976188.png

 

 

Helpful resources

Announcements
OCT PBI Update Carousel

Power BI Monthly Update - October 2024

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

September Hackathon Carousel

Microsoft Fabric & AI Learning Hackathon

Learn from experts, get hands-on experience, and win awesome prizes.

October NL Carousel

Fabric Community Update - October 2024

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