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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
irishguurl
New Member

Bulk replace in M language

I have a table that has project names and numbers in seperate columns.  I have grouped the columns together but I have multiple instances of the same project and with different names.  For example:

 

U0133 SCADA at LLV-Sewer
U0133 SCADA at LLV-Water
U0133 SCADA Upgrades at Lake LV
U0143 Radio Repeater P/C-Sewer
U0143 Radio Repeater P/C-Water
U0143 Radio Repeater Power/Comm
U0171 Via Nobila Utilities
U0171 Via Nobila-Sewer
U0171 Via Nobila-Water
U0180 DUS Space Needs Assessment
U0180 Space Needs Assessment-sewer
U0180 Space Needs Assessment-water

I want the main project to be the primary name.  So the -water and - sewer would go away.  Since the names aren't all pretty I'm not sure how to go about replacing.  Thoughts?  

1 ACCEPTED SOLUTION

Here is the solution based on Fuzzy matching with a sensitivity of 0.5. Download example file from https://1drv.ms/x/s!Akd5y6ruJhvhuTWHGs0sOgEVhYHd?e=3nFBvL 

let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Filtered Rows" = Table.SelectRows(Source, each Text.Contains([Data], "-")),
    #"Extracted Text Before Delimiter" = Table.TransformColumns(#"Filtered Rows", {{"Data", each Text.BeforeDelimiter(_, "-"), type text}}),
    #"Removed Duplicates" = Table.Distinct(#"Extracted Text Before Delimiter"),
    #"Merged Queries" = Table.FuzzyNestedJoin(Source, {"Data"}, #"Removed Duplicates", {"Data"}, "Removed Duplicates", JoinKind.LeftOuter, [IgnoreCase=true, IgnoreSpace=true, NumberOfMatches=1, Threshold=0.5]),
    #"Expanded Removed Duplicates" = Table.ExpandTableColumn(#"Merged Queries", "Removed Duplicates", {"Data"}, {"Removed Duplicates.Data"})
in
    #"Expanded Removed Duplicates"

 

View solution in original post

7 REPLIES 7
Vijay_A_Verma
Super User
Super User

You can use following in a custom column and then delete the original column

try Text.Start([Project],Text.PositionOf([Project],"-")) otherwise [Project]

For column inplace replace, use following code (change Source with your last step)

Table.ReplaceValue(Source,each [Project], each try Text.Start([Project],Text.PositionOf([Project],"-")) otherwise [Project],    Replacer.ReplaceValue,{"Project"})

 

I believe I can replace the -water and -sewer part through the replace option in the tool bar.  What complicates things is the base name of the project differs. See example below:

 

U0143 Radio Repeater P/C-Sewer

U0143 Radio Repeater P/C-Water

U0143 Radio Repeater Power/Comm

 

Ideally, I would want U0143 Radio Repeater Power/Comm to be the project name for all 3 versions.  Does that make more sense?  This issue occurs for many projects.

Either we need a list of replacement words or some convention to identify...For example -

U0133 SCADA at LLV-Sewer
U0133 SCADA at LLV-Water
U0133 SCADA Upgrades at Lake LV

Whether name will be U0133 SCADA Upgrades at Lake LV or U0133 SCADA at LLV
U0171 Via Nobila Utilities
U0171 Via Nobila-Sewer
U0171 Via Nobila-Water

What will name will it be U0171 Via Nobila or U0171 Via Nobila Utilities?

I think it would be easier to replace with whatever is before the -water or -sewer.  So in the case of the examples you show, it would be U0133 SCADA at LLV and U0171 Via Nobila.  

Here is the solution based on Fuzzy matching with a sensitivity of 0.5. Download example file from https://1drv.ms/x/s!Akd5y6ruJhvhuTWHGs0sOgEVhYHd?e=3nFBvL 

let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Filtered Rows" = Table.SelectRows(Source, each Text.Contains([Data], "-")),
    #"Extracted Text Before Delimiter" = Table.TransformColumns(#"Filtered Rows", {{"Data", each Text.BeforeDelimiter(_, "-"), type text}}),
    #"Removed Duplicates" = Table.Distinct(#"Extracted Text Before Delimiter"),
    #"Merged Queries" = Table.FuzzyNestedJoin(Source, {"Data"}, #"Removed Duplicates", {"Data"}, "Removed Duplicates", JoinKind.LeftOuter, [IgnoreCase=true, IgnoreSpace=true, NumberOfMatches=1, Threshold=0.5]),
    #"Expanded Removed Duplicates" = Table.ExpandTableColumn(#"Merged Queries", "Removed Duplicates", {"Data"}, {"Removed Duplicates.Data"})
in
    #"Expanded Removed Duplicates"

 

CNENFRNL
Community Champion
Community Champion

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("dc7LCoMwEIXhVzm4rmix0G5FlyLFoF2Ii2kdSqg24gR8/d4QDKTr82X+tG1Qx/skgcrSPAVZFEUTKl54Drqdd7yQ9Yz1dJ+pZ/kqejCKZjWHBBX12qDiiT+PcY4yt+EnTslDzPtClJlxXM1xj0YTSnPVA6G2etBWs3hn9wPu5IRPMfJaQU10Y5TMvSAVYZGRn3aD/CCUbeY/W37J7gU=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Project = _t]),
    Removal = Table.TransformColumns(Source, {"Project", each let pos=Text.PositionOf(_, "-", Occurrence.First) in if pos>-1 then Text.ReplaceRange(_, pos, 10, "") else _})
in
    Removal

CNENFRNL_0-1647493378254.png

 


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

HotChilli
Super User
Super User

You could split the column by delimiter (on -)  ,if that holds as a rule

or

a replace -sewer (or whatever) with nothing .

Both options are a right-click on the column header in Power Query 

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Solution Authors