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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Royoam
New Member

Copy data from another table

Hi, I m new to PowerBi. Currently, I encountered an issue about getting data from one table to another table, below is my trouble:

Table 1
Case numberDescriptionResponseResolution
1234zzzzzzzxxxyyy
    
Table 2 
NumberTargetWanted value 
1234Responsexxx 
1234Resolutionyyy 


Table 1 initially gets two column fields only, I want to add two columns "response" & "resolution" into it in which their value should be referred from table 2. Table 1 [Case number] & Table 2 [Number] formed the relationship.

 

Please help to advise how to proceed. Thanks !!

1 ACCEPTED SOLUTION
Vera_33
Resident Rockstar
Resident Rockstar

Hi @Royoam 

 

Merge table1 and table2, then get the column value

Vera_33_0-1626923276696.png

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQyNlHSUaqCAKXYWAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Case number" = _t, Description = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Case number", Int64.Type}, {"Description", type text}}),
    #"Merged Queries" = Table.NestedJoin(#"Changed Type", {"Case number"}, Table2, {"Number"}, "Table2", JoinKind.LeftOuter),
    #"Added Custom" = Table.AddColumn(#"Merged Queries", "Response", each Table.SelectRows([Table2], each [Target]="Response")[Wanted value]{0}?),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "Resolution", each Table.SelectRows([Table2], each [Target]="Resolution")[Wanted value]{0}?),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom1",{"Table2"})
in
    #"Removed Columns"

 

Or you can pivot table2 first, then merge two tables, no need to add columns, this is table2

Vera_33_1-1626923437378.png

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQyNlHSUQpKLS7IzytOBTIrKiqUYnWQZfJzSksy8/OAnMrKSqXYWAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Number = _t, Target = _t, #"Wanted value" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Number", Int64.Type}, {"Target", type text}, {"Wanted value", type text}}),
    #"Pivoted Column" = Table.Pivot(#"Changed Type", List.Distinct(#"Changed Type"[Target]), "Target", "Wanted value")
in
    #"Pivoted Column"

 

View solution in original post

3 REPLIES 3
Syndicate_Admin
Administrator
Administrator

Hi @Royoam 

 

Merge table1 and table2, then get the column value

Vera_33_0-1626923276696.png

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQyNlHSUaqCAKXYWAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Case number" = _t, Description = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Case number", Int64.Type}, {"Description", type text}}),
    #"Merged Queries" = Table.NestedJoin(#"Changed Type", {"Case number"}, Table2, {"Number"}, "Table2", JoinKind.LeftOuter),
    #"Added Custom" = Table.AddColumn(#"Merged Queries", "Response", each Table.SelectRows([Table2], each [Target]="Response")[Wanted value]{0}?),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "Resolution", each Table.SelectRows([Table2], each [Target]="Resolution")[Wanted value]{0}?),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom1",{"Table2"})
in
    #"Removed Columns"

 

Or you can pivot table2 first, then merge two tables, no need to add columns, this is table2

Vera_33_1-1626923437378.png

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQyNlHSUQpKLS7IzytOBTIrKiqUYnWQZfJzSksy8/OAnMrKSqXYWAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Number = _t, Target = _t, #"Wanted value" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Number", Int64.Type}, {"Target", type text}, {"Wanted value", type text}}),
    #"Pivoted Column" = Table.Pivot(#"Changed Type", List.Distinct(#"Changed Type"[Target]), "Target", "Wanted value")
in
    #"Pivoted Column"

 

Vera_33
Resident Rockstar
Resident Rockstar

Hi @Royoam 

 

Merge table1 and table2, then get the column value

Vera_33_0-1626923276696.png

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQyNlHSUaqCAKXYWAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Case number" = _t, Description = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Case number", Int64.Type}, {"Description", type text}}),
    #"Merged Queries" = Table.NestedJoin(#"Changed Type", {"Case number"}, Table2, {"Number"}, "Table2", JoinKind.LeftOuter),
    #"Added Custom" = Table.AddColumn(#"Merged Queries", "Response", each Table.SelectRows([Table2], each [Target]="Response")[Wanted value]{0}?),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "Resolution", each Table.SelectRows([Table2], each [Target]="Resolution")[Wanted value]{0}?),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom1",{"Table2"})
in
    #"Removed Columns"

 

Or you can pivot table2 first, then merge two tables, no need to add columns, this is table2

Vera_33_1-1626923437378.png

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQyNlHSUQpKLS7IzytOBTIrKiqUYnWQZfJzSksy8/OAnMrKSqXYWAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Number = _t, Target = _t, #"Wanted value" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Number", Int64.Type}, {"Target", type text}, {"Wanted value", type text}}),
    #"Pivoted Column" = Table.Pivot(#"Changed Type", List.Distinct(#"Changed Type"[Target]), "Target", "Wanted value")
in
    #"Pivoted Column"

 

Thanks a lot...it works..

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors