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

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
martinstronic
New Member

How to Merge two different Collumns and add values to them

Hi everyone! I hope you are doing fine!

 

I need to merge two different tables and add values to one of them to each value I have in the dimesion table. For example:

 

In one table I have the name of the training and who did it.  

martinstronic_1-1643299203611.png

 

In the other, I have the name of the Trainings:

martinstronic_2-1643299962870.png

What I need is to discover what training were not done yet:

 

martinstronic_3-1643300151569.png

In this case, I know that the blank rows is the missing trainings.

 

Is that a way to do this with DAX or M? I've tried several forms using union, except, join in DAX and All the merge options in Power Query, but I have success only using 1 number. 

 

Let me know if you need some extra info. Thanks!


https://drive.google.com/file/d/1Jha1Pgxr-_erpdomTIEwriC2QVdtHEbF/view?usp=sharing 

 

 

1 ACCEPTED SOLUTION
lbendlin
Super User
Super User

This can be done in Power Query, here is one possible implementation:

let
    Fonte = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjAwMFTSUQopSszMy8xLN1SK1cEQNMImaIxN0ASboClM0AibRUbYLDIipN0cJmiM6qRYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Number = _t, Training = _t]),
    #"Grouped Rows" = Table.Group(Fonte, {"Number"}, {{"Rows", each _, type table [Number=nullable text, Training=nullable text]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Ref", each Trainings),
    #"Expanded Ref" = Table.ExpandTableColumn(#"Added Custom", "Ref", {"All Trainings"}, {"All Trainings"}),
    #"Added Custom1" = Table.AddColumn(#"Expanded Ref", "Training", each if List.Contains([Rows][Training],[All Trainings]) then [All Trainings] else null),
    #"Removed Other Columns" = Table.SelectColumns(#"Added Custom1",{"Number", "All Trainings", "Training"})
in
    #"Removed Other Columns"

 

See attached.

View solution in original post

2 REPLIES 2
lbendlin
Super User
Super User

This can be done in Power Query, here is one possible implementation:

let
    Fonte = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjAwMFTSUQopSszMy8xLN1SK1cEQNMImaIxN0ASboClM0AibRUbYLDIipN0cJmiM6qRYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Number = _t, Training = _t]),
    #"Grouped Rows" = Table.Group(Fonte, {"Number"}, {{"Rows", each _, type table [Number=nullable text, Training=nullable text]}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Ref", each Trainings),
    #"Expanded Ref" = Table.ExpandTableColumn(#"Added Custom", "Ref", {"All Trainings"}, {"All Trainings"}),
    #"Added Custom1" = Table.AddColumn(#"Expanded Ref", "Training", each if List.Contains([Rows][Training],[All Trainings]) then [All Trainings] else null),
    #"Removed Other Columns" = Table.SelectColumns(#"Added Custom1",{"Number", "All Trainings", "Training"})
in
    #"Removed Other Columns"

 

See attached.

Hey Ibendlin! Thank you so much for this!

 

It was exactly what I was in need! Have a nice week!

Helpful resources

Announcements
PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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