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

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
Anonymous
Not applicable

How to change specific values in a column depending on what that value is or might not be in another

I have a table that will be going through major change in the next two months, however I'd like my reports to reflect the new data as it is today. The table has region, subregion and state data in columns. Some states for example, california was region northwest and it has been changed in the reporting structure as west. I did a replace value in power query for that, however there are other states such as Connecticut and New York that were north and then got changed to East in the reporting structure. The conflict I'm having is some of the North region states are now West and there are other North region states that are now East. The challenge is to get the region and subregion to change for each State.


Sample data (saved as xlxs):
Region,Subregion,State
North,Mountain East,Colorado
North,Mountain West,Wyoming
North,New England,Connecticut


Need to change TO:
Region,Subregion,State
West,Mountain East,Colorado
West,Mountain West,Wyoming
East,New England,Connecticut

 

I've been trying to do a replace formula in power query but either I'm getting an error, or nothing get changed. I thought I had it with the below but the data is still the same. What am I doing wrong?? I'd like to get this resolved today. I appreciate your help and feedback.
= Table.ReplaceValue(#"Replaced Value6","North", each if {"Subregion"}="New England" then "East" else "North" ,Replacer.ReplaceText,{"Region"})

1 ACCEPTED SOLUTION
sturlaws
Resident Rockstar
Resident Rockstar

Hi, @Anonymous,

 

Through some trial and error, I came up with this code which solves the examples you have provided:

= Table.ReplaceValue(#"Changed Type2", 
each if List.Contains({"Mountain East","Mountain West","New England"},[Subregion]) 
then [Region] else false, 
each if List.Contains({"Mountain East","Mountain West"},[Subregion]) then "West" 
else if List.Contains({"New England"},[Subregion]) then "East" else false,
Replacer.ReplaceValue,{"Region"})

 

Cheers,
Sturla

If this post helps, then please consider Accepting it as the solution. Kudos are nice too.

View solution in original post

2 REPLIES 2
Anonymous
Not applicable

@sturlaws thank you so much! It worked!

sturlaws
Resident Rockstar
Resident Rockstar

Hi, @Anonymous,

 

Through some trial and error, I came up with this code which solves the examples you have provided:

= Table.ReplaceValue(#"Changed Type2", 
each if List.Contains({"Mountain East","Mountain West","New England"},[Subregion]) 
then [Region] else false, 
each if List.Contains({"Mountain East","Mountain West"},[Subregion]) then "West" 
else if List.Contains({"New England"},[Subregion]) then "East" else false,
Replacer.ReplaceValue,{"Region"})

 

Cheers,
Sturla

If this post helps, then please consider Accepting it as the solution. Kudos are nice too.

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

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

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

Check out the November 2024 Power BI update to learn about new features.