cancel
Showing results for 
Search instead for 
Did you mean: 

Fabric is Generally Available. Browse Fabric Presentations. Work towards your Fabric certification with the Cloud Skills Challenge.

Reply
sergioquerido
Frequent Visitor

How to merge columns from different tables in a new table caculation not displayed in Power Query

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?

This is the code of the created new table (table 3):
RealxExpected = ADDCOLUMNS(SUMMARIZE(
     GPS, GPS[Date], GPS[Unit Number], GPS[Period]),
     "REAL_WORKLOAD", [%_WORKLOAD],
     "REAL_ENDURANCE", GPS[%_TOTAL DISTANCE],
     "REAL_SHORT", DIVIDE([%_ACC&DEC>2]+[%_ACC&DEC>3],2),
     "REAL_LONG", DIVIDE([%_HSD-Z5]+[%_SD-Z6],2))
 

2) How to dynamically merge columns from 2 different tables with at least 2 relationships without Power Query?

 

Thanks

 

SQ

1 ACCEPTED SOLUTION
v-jianboli-msft
Community Support
Community Support

Hi @sergioquerido ,

 

You can achieve this by using ADDCOLUMNS and FILTER()

Here is may example:

vjianbolimsft_0-1676018435372.png

vjianbolimsft_1-1676018457457.png

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:

vjianbolimsft_2-1676018489250.png

 

 

 

View solution in original post

2 REPLIES 2
sergioquerido
Frequent Visitor

It works! Thanks!

 

SQ

v-jianboli-msft
Community Support
Community Support

Hi @sergioquerido ,

 

You can achieve this by using ADDCOLUMNS and FILTER()

Here is may example:

vjianbolimsft_0-1676018435372.png

vjianbolimsft_1-1676018457457.png

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:

vjianbolimsft_2-1676018489250.png

 

 

 

Helpful resources

Announcements
PBI November 2023 Update Carousel

Power BI Monthly Update - November 2023

Check out the November 2023 Power BI update to learn about new features.

Community News

Fabric Community News unified experience

Read the latest Fabric Community announcements, including updates on Power BI, Synapse, Data Factory and Data Activator.

Dashboard in a day with date

Exclusive opportunity for Women!

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!

Power BI Fabric Summit Carousel

The largest Power BI and Fabric virtual conference

130+ sessions, 130+ speakers, Product managers, MVPs, and experts. All about Power BI and Fabric. Attend online or watch the recordings.

Top Solution Authors
Top Kudoed Authors