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
dkernen
Resolver II
Resolver II

Converting text (Replacing values) within multiple columns in Power Query

Good morning!  I have a simple file I need to massage and I would like to learn how to do it more efficiently.  I have four columns that have values that all begin with "Yes" (Yes please enter by whom, Yes please enter which physician, etc), that I want to just change to "Yes".  Here is a snippit of my multi-step process.

 

#"Replaced Value UMD" = Table.ReplaceValue(#"Reordered Columns","Yes (please enter by whom):","Yes",Replacer.ReplaceText,{"UMD?"}),
#"Replaced Value MD" = Table.ReplaceValue(#"Replaced Value UMD","Yes (please enter which physician):","Yes",Replacer.ReplaceText,{"MD?"}),
#"Replaced Value BD Early" = Table.ReplaceValue(#"Replaced Value MD","Yes (please explain):","Yes",Replacer.ReplaceText,{"BDEarlyConv?"}),
#"Replaced Value DCD Pron" = Table.ReplaceValue(#"Replaced Value BD Early","Yes (please explain):","Yes",Replacer.ReplaceText,{"DCDPronIssue?"})

Would you be able to show me how to use ReplaceValue with some kind of "starts with" functionality?

Files attached below.

PBIX

 

Sample Data

 


 Thank you in advance!!
@ReplaceValues

1 ACCEPTED SOLUTION

Hi @dkernen ,

You can try this query:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUYpMLVbQKMhJTSxOVUjNK0ktUkiqVCjPyM/VtMIqW56RmZyhUJBRWZyZnJmYh6mqoiAnMROfeKxOtJITUBaCcOkFK3MeGAfGAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Category = _t, UMD = _t, MD = _t, BDEarlyConv = _t, DCDPronIssues = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Category", type text}, {"UMD", type text}, {"MD", type text}, {"BDEarlyConv", type text}, {"DCDPronIssues", type text}}),
    #"AllReplace" = 
        [
            #"Yes (please enter by whom):"= "Yes",
            #"Yes (please enter which physician):" = "Yes",
            #"Yes (please explain):" = "Yes"
        ],
    #"Replace Value" = 
        Table.TransformColumns(
            #"Changed Type",
                {
                    {"UMD", each Record.FieldOrDefault(#"AllReplace",_,_),type text},
                    {"MD", each Record.FieldOrDefault(#"AllReplace",_,_),type text},
                    {"BDEarlyConv", each Record.FieldOrDefault(#"AllReplace",_,_),type text},
                    {"DCDPronIssues", each Record.FieldOrDefault(#"AllReplace",_,_),type text}
                }
        )
in
    #"Replace Value"

replace.png

 

Best Regards,
Community Support Team _ Yingjie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

4 REPLIES 4
Greg_Deckler
Super User
Super User

@dkernen Could you just split the columns by the first space and dump the extra columns?


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

Greg - thank you for you swift reply!  Definitely I could strip out anything after the first space (if a space exists).  Are you suggesting that  I create new dummy columns, then delete the ones I don't need, and then rename the new one?  I was perhaps hoping I could do it all in one step.  Is that not possible?

 

@Greg_Deckler  

Hi @dkernen ,

You can try this query:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUYpMLVbQKMhJTSxOVUjNK0ktUkiqVCjPyM/VtMIqW56RmZyhUJBRWZyZnJmYh6mqoiAnMROfeKxOtJITUBaCcOkFK3MeGAfGAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Category = _t, UMD = _t, MD = _t, BDEarlyConv = _t, DCDPronIssues = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Category", type text}, {"UMD", type text}, {"MD", type text}, {"BDEarlyConv", type text}, {"DCDPronIssues", type text}}),
    #"AllReplace" = 
        [
            #"Yes (please enter by whom):"= "Yes",
            #"Yes (please enter which physician):" = "Yes",
            #"Yes (please explain):" = "Yes"
        ],
    #"Replace Value" = 
        Table.TransformColumns(
            #"Changed Type",
                {
                    {"UMD", each Record.FieldOrDefault(#"AllReplace",_,_),type text},
                    {"MD", each Record.FieldOrDefault(#"AllReplace",_,_),type text},
                    {"BDEarlyConv", each Record.FieldOrDefault(#"AllReplace",_,_),type text},
                    {"DCDPronIssues", each Record.FieldOrDefault(#"AllReplace",_,_),type text}
                }
        )
in
    #"Replace Value"

replace.png

 

Best Regards,
Community Support Team _ Yingjie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

@dkernen 1 Step:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WqkwtVkgsTklLLFaK1YFyk3ISFRKBZIpCamJKIkI8JRskkZMGlIQjpdhYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Changed Type", "Column1", Splitter.SplitTextByEachDelimiter({" "}, QuoteStyle.Csv, false), {"Column1.1"})
in
    #"Split Column by Delimiter"

@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

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