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

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
Thigs
Helper III
Helper III

Incorrect result - SUMX two tables

Hi all, 

I am working with SUMX for the first time and with two different tables.

 

Yes, I have look at other similar posts, and my formula isn't throwing errors, but it isn't getting the correct result. 

 

I have two tables - Dimensions has a SKU number, height, weight, length and width. Each SKU is unique

Orders has Order Number, SKU number, quantity, and then several other columns not needed for this calculation. 

 

I am trying to figure out the average weight of orders per day. 

 

Here is my formula - 

New Measure Try = sumx(Orders, Orders[Quantity] * AVERAGE('Dimensions'[weight]))
 
This is getting larger numbers than when I do it in Excel. Is the "Average" the issue? I can't seem to tell it to do SUMX without using some kind of calculation for the second table. The two tables have a one-many relationship, with Dimensions being the one. 
 
Any help is super appreciated!
1 ACCEPTED SOLUTION
OwenAuger
Super User
Super User

Hi @Thigs 

Based on what you've described, here is what I would suggest if I were creating these calculations:

 

Create these measures:

Order Quantity =
SUM ( Orders[Quantity] )
Total Weight =
SUMX (
    SUMMARIZE ( Orders, 'Dimensions'[weight] ),
    'Dimensions'[weight] * [Order Quantity]
)

The Total Weight measure takes the distinct weights for SKUs appearing in the Orders table, and multiplies these by the corresponding Order Quantity and sums.

 

Then for the average weight, did you want the average weight per order?

You would first need a measure that returns the Order Count, either by counting distinct Order Numbers, or counting rows of Orders (whichever is correct), i.e.:

Order Count =
DISTINCTCOUNT ( Orders[Order Number] )

or

Order Count =
COUNTROWS ( Orders )

Then the average weight per order would be:

Order Average Weight =
DIVIDE ( [Total Weight], [Order Count] )

 

Does the above help get the result you were looking for?

Please post back if needed.

 

Regards,

Owen

 


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

View solution in original post

2 REPLIES 2
OwenAuger
Super User
Super User

Hi @Thigs 

Based on what you've described, here is what I would suggest if I were creating these calculations:

 

Create these measures:

Order Quantity =
SUM ( Orders[Quantity] )
Total Weight =
SUMX (
    SUMMARIZE ( Orders, 'Dimensions'[weight] ),
    'Dimensions'[weight] * [Order Quantity]
)

The Total Weight measure takes the distinct weights for SKUs appearing in the Orders table, and multiplies these by the corresponding Order Quantity and sums.

 

Then for the average weight, did you want the average weight per order?

You would first need a measure that returns the Order Count, either by counting distinct Order Numbers, or counting rows of Orders (whichever is correct), i.e.:

Order Count =
DISTINCTCOUNT ( Orders[Order Number] )

or

Order Count =
COUNTROWS ( Orders )

Then the average weight per order would be:

Order Average Weight =
DIVIDE ( [Total Weight], [Order Count] )

 

Does the above help get the result you were looking for?

Please post back if needed.

 

Regards,

Owen

 


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

Ah! Perfect! Thanks SO much!

 

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

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

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

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