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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Anonymous
Not applicable

Replacing values in one column with values from another table

Hi,

I want to replace values in one table using another table as a reference/lookup.

I have tried to add the following as a step in my orginal tables 

 

= Table.ReplaceValue ( #"Changed Type",each [Stop Location], each List.Accumulate (List.Buffer(Table.ToRecords(Amendments)),[Stop Location], (valueToReplace, replaceOldNewRecord)=>Text.Replace (valueToReplace, replaceOldNewRecord[Current], replaceOldNewRecord[Replace])),Replacer.ReplaceText,{"Stop Location"})

 

Where Stop Location is the column containing the data I want to amend. 

Amendments is the table containing the two values that I want to use as a look up and replcement (current = lookup, replace = replacement value to switch within the organial table in the Stop Location collumn. 

 

However, this results in the following

 

Expression.Error: The column 'Stop Location' of the table wasn't found.
Details:
Stop Location

 

Any ideas what I am doing wrong? I am very new to Power BI / Power Query. 

 

Many thanks in advance

HM

1 ACCEPTED SOLUTION
v-angzheng-msft
Community Support
Community Support

Hi, @Anonymous 

 

Check whether the above search column text contains invisible characters. The simple way to avoid this error is to copy and paste the column name.

vangzhengmsft_1-1638434705304.png

 

refer:

Table.ReplaceValue

Table.ReplaceValue(table as table, oldValue as any, newValue as any, replacer as function, columnsToSearch as list) as table

 

Here is a solution I thought of, which may help you.

I encapsulated a function that replaces the value, which can be called on the column. This works for all columns.

Create a blank query, open Advanced Editor and replace the text there with the code below.  In your original query, you can then go to the Add Column tab, invoke custom function and choose this function and choose your "Old" column as the input.

 

(inputtext as text) =>
let 
Result = List.ReplaceMatchingItems(Table.ToList(Table.FromValue(Text.From(inputtext))), List.Zip({Amendments[Current], Amendments[Replace]}))
in 
Result{0}

Result:

 

vangzhengmsft_2-1638435609704.png

 

Please refer to the attachment below for details. Hope this helps.

 

 

 

Best Regards,
Community Support Team _ Zeon Zheng


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

11 REPLIES 11
RogervwNL
New Member

Hi guys, 
As I had the same issue I stumbled across this topic. It took me another 3 hours with ChatGPT to come up with the following code:

 

let
    // Load TableA
    SourceA = ..., // Enter the source for TableA

    // Load TableB
    TableB = ..., // Enter the source for TableB

    // Define a function to replace Total Amount
    ReplaceTotalAmount = (invoiceNum, amountA) =>
        let
            matchingRow = Table.SelectRows(TableB, each [Invoicenumber] = invoiceNum),
            correctedAmount = if Table.RowCount(matchingRow) > 0 then matchingRow{0}[Total Amount] else amountA
        in
            correctedAmount,

    // Add a new column with corrected Total Amount values
    UpdatedTableA = Table.AddColumn(
        SourceA,
        "Corrected Total Amount",
        each ReplaceTotalAmount([Invoicenumber], [Total Amount]),
        type number
    ),

    // Remove the original "Total Amount" column
    RemovedOriginalTotalAmount = Table.RemoveColumns(UpdatedTableA, {"Total Amount"}),

    // Rename the new "Corrected Total Amount" column to "Total Amount"
    RenamedColumn = Table.RenameColumns(RemovedOriginalTotalAmount, {{"Corrected Total Amount", "Total Amount"}}),

    // Reorder the columns back to original order
    ReorderedColumns = Table.ReorderColumns(RenamedColumn, {"Invoicenumber", ..., "Total Amount"}) // Replace ... with the other column names

in
    ReorderedColumns

 

Table A is your source file, TableB has some corrections.
TableB has 2 fields (in my case, but you can easily change this to your situation): invoicenumber and total amount. 
You must have understood by now, that TableA has many fields with invoice data and TableB can make a correction to the invoice amount based on a matching invoice number.

I didn't want the outcome to produce a new table, so merging was out of the option. ChatGPT tried many times to update the field with the corrected amount but that took me an hour to get around.
So the solution is:
- add a column that has either the original amount unless based on a matching invoicenumber the corrected amount of table b is placed there.
- then remove/delete the original column (that as a wrong entry)
- rename the added column to the column name you just removed/deleted
- to tidy things up, like nothing happened, I reordered the columns to the original order as the newly added column was added as last

Hope this helps someone, it took me 6 hours to figure it out, it may save you some time.
Cheers R 

Anonymous
Not applicable

Hi, Sorry for the long delays in replying. The first table shows and example of the main data, the 2nd the replacement data. As mentioned I have been able to get the results I wanted using: 

= Table.ReplaceValue ( #"Changed Type",each [Stop Location], each List.Accumulate (List.Buffer(Table.ToRecords(Amendments)),[Stop Location], (valueToReplace, replaceOldNewRecord)=>Text.Replace (valueToReplace, replaceOldNewRecord[Current], replaceOldNewRecord[Replace])),Replacer.ReplaceText,{"Stop Location"})

as a step in  power query, but it took a few reloads for it to really stick. I had to duplicate the step to replace values in both start and stop location.

 

 

Driver NameStart LocationStop Location
1Joe Bloggs19 Brownstone Ave, Cloverfield, SY89 4, UK50 One Rd, That Town, TV12 8, UK
2Joe Bloggs50 One Rd, That Town, TV12 8, UKSkips - Long Rd (K3894), Sunny Side, By The River,  BZ9 5, UK
3Joe BloggsSkips - Long Rd (K3894), Sunny Side, By The River,  BZ9 5, UK70 Westview, PondTown, BV7 0, UK
1Sarah RobbinsLocation near BerryTree Lane, Maple, SK42 6, UKGarage - Bradley Street, Tower Hill, WV8 4, UK
2Sarah RobbinsGarage - Bradley Street, Tower Hill, WV8 4, UK11 Avalon Close, Cherryton, Warmly, BD76 2, UK
3Sarah Robbins11 Avalon Close, Cherryton, Warmly, BD76 2, UKGarage - Bradley Street, Tower Hill, WV8 4, UK
4Sarah RobbinsGarage - Bradley Street, Tower Hill, WV8 4, UKSkips - Long Rd (K3894), Sunny Side, By The River,  BZ9 5, UK
5Sarah RobbinsSkips - Long Rd (K3894), Sunny Side, By The River,  BZ9 5, UKLocation near BerryTree Lane, Maple, SK42 6, UK

 

CurrentReplace
Skips - Long Rd (K3894), Sunny Side, By The River,  BZ9 5, UKSkips - Long Rd (K3894), Sunny Side, By The River,  BZ9 5GH, UK
Garage - Bradley Street, Tower Hill, WV8 4, UKGarage - Bradley Street, Tower Hill, WV8 4HT, UK
Location near BerryTree Lane, Maple, SK42 6, UKNewside near BerryTree Lane, Maple, SK42 6HT, UK
Anonymous
Not applicable

Hi @smpa01 , I can't figure out how to attached a pbix here. What I have found is that 

 

= Table.ReplaceValue ( #"Changed Type",each [Stop Location], each List.Accumulate (List.Buffer(Table.ToRecords(Amendments)),[Stop Location], (valueToReplace, replaceOldNewRecord)=>Text.Replace (valueToReplace, replaceOldNewRecord[Current], replaceOldNewRecord[Replace])),Replacer.ReplaceText,{"Stop Location"})

 

Does actually work, the issue was where I had the step. I moved it so that it was directly after promoting first row to headers and prior to a data change and it worked. I added a second step, the same as above to amend the start locations also.

For some reason I had to refresh about 3 times for everything to 'stick' I have no idea why this might be.

@Anonymous  you can easily copy paste sample data and desired output here. If you fail, you can always uplaod a sample pbix in g/1 drive and share the linke here. Without sample data I can't advise.

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs
v-angzheng-msft
Community Support
Community Support

Hi, @Anonymous 

 

Check whether the above search column text contains invisible characters. The simple way to avoid this error is to copy and paste the column name.

vangzhengmsft_1-1638434705304.png

 

refer:

Table.ReplaceValue

Table.ReplaceValue(table as table, oldValue as any, newValue as any, replacer as function, columnsToSearch as list) as table

 

Here is a solution I thought of, which may help you.

I encapsulated a function that replaces the value, which can be called on the column. This works for all columns.

Create a blank query, open Advanced Editor and replace the text there with the code below.  In your original query, you can then go to the Add Column tab, invoke custom function and choose this function and choose your "Old" column as the input.

 

(inputtext as text) =>
let 
Result = List.ReplaceMatchingItems(Table.ToList(Table.FromValue(Text.From(inputtext))), List.Zip({Amendments[Current], Amendments[Replace]}))
in 
Result{0}

Result:

 

vangzhengmsft_2-1638435609704.png

 

Please refer to the attachment below for details. Hope this helps.

 

 

 

Best Regards,
Community Support Team _ Zeon Zheng


If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Anonymous
Not applicable

Hi @v-angzheng-msft , thank you so much for replying. I am very new to PBI so I've not created functions outside of the steps as yet. I will try to use your example to further my knowlege of how to do this. 

KNP
Super User
Super User

Sometimes it's easier to break this down into multiple steps rather than trying to do it all at once.

See attached PBIX file for a very basic example of what I mean.

It essentially merges the "lookup" table (called mapping in my case) with a left join and then uses the new value if not null otherwise uses the original.

You can then just remove the columns you don't need. 

Don't forget, Power Query is case sensitive, so you will need to account for that if this is an issue.

 

I hope this helps.

 

Have I solved your problem?
Please click Accept as Solution so I don't keep coming back to this post, oh yeah, others may find it useful also ;).
chrome-9xf-Zagzel-B

If you found this post helpful, please give Kudos.
It gives me a sense of instant gratification and, if you give me Kudos enough times, magical unicorns will appear on your screen.
If you find my signature vaguely amusing, please give Kudos.
KIfp67uy-Sr
Proud to be a Super User!PBI-Super-User-Rank-30x30-1x
Anonymous
Not applicable

Thanks you @KNP , this is a good solution. I really wanted to try to find a way to replace without adding anotnher column, which I have done using the orginal code, the missue seems to be around the placement of the step. Thank you for responding though, this is no doubt be a useful addition to my tool kit!

Anonymous
Not applicable

Hi thanks for the reply. I can't post the data as it is location sensitive, but I am looking to replace one string of text in its entirety with another string of text. There are likely to be multiple instances as I move forwards where I will need to replace items and so want to be able to add to a table of replacements to feed into the main data set rather than creating separate replace values for each entry.

@Anonymous  can you create some dummy data that is representative of the issue and post here.

I am not asking you to post the real data.

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs
smpa01
Super User
Super User

@Anonymous this is possible. Can you post some sample data with desired output.

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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

Top Solution Authors
Top Kudoed Authors