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
Anonymous
Not applicable

Replace Values

Hello,

 

I have values in a column like the following:

"Example$_!"

 

The "&#<digits>;" are HTML codes that needs to be decoded.

 

In the example, the result string must be:

"Example$_!"

 

The HTML codes can be of course any valid code.

 

I have already a Web Query with the list of code and its equivalent character.

 

What is the best way to do the decoding in my case and replace the values with Power Query?

 

Thanks!

Jonathan

 

1 ACCEPTED SOLUTION

Hi @Anonymous,

 

In this case, the best solution will be a recursive custom function in Power Query.

 

1. Create a new blank query and paste below code there:

 

(InputText as text)=> //Text variable
       //Generate a list of consecutive replacements and get only the last value
       List.Last(List.Generate(
                          ()=> [ //Set default values for counter and result column
                                MyText=InputText,
                                nr = Text.Length(InputText) - Text.Length(Text.Replace(InputText,"&#","#"))
                                ], 
                          each [nr]<>0, //Condition
                          each [ //Result                               
                                MyText =
                                          let   
                                                //Get first occurrence of &#<digit>; combination
                                                Code = Number.FromText(Text.BetweenDelimiters([MyText], "&#", ";")),
                                                //Get related text to be replaced to based on result form previous row
                                                TextNew = Table.SelectRows(Dictionary, each [Column1] = Code)[Column2]{0},
                                                //Do replace
                                                Result = Text.Replace([MyText],"&#" & Number.ToText(Code) & ";",TextNew)
                                          in
                                                Result,
                                nr = Text.Length([MyText]) - Text.Length(Text.Replace([MyText],"&#","#"))      
                                ],
                          each [MyText])
       )

2. Go to your query with a column to be replaced and then Press menu Add Column -> Invoke Custom Function

    Enter a name for the new column and select Function query (from step 1). Then choose a column to be replaced and press OK.

 

RegExp replaceRegExp replace

dictionarydictionary

I've learned this approach from Chris Webb's post - https://blog.crossjoin.co.uk/2014/06/25/using-list-generate-to-make-multiple-replacements-of-words-in-text-in-power-query/. Maybe you will find it useful as well.

 

Regards,
Ruslan
-------------------------------------------------------------------
Did I answer your question? Mark my post as a solution!

 

View solution in original post

9 REPLIES 9
v-juanli-msft
Community Support
Community Support

Hi @Anonymous

Is the result string should be:

"Example$_!" for all rows though code string are varies in rows?

If so, follow steps below

Split column

1.png

 

Add custom column

2.png

 

Merge column

3.png

 

 

Best Regards

Maggie

Anonymous
Not applicable

@v-juanli-msft,

 

The result needs to vary for each row. In fact, the source strings vary, each can have between 0 and n HTML codes of the form "&#<digits>;". Each of these must be replace with their corresponding character.

 

So unfortunately, your solution won't solve my problem.

 

Thank you

Joorge_C
Resolver II
Resolver II

In power query under Transform menu, you will have to use Split by Delimiter and Replace Values a few times to get to your wanted result.

 

If you have different scenarios, meanining you have to apply different steps based on the value, then you could try to duplicate the column then apply the different steps acctodringly.

 

 

Anonymous
Not applicable

@Joorge_C,

 

 

Yes, I know I can do it, but I think it won't work if the count of symbols varies on each cell content. Let's say in the first cell I have 2 symbols in the string but on the next I have 3 symbols. If I am not wrong, applying the steps as you described won't solve my problem.

 

Thanks

Hi @Anonymous,

 

In this case, the best solution will be a recursive custom function in Power Query.

 

1. Create a new blank query and paste below code there:

 

(InputText as text)=> //Text variable
       //Generate a list of consecutive replacements and get only the last value
       List.Last(List.Generate(
                          ()=> [ //Set default values for counter and result column
                                MyText=InputText,
                                nr = Text.Length(InputText) - Text.Length(Text.Replace(InputText,"&#","#"))
                                ], 
                          each [nr]<>0, //Condition
                          each [ //Result                               
                                MyText =
                                          let   
                                                //Get first occurrence of &#<digit>; combination
                                                Code = Number.FromText(Text.BetweenDelimiters([MyText], "&#", ";")),
                                                //Get related text to be replaced to based on result form previous row
                                                TextNew = Table.SelectRows(Dictionary, each [Column1] = Code)[Column2]{0},
                                                //Do replace
                                                Result = Text.Replace([MyText],"&#" & Number.ToText(Code) & ";",TextNew)
                                          in
                                                Result,
                                nr = Text.Length([MyText]) - Text.Length(Text.Replace([MyText],"&#","#"))      
                                ],
                          each [MyText])
       )

2. Go to your query with a column to be replaced and then Press menu Add Column -> Invoke Custom Function

    Enter a name for the new column and select Function query (from step 1). Then choose a column to be replaced and press OK.

 

RegExp replaceRegExp replace

dictionarydictionary

I've learned this approach from Chris Webb's post - https://blog.crossjoin.co.uk/2014/06/25/using-list-generate-to-make-multiple-replacements-of-words-in-text-in-power-query/. Maybe you will find it useful as well.

 

Regards,
Ruslan
-------------------------------------------------------------------
Did I answer your question? Mark my post as a solution!

 

Anonymous
Not applicable

Hi @zoloturu,

 

You solution worked almost as is. I had to modify the code a little bit. One of the changes is to fix the case where the input string is not containing a HTML code. The function was returning null. Here is below the code of the function I use now. Thanks for the help!

 

(inputText as text) =>
let
    transformed = 
        List.Last(
            List.Generate(
                () =>
                [
                    MyText = inputText,
                    nr = Text.Length(inputText) - Text.Length(Text.Replace(inputText, "&#", "#"))
                ],
            each [nr] <> 0,
            each
            [
                MyText =
                    let
                        CodeOnly = Text.BetweenDelimiters([MyText], "&#", ";"),
                        Code = "&#" & CodeOnly & ";",
                        TextNew = Table.SelectRows(#"HTML codes", each [Numeric code] = Code)[Char]{0},
                        Result = Text.Replace([MyText], Code, TextNew)
                    in
                        Result,
                        nr = Text.Length([MyText]) - Text.Length(Text.Replace([MyText], "&#", "#"))
            ],
            each [MyText])),
    result = if transformed is null then inputText else transformed
in
    result

 

Anonymous
Not applicable

@zoloturu,

 

Thanks a lot for that superb reply! It sounds really good! I haven't had time to try it yet. I will let you know if it works after.

 

Thank you

zoloturu
Memorable Member
Memorable Member

Hi @Anonymous,

 

How many such symbols your text cell can contain? Two or a different amount?

 

Regards,
Ruslan

 

Anonymous
Not applicable

Hi @zoloturu,

 

My text cell can contain different amount of those symbols.

 

Thank you

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.