The ultimate Microsoft Fabric, Power BI, Azure AI, and SQL learning event: Join us in Stockholm, September 24-27, 2024.
Save €200 with code MSCUST on top of early bird pricing!
Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
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"})
Solved! Go to Solution.
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.
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.
Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.
Check out the August 2024 Power BI update to learn about new features.
User | Count |
---|---|
111 | |
79 | |
71 | |
48 | |
41 |
User | Count |
---|---|
136 | |
108 | |
71 | |
64 | |
58 |