Fabric is Generally Available. Browse Fabric Presentations. Work towards your Fabric certification with the Cloud Skills Challenge.
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?
Solved! Go to Solution.
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])
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
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])
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
Check out the November 2023 Power BI update to learn about new features.
Read the latest Fabric Community announcements, including updates on Power BI, Synapse, Data Factory and Data Activator.