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
vyny17
Frequent Visitor

Create a reference table from three tables

Hi there, Power BI enthusiasts and specialists!

 

Here is the trouble:

 

I have three different tables, each table has the same three columns, these columns tell the respective client, the client's departament and the client's salesman (the data is always standardized). There are other columns in each one of theses table that inform other kind of data, but that's not relevant to the problem.

 

Here is an example of these tables:

 

vyny17_2-1656700794612.png

 

vyny17_3-1656700797448.png

 

vyny17_4-1656700799191.png

 

I want - using DAX or Power Query - to create a fourth table that reunites all of these three columns (the set of three columns cannot have duplicates), this table must seem like this:

 

vyny17_6-1656700878168.png

 

 

It must act like a reference or dim table, how can I do that? 

 

1 ACCEPTED SOLUTION
ManguilibeKAO
Resolver I
Resolver I

Hi vyny17,

 

Here's a solution:

 

Create a new table Table4, with the following DAX formula:

 

Table4 =
Var Tablea=SelectColumns('Table1',
                                            "Client",[Client],
                                           "Department",[Department],
                                           "Salesman",[Salesman]
                                          )
Var Tableb=SelectColumns('Table2',
                                            "Client",[Client],
                                            "Department",[Department],
                                            "Salesman",[Salesman]
                                           )
Var Tablec=SelectColumns('Table3',
                                           "Client",[Client],
                                            "Department",[Department],
                                            "Salesman",[Salesman]
                                          )
Var UnionTable = union (Tablea,Tableb,Tablec)
Var finalTable = SUMMARIZE(UnionTable,[Client],[Department],[Salesman])
return finalTable
 
Note that I've assumed that your first table is called Table1,  that your second table is called Table2, and that your third table is called Table3.
 
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
 
Manguilibe KAO

View solution in original post

1 REPLY 1
ManguilibeKAO
Resolver I
Resolver I

Hi vyny17,

 

Here's a solution:

 

Create a new table Table4, with the following DAX formula:

 

Table4 =
Var Tablea=SelectColumns('Table1',
                                            "Client",[Client],
                                           "Department",[Department],
                                           "Salesman",[Salesman]
                                          )
Var Tableb=SelectColumns('Table2',
                                            "Client",[Client],
                                            "Department",[Department],
                                            "Salesman",[Salesman]
                                           )
Var Tablec=SelectColumns('Table3',
                                           "Client",[Client],
                                            "Department",[Department],
                                            "Salesman",[Salesman]
                                          )
Var UnionTable = union (Tablea,Tableb,Tablec)
Var finalTable = SUMMARIZE(UnionTable,[Client],[Department],[Salesman])
return finalTable
 
Note that I've assumed that your first table is called Table1,  that your second table is called Table2, and that your third table is called Table3.
 
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
 
Manguilibe KAO

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.