Fabric is Generally Available. Browse Fabric Presentations. Work towards your Fabric certification with the Cloud Skills Challenge.
Hi,
I created a new table (table 3) with some measures from another table (table 1) and now i need to add 3 collumns from a third table (table 2) through mulple relationships (i.e., date, and moment of the day).
I know how to merge columns from different tables with Power Query but the new table created (table 3) is not displayed in Power Query (maybe because it is not imported externally).
What are the best solutions:
1) How to add columns from 2 different tables?
2) How to dynamically merge columns from 2 different tables with at least 2 relationships without Power Query?
Thanks
SQ
Solved! Go to Solution.
Hi @sergioquerido ,
You can achieve this by using ADDCOLUMNS and FILTER()
Here is may example:
Please try:
RealxExpected =
ADDCOLUMNS (
SUMMARIZE ( GPS, GPS[Date], GPS[Unit Number], GPS[Period] ),
"REAL_WORKLOAD", [%_WORKLOAD],
"REAL_ENDURANCE", GPS[%_TOTAL DISTANCE],
"Column1",CALCULATE(MAX('Table 2'[Column1]),FILTER('Table 2','Table 2'[Date]=EARLIER(GPS[Date])&&[Period]=EARLIER(GPS[Period]))),
"Column2",CALCULATE(MAX('Table 2'[Column2]),FILTER('Table 2','Table 2'[Date]=EARLIER(GPS[Date])&&[Period]=EARLIER(GPS[Period])))
)
Final output:
It works! Thanks!
SQ
Hi @sergioquerido ,
You can achieve this by using ADDCOLUMNS and FILTER()
Here is may example:
Please try:
RealxExpected =
ADDCOLUMNS (
SUMMARIZE ( GPS, GPS[Date], GPS[Unit Number], GPS[Period] ),
"REAL_WORKLOAD", [%_WORKLOAD],
"REAL_ENDURANCE", GPS[%_TOTAL DISTANCE],
"Column1",CALCULATE(MAX('Table 2'[Column1]),FILTER('Table 2','Table 2'[Date]=EARLIER(GPS[Date])&&[Period]=EARLIER(GPS[Period]))),
"Column2",CALCULATE(MAX('Table 2'[Column2]),FILTER('Table 2','Table 2'[Date]=EARLIER(GPS[Date])&&[Period]=EARLIER(GPS[Period])))
)
Final output:
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.
Join us for a free, hands-on Microsoft workshop led by women trainers for women where you will learn how to build a Dashboard in a Day!