cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Stex85
New Member

Using a find and replace based on another table

Hi all,

 

Apologies if this has been asked before I have a database which I access which has codes to replace data. As a reference it contains another table which has a list of the codes used and where they are used, and a separate table with what the codes mean. What I'm looking for is a way to replace the codes with their meanings. I've put some sample data below, which will hopefuly make it a bit clearer! Annoyingly none of the codes or the column names are unique!

 

Customer Table:

NameMember_StatusAddress_type
JimAAAA
SteveABAA
LisaAAAB
GregACAB
AmyACAA

 

Code Location Table:

 

CVTnametablenamecolumnname
MemberstatusCustomerFactMember_Status
addressusedCustomerFactAddress_type
MemberstatusAccountFact

Account_Status

 

Code Definition Table:

 

CVTnameKeyDecription
MemberstatusAAActive
MemberstatusABSuspended
MemberstatusACInactive
addressusedAAHome
addressusedABWork

 

Desired Output (from Customer Table):

 

NameMember_StatusAddress_type
JimActiveHome
SteveSuspendedHome
LisaActiveWork
GregInactiveWork
AmyInactiveHome

 

Any help is much appreciated

 

Thanks,

 

Simon

1 ACCEPTED SOLUTION
Shishir22
Solution Sage
Solution Sage

Hello @Stex85 ,

 

I am assuming that you have 'N' number of columns like this and you need to add information.

Please follow below steps-

 

Step 1- Add custom column in Code Defination table using below code-

   #"Inserted Merged Column" = Table.AddColumn(#"Changed Type", "Merged", each Text.Combine({[CVTname], [Key]}), type text),
    #"Renamed Columns" = Table.RenameColumns(#"Inserted Merged Column",{{"Merged", "MergeKey"}})
in
    #"Renamed Columns"

 

Step 2-

Add below transformation in your customer table-

#"Changed Type" = Table.TransformColumnTypes(Source,{{"Name", type text}, {"Member_Status", type text}, {"Address_type", type text}}),
    #"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Name"}, "Attribute", "Value"),
    #"Merged Queries" = Table.NestedJoin(#"Unpivoted Columns", {"Attribute"}, #"Code Location", {"columnname"}, "Code Location", JoinKind.LeftOuter),
    #"Expanded Code Location" = Table.ExpandTableColumn(#"Merged Queries", "Code Location", {"CVTname"}, {"Code Location.CVTname"}),
    #"Added Custom" = Table.AddColumn(#"Expanded Code Location", "Custom", each [Code Location.CVTname]&[Value]),
    #"Merged Queries1" = Table.NestedJoin(#"Added Custom", {"Custom"}, #"Code Definition", {"MergeKey"}, "Code Definition", JoinKind.LeftOuter),
    #"Expanded Code Definition" = Table.ExpandTableColumn(#"Merged Queries1", "Code Definition", {"Decription"}, {"Code Definition.Decription"}),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded Code Definition",{"Code Location.CVTname", "Custom", "Value"}),
    #"Reordered Columns" = Table.ReorderColumns(#"Removed Columns",{"Name", "Code Definition.Decription", "Attribute"}),
    #"Pivoted Column" = Table.Pivot(#"Reordered Columns", List.Distinct(#"Reordered Columns"[Attribute]), "Attribute", "Code Definition.Decription")
in
    #"Pivoted Column"

 

You should get desired result.

 

Shishir22_0-1652875518274.png

 

Please mark it as answer if it solves your issue. Kudos are also appreciated.

Cheers,
Shishir

View solution in original post

4 REPLIES 4
Shishir22
Solution Sage
Solution Sage

Hello @Stex85 ,

 

I am assuming that you have 'N' number of columns like this and you need to add information.

Please follow below steps-

 

Step 1- Add custom column in Code Defination table using below code-

   #"Inserted Merged Column" = Table.AddColumn(#"Changed Type", "Merged", each Text.Combine({[CVTname], [Key]}), type text),
    #"Renamed Columns" = Table.RenameColumns(#"Inserted Merged Column",{{"Merged", "MergeKey"}})
in
    #"Renamed Columns"

 

Step 2-

Add below transformation in your customer table-

#"Changed Type" = Table.TransformColumnTypes(Source,{{"Name", type text}, {"Member_Status", type text}, {"Address_type", type text}}),
    #"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Changed Type", {"Name"}, "Attribute", "Value"),
    #"Merged Queries" = Table.NestedJoin(#"Unpivoted Columns", {"Attribute"}, #"Code Location", {"columnname"}, "Code Location", JoinKind.LeftOuter),
    #"Expanded Code Location" = Table.ExpandTableColumn(#"Merged Queries", "Code Location", {"CVTname"}, {"Code Location.CVTname"}),
    #"Added Custom" = Table.AddColumn(#"Expanded Code Location", "Custom", each [Code Location.CVTname]&[Value]),
    #"Merged Queries1" = Table.NestedJoin(#"Added Custom", {"Custom"}, #"Code Definition", {"MergeKey"}, "Code Definition", JoinKind.LeftOuter),
    #"Expanded Code Definition" = Table.ExpandTableColumn(#"Merged Queries1", "Code Definition", {"Decription"}, {"Code Definition.Decription"}),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded Code Definition",{"Code Location.CVTname", "Custom", "Value"}),
    #"Reordered Columns" = Table.ReorderColumns(#"Removed Columns",{"Name", "Code Definition.Decription", "Attribute"}),
    #"Pivoted Column" = Table.Pivot(#"Reordered Columns", List.Distinct(#"Reordered Columns"[Attribute]), "Attribute", "Code Definition.Decription")
in
    #"Pivoted Column"

 

You should get desired result.

 

Shishir22_0-1652875518274.png

 

Please mark it as answer if it solves your issue. Kudos are also appreciated.

Cheers,
Shishir

Hi, sorry, getting a token EOF expected error. Here's the code for the table

 

let
Source = Sql.Database("XXXXXXXXXXX", "xxxxxxxxxx"),

cvt_cvtValues = Source{[Schema="cvt",Item="cvtValues"]}[Data]

in
"code definition"

#"Inserted Merged Column" = Table.AddColumn(#"Changed Type", "Merged", each Text.Combine({[CVTname], [Key]}), type text),
#"Renamed Columns" = Table.RenameColumns(#"Inserted Merged Column",{{"Merged", "MergeKey"}})
in
#"Renamed Columns"

Hello,

 

Please remove 

in

"code defination"

from above code. And use-

 

let
Source = Sql.Database("XXXXXXXXXXX", "xxxxxxxxxx"),

cvt_cvtValues = Source{[Schema="cvt",Item="cvtValues"]}[Data]

#"Inserted Merged Column" = Table.AddColumn(#"Changed Type", "Merged", each Text.Combine({[CVTname], [Key]}), type text),
#"Renamed Columns" = Table.RenameColumns(#"Inserted Merged Column",{{"Merged", "MergeKey"}})
in
#"Renamed Columns"

Cheers,
Shishir
amitchandak
Super User
Super User

@Stex85 , New columns on the customer table

 

maxx(filter(code, code[Key] = Customer[Member_Status]  && [CVTname] = "Memberstatus"), Code[Decription])

 

Add other in same way



Power BI Features || Datamarts: https://youtu.be/8tskWsJTEpg || Field Parameters : https://youtu.be/lqF3Wa1FllE?t=70
Time Intelligence Decoded : https://youtu.be/aU2aKbnHuWs&t=145s
Did I answer your question? Mark my post as a solution! Appreciate your Kudos !! Proud to be a Super User! !!
Dashboard of My Blogs !! Connect on Linkedin !! Subscribe to my youtube Channel !!
Want To Learn Power BI | Beginners !! Advance Concepts !! Power BI For Tableau User !!

Helpful resources

Announcements
August 2022 update 768x460.jpg

Check it Out!

Click here to learn more about the August 2022 updates!

August 1 episode 9_no_dates 768x460.jpg

The Power BI Community Show

Watch the playback when Priya Sathy and Charles Webb discuss Datamarts! Kelly also shares Power BI Community updates.

Power Platform Conf 2022 768x460.jpg

Join us for Microsoft Power Platform Conference

The first Microsoft-sponsored Power Platform Conference is coming in September. 100+ speakers, 150+ sessions, and what's new and next for Power Platform.

Top Solution Authors
Top Kudoed Authors