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

Power BI is turning 10! Let’s celebrate together with dataviz contests, interactive sessions, and giveaways. Register now.

Reply
POSPOS
Post Patron
Post Patron

How to create a summary table

Hi All,

I have three tables (Master, Source 1, Source 2).

Based on the tables, my requriement is to create a summary table:

Sample file -Download

Master Table:

DeptDivSales
Dept ADiv 1500
Dept ADiv 2620
Dept ADiv 3800
Dept BDiv 1700
Dept BDiv 11560
Dept CDiv 5800

 

Source 1:

DeptDivSales
Dept ADiv 1700
Dept ADiv 2700
Dept ADiv 3900
Dept ADiv 5205
Dept ADiv 11650
Dept BDiv 1900
Dept BDiv 11600
Dept BDiv 2200
Dept CDiv 5900

 

Source 2:

DeptDivSales
Dept ADiv 1500
Dept ADiv 2700
Dept ADiv 3900
Dept ADiv 2620
Dept ADiv 11800
Dept BDiv 1700
Dept BDiv 11900
Dept CDiv 5800
Dept EDiv 3500

 

Expected Output:

POSPOS_2-1734454006155.png

Requirement is to create a summary table with all the data from the three tables.

 

Dept = Union of all values from Master, Source 1, Source 2 tables

Div =  Union of all values from Master, Source 1, Source 2 tables
Sales 1=  Sales value from Master Table

Sale 2 = Sale 2 from Source 1 minus Sales value from Master Table

Sale 3 = Sale 3 from Source 2 minus Sales value from Master Table

 

Can someone please suggest on how to achieve this?

Thank you

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @POSPOS ,

 

Please create a new table :

vcgaomsft_0-1734487554026.png

And 3 measures:

 

Sales 1 = 
VAR __curr_dept = MAX('Table'[Dept])
VAR __curr_div = MAX('Table'[Div])
VAR __result = IF( HASONEVALUE('Table'[Dept]), CALCULATE(SUM('Master'[Sales]),'Master'[Dept]=__curr_dept&&'Master'[Div]=__curr_div), SUM('Master'[Sales]))
RETURN
    __result
Sales 2 = 
VAR __curr_dept = MAX('Table'[Dept])
VAR __curr_div = MAX('Table'[Div])
VAR __sales = IF(HASONEVALUE('Table'[Dept]), CALCULATE(SUM('Source 1'[Sales]),'Source 1'[Dept]=__curr_dept, 'Source 1'[Div]=__curr_div), SUM('Source 1'[Sales]))
VAR __result = __sales - [Sales 1]
RETURN
    __result
Sales 3 = 
VAR __curr_dept = MAX('Table'[Dept])
VAR __curr_div = MAX('Table'[Div])
VAR __sales = IF( HASONEVALUE('Table'[Dept]), CALCULATE(SUM('Source 2'[Sales]),'Source 2'[Dept]=__curr_dept, 'Source 2'[Div]=__curr_div), SUM('Source 2'[Sales]))
VAR __result = __sales - [Sales 1]
RETURN
    __result

 

vcgaomsft_1-1734487619027.png

Best Regards,
Gao

Community Support Team

 

If there is any post helps, then please consider Accept it as the solution  to help the other members find it more quickly.
If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!

How to get your questions answered quickly --  How to provide sample data in the Power BI Forum

View solution in original post

11 REPLIES 11
lbendlin
Super User
Super User

please explain what you mean by "minus".

 

lbendlin_0-1734466600892.png

 

@lbendlin  I was referrning to "Minus" as "Difference"/"Substraction" between two values.

Dept = Union of all values from Master, Source 1, Source 2 tables

Div =  Union of all values from Master, Source 1, Source 2 tables
Sales 1=  Sales value from Master Table

Sale 2 = Sale 2 from Source 1 difference Sales value from Master Table 

Sale 3 = Sale 3 from Source 2 difference Sales value from Master Table

I used EXCEPT but that removes the exact matches - you will need to modify that to remove the difference regardless of exact matches.

@lbendlin  - Thanks for your response. We were looking for having Sales as three different measures (Sales,Sale1 and Sale2)as we cannot use a matrix as there are many more additional columns that we have and also to use these measures for further calculations.

Please provide sample data that fully covers your issue.
Please show the expected outcome based on the sample data you provided.

@lbendlin  - Expected output is as provided in the post above where We will need three measures separately.

Anonymous
Not applicable

Hi @POSPOS ,

 

Please create a new table :

vcgaomsft_0-1734487554026.png

And 3 measures:

 

Sales 1 = 
VAR __curr_dept = MAX('Table'[Dept])
VAR __curr_div = MAX('Table'[Div])
VAR __result = IF( HASONEVALUE('Table'[Dept]), CALCULATE(SUM('Master'[Sales]),'Master'[Dept]=__curr_dept&&'Master'[Div]=__curr_div), SUM('Master'[Sales]))
RETURN
    __result
Sales 2 = 
VAR __curr_dept = MAX('Table'[Dept])
VAR __curr_div = MAX('Table'[Div])
VAR __sales = IF(HASONEVALUE('Table'[Dept]), CALCULATE(SUM('Source 1'[Sales]),'Source 1'[Dept]=__curr_dept, 'Source 1'[Div]=__curr_div), SUM('Source 1'[Sales]))
VAR __result = __sales - [Sales 1]
RETURN
    __result
Sales 3 = 
VAR __curr_dept = MAX('Table'[Dept])
VAR __curr_div = MAX('Table'[Div])
VAR __sales = IF( HASONEVALUE('Table'[Dept]), CALCULATE(SUM('Source 2'[Sales]),'Source 2'[Dept]=__curr_dept, 'Source 2'[Div]=__curr_div), SUM('Source 2'[Sales]))
VAR __result = __sales - [Sales 1]
RETURN
    __result

 

vcgaomsft_1-1734487619027.png

Best Regards,
Gao

Community Support Team

 

If there is any post helps, then please consider Accept it as the solution  to help the other members find it more quickly.
If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!

How to get your questions answered quickly --  How to provide sample data in the Power BI Forum

@Anonymous  - When I use the above measures in another calcuated column, then I get circular dependency error.
eg: column = if( sales 2 <>0, "Y","N")

Can you please suggest on to fix this.

Anonymous
Not applicable

Hi @POSPOS ,

 

These two blogs explain the cause of the error and how to avoid it.

Understanding circular dependencies in DAX - SQLBI
Avoiding circular dependency errors in DAX - SQLBI

You can also consider going to build the previous table in Powerquery, see the steps in Query1.

vcgaomsft_0-1734660373890.png

Best Regards,
Gao

Community Support Team

 

If there is any post helps, then please consider Accept it as the solution  to help the other members find it more quickly.
If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!

How to get your questions answered quickly --  How to provide sample data in the Power BI Forum

@Anonymous  - This worked and saved a lot of our development effort. Much appreciated for the detailed steps. 🙂

@Anonymous  - Thank you for your response. This is very helpful. 
Could you please help me tweak the logic for Sales 2 and Sales 3 to only when the below condition is satisfied?

Sale 2 = Sale 2 from Source 1 difference Sales value from Master Table only for the Dept which is common in "Source 1" and "Master Table" and Div should not exist in "Master" Table

 

Sale 3 = Sale 3 from Source 2 difference Sales value from Master Table only for the Div which is common in "Source 1" and "Master Table" and Dept should not exist in Master Table

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

Find out what's new and trending in the Fabric community.