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
freelensia
Advocate II
Advocate II

Return a unique list of all strings enclosed within {} from a column

This is a very complex problem with many moving parts. 

I have a table with column named Value like this:

 

Value
Hello!
This is great.
This is {adjective}.
My {person} is {adjective} now.

 


The final product I need is a unique table OR list of all strings found enclosed within {} from column Value:

 

Variable
adjective
person
{"adjective", "person"}

 

 

So far, I know that we can find the position of { and } like this:

 

#"Count{" = Table.AddColumn(LastStep, "Count Of {", each List.Count(Text.PositionOf([Value],"{",Occurrence.All ))),
#"Count}" = Table.AddColumn(#"Count{", "Count Of }", each List.Count(Text.PositionOf([Value],"}",Occurrence.All ))),

 

 

We can also return the matched string with Text.PositionOf([Value], "{", n) where n is the number of occurence.

 

Now there are 2 ways to proceed:
METHOD 1:
1. Output the matched strings to columns dynamically resized based on the max number of matches in the entire table.
2. Append those columns, remove blanks and duplicates
With this method I can do 2. I need your help with step 1 only.
METHOD 2:
1. Output the matched strings to a list in a single column.

2. Combine the lists from all rows into a big list. Remove duplicates.
I have no idea how to proceed with this method.

Can any experts help me?
@Greg_Deckler @amitchandak @parry2k @Mariusz @ImkeF 

1 ACCEPTED SOLUTION
ImkeF
Super User
Super User

Hi @freelensia 

please paste the code into the advanced editor and follow the steps:

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8kjNyclXVIrViVYKycgsVgCi9KLUxBI9FKHqxJSs1OSSzLLUWoiEb6VCdUFqUXF+Xi2avEJefjlQTSwA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Value", type text}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each Text.Split([Value], "{")),
    #"Expanded Custom" = Table.ExpandListColumn(#"Added Custom", "Custom"),
    #"Filtered Rows" = Table.SelectRows(#"Expanded Custom", each Text.Contains([Custom], "}")),
    #"Extracted Text Before Delimiter" = Table.TransformColumns(#"Filtered Rows", {{"Custom", each Text.BeforeDelimiter(_, "}"), type text}}),
    #"Removed Other Columns" = Table.SelectColumns(#"Extracted Text Before Delimiter",{"Custom"}),
    #"Removed Duplicates" = Table.Distinct(#"Removed Other Columns")
in
    #"Removed Duplicates"

 

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

View solution in original post

2 REPLIES 2
ImkeF
Super User
Super User

Hi @freelensia 

please paste the code into the advanced editor and follow the steps:

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8kjNyclXVIrViVYKycgsVgCi9KLUxBI9FKHqxJSs1OSSzLLUWoiEb6VCdUFqUXF+Xi2avEJefjlQTSwA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Value", type text}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each Text.Split([Value], "{")),
    #"Expanded Custom" = Table.ExpandListColumn(#"Added Custom", "Custom"),
    #"Filtered Rows" = Table.SelectRows(#"Expanded Custom", each Text.Contains([Custom], "}")),
    #"Extracted Text Before Delimiter" = Table.TransformColumns(#"Filtered Rows", {{"Custom", each Text.BeforeDelimiter(_, "}"), type text}}),
    #"Removed Other Columns" = Table.SelectColumns(#"Extracted Text Before Delimiter",{"Custom"}),
    #"Removed Duplicates" = Table.Distinct(#"Removed Other Columns")
in
    #"Removed Duplicates"

 

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

@ImkeF Wow you are a genius. Yes this worked as intended. I have to study the code more to see what it does.
But so far, it accounts for multiple variables appearing in the same record, too.

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