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

Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started

Reply
dxwalker
Frequent Visitor

Concatenating fields from two dimensions joined to the same fact table.

In OBIEE (Oracle Business Intellegence Enterprise Edition), we have multiple instances where we have a column which concatenates the values from 2 different Dimension tables which are joined to a Fact table. This can be done in the Repository Logical Layer or when an Analysis is created in OBIEE. The Oracle BI Engine creates the query sent to the Oracle database and the syntax is fairly simple. For example:

Select a.Name || ' ' || b.Description

from 

Fact_MyFact c

join Dim_Name a on a.Key = c.Name_Key

join Dim_Description b on b.Key = c.Description_Key

 

How can something similar be done in Power Query or Dax?

2 ACCEPTED SOLUTIONS
AmiraBedh
Resident Rockstar
Resident Rockstar

If you want to use PowerQuery :

let
Source_Fact = Table.FromRecords({[Key=1, Name_Key=1, Description_Key=1], [Key=2, Name_Key=2, Description_Key=2]}),
Source_Name = Table.FromRecords({[Key=1, Name="John"], [Key=2, Name="Doe"]}),
Source_Description = Table.FromRecords({[Key=1, Description="Engineer"], [Key=2, Description="Doctor"]}),

// Merge with Dim_Name table
Merge_Name = Table.NestedJoin(Source_Fact, {"Name_Key"}, Source_Name, {"Key"}, "NewColumn1", JoinKind.Inner),
Expand_Name = Table.ExpandTableColumn(Merge_Name, "NewColumn1", {"Name"}, {"Name"}),

// Merge with Dim_Description table
Merge_Description = Table.NestedJoin(Expand_Name, {"Description_Key"}, Source_Description, {"Key"}, "NewColumn2", JoinKind.Inner),
Expand_Description = Table.ExpandTableColumn(Merge_Description, "NewColumn2", {"Description"}, {"Description"}),

// Create Concatenated Column
Concat_Column = Table.AddColumn(Expand_Description, "Concatenated", each [Name] & " " & [Description])
in
Concat_Column

If you want to use DAX, create relationships between your tables (Fact and Dimension tables) in Power BI's model view. Then create a new calculated column in your fact table :

ConcatenatedColumn = RELATED(Dim_Name[Name]) & " " & RELATED(Dim_Description[Description])




Proud to be a Power BI Super User !

Microsoft Community : https://docs.microsoft.com/en-us/users/AmiraBedhiafi
Linkedin : https://www.linkedin.com/in/amira-bedhiafi/
StackOverflow : https://stackoverflow.com/users/9517769/amira-bedhiafi
C-Sharp Corner : https://www.c-sharpcorner.com/members/amira-bedhiafi
Power BI Community :https://community.powerbi.com/t5/user/viewprofilepage/user-id/332696

View solution in original post

If you are using Power BI : Organize Power BI DAX Measures in Folders - RADACAD

If you are using SSAS Tabular : Organize Calculated columns and Measures in Folder... - Microsoft Fabric Community


Proud to be a Power BI Super User !

Microsoft Community : https://docs.microsoft.com/en-us/users/AmiraBedhiafi
Linkedin : https://www.linkedin.com/in/amira-bedhiafi/
StackOverflow : https://stackoverflow.com/users/9517769/amira-bedhiafi
C-Sharp Corner : https://www.c-sharpcorner.com/members/amira-bedhiafi
Power BI Community :https://community.powerbi.com/t5/user/viewprofilepage/user-id/332696

View solution in original post

3 REPLIES 3
AmiraBedh
Resident Rockstar
Resident Rockstar

If you want to use PowerQuery :

let
Source_Fact = Table.FromRecords({[Key=1, Name_Key=1, Description_Key=1], [Key=2, Name_Key=2, Description_Key=2]}),
Source_Name = Table.FromRecords({[Key=1, Name="John"], [Key=2, Name="Doe"]}),
Source_Description = Table.FromRecords({[Key=1, Description="Engineer"], [Key=2, Description="Doctor"]}),

// Merge with Dim_Name table
Merge_Name = Table.NestedJoin(Source_Fact, {"Name_Key"}, Source_Name, {"Key"}, "NewColumn1", JoinKind.Inner),
Expand_Name = Table.ExpandTableColumn(Merge_Name, "NewColumn1", {"Name"}, {"Name"}),

// Merge with Dim_Description table
Merge_Description = Table.NestedJoin(Expand_Name, {"Description_Key"}, Source_Description, {"Key"}, "NewColumn2", JoinKind.Inner),
Expand_Description = Table.ExpandTableColumn(Merge_Description, "NewColumn2", {"Description"}, {"Description"}),

// Create Concatenated Column
Concat_Column = Table.AddColumn(Expand_Description, "Concatenated", each [Name] & " " & [Description])
in
Concat_Column

If you want to use DAX, create relationships between your tables (Fact and Dimension tables) in Power BI's model view. Then create a new calculated column in your fact table :

ConcatenatedColumn = RELATED(Dim_Name[Name]) & " " & RELATED(Dim_Description[Description])




Proud to be a Power BI Super User !

Microsoft Community : https://docs.microsoft.com/en-us/users/AmiraBedhiafi
Linkedin : https://www.linkedin.com/in/amira-bedhiafi/
StackOverflow : https://stackoverflow.com/users/9517769/amira-bedhiafi
C-Sharp Corner : https://www.c-sharpcorner.com/members/amira-bedhiafi
Power BI Community :https://community.powerbi.com/t5/user/viewprofilepage/user-id/332696

The related function to create a new calculated column in DAX works great. Do you know of a way to have the calculated column appear in a different "folder"? We are trying to emulate OBIEE Subject Areas to help the user community transition easier and having dimension data mixed with facts could be confusing for them. Thank you so much for the quick help!

If you are using Power BI : Organize Power BI DAX Measures in Folders - RADACAD

If you are using SSAS Tabular : Organize Calculated columns and Measures in Folder... - Microsoft Fabric Community


Proud to be a Power BI Super User !

Microsoft Community : https://docs.microsoft.com/en-us/users/AmiraBedhiafi
Linkedin : https://www.linkedin.com/in/amira-bedhiafi/
StackOverflow : https://stackoverflow.com/users/9517769/amira-bedhiafi
C-Sharp Corner : https://www.c-sharpcorner.com/members/amira-bedhiafi
Power BI Community :https://community.powerbi.com/t5/user/viewprofilepage/user-id/332696

Helpful resources

Announcements
July 2024 Power BI Update

Power BI Monthly Update - July 2024

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

PBI_Carousel_NL_June

Fabric Community Update - June 2024

Get the latest Fabric updates from Build 2024, key Skills Challenge voucher deadlines, top blogs, forum posts, and product ideas.

Top Solution Authors