cancel
Showing results for 
Search instead for 
Did you mean: 
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
September Update

Check it Out!

Click here to learn more about the September 2022 updates!

Power BI Show Episode 10 Recap

The Power BI Community Show

Watch the playback when Amit Chandak, a Power BI Super User, demos how to use Field Parameters to make reports more dynamic.

Power BI Dev Camp Session 26

New Date - Check it Out!

Mark your calendars and join us on Thursday, October 6 at 11a PDT for a great session with Ted Pattison!

Health and Life Sciences Power BI User Group

Health and Life Sciences Power BI User Group

Power BI specialists at Microsoft have created a community user group where customers in the provider, payor, pharma, health solutions, and life science industries can collaborate.

Top Solution Authors