Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.
Hi All
Thanks in Advance.
Im stuck with this requitement, it would be great if i get some help.
I have this wiered requirement, that, the drill up to higher level should do a different calculation based on the results from the previous level . Is this ever possible.
Matrix At Lower Level (SubCategory :
In the table below, category, subcategory, density and price i get from source table
I have a measure in report to calculate cost=Density*Price
Calculation at this hierarchy level is the cost
Category | Subcategory | Density | Price | cost |
Packets | Plastic | 1000 | $50 | $50000 |
Packets | Plastic1 | 1000 | $50 | $50000 |
Packets | Plastic2 | 850 | $40 | $34000 |
Cups | Paper | 550 | $55 | $30250 |
Cups | Paper1 | 550 | $47 | $25850 |
Matrix when drill up to Category 2
Sshould show up like below. Basically, calculation here is the price, which is
sum (cost for the category) from previous hierarchy level divided by
sum (density for the category) in the previous hierarchy level
Category | Density | Price | cost |
Packets | Sum(1000+1000+850) =2850 | Formula =Cost/density 134000/2850=47.017 | sum(50000,50000,34000)=134000 |
Cups | Sum(550+550)=1100 | 56100/1100=51 | sum(30250+25850)=56100 |
I tried several methods but stil no success. Not sure if i have explained it clearly.
Can someone help?
Hi @siva6063 ,
Write a measure llike this.
Values =
VAR _inscopecat =
ISINSCOPE ( 'Table'[Category] )
VAR _inscopesub =
ISINSCOPE ( 'Table'[Subcategory] )
VAR _totalpricebycat =
CALCULATE (
SUM ( 'Table'[Price] ),
ALLEXCEPT (
'Table',
'Table'[Category]
)
)
VAR _totaldensitybycat =
CALCULATE (
SUM ( 'Table'[Density] ),
ALLEXCEPT (
'Table',
'Table'[Category]
)
)
VAR _totalcost =
SUMX (
'Table',
'Table'[Density] * 'Table'[Price]
)
VAR _totalcostbycat =
SUMX (
FILTER (
ALL ( 'Table' ),
'Table'[Category]
= MAX ( 'Table'[Category] )
),
'Table'[Density] * 'Table'[Price]
)
RETURN
SWITCH (
TRUE (),
_inscopesub
= TRUE (), DIVIDE (
_totalcostbycat,
_totaldensitybycat
),
_inscopecat
= TRUE (), _totalcost
)
Regards,
Harsh Nathani
Did I answer your question? Mark my post as a solution! Appreciate with a Kudos!! (Click the Thumbs Up Button)
Hi @siva6063,
You'll need to use a SUMX formula for this one. Something along these lines
SUMX(
YourTable,
Density * Price
)
This effectively iterate through all rows of YourTable calculating Density * Price and then adds them all up. This measure should work no matter what level you then drill into.
Hope it helps. If I answered your question please mark my answer as a solution so others can find this in the future.
Kris
Copying DAX from this post? Click here for a hack to quickly replace it with your own table names
Has this post solved your problem? Please Accept as Solution so that others can find it quickly and to let the community know your problem has been solved.
If you found this post helpful, please give Kudos C
I work as a Microsoft trainer and consultant, specialising in Power BI and Power Query.
www.excelwithallison.com
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
10 | |
9 | |
9 | |
8 | |
8 |
User | Count |
---|---|
14 | |
12 | |
11 | |
11 | |
8 |