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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
siva6063
Regular Visitor

How to do different calculation when drillup

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

CategorySubcategoryDensityPricecost
PacketsPlastic

1000

$50$50000
PacketsPlastic11000$50$50000
PacketsPlastic2850$40$34000
CupsPaper550$55$30250
CupsPaper1550$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

 

CategoryDensityPricecost
PacketsSum(1000+1000+850) =2850

Formula =Cost/density

134000/2850=47.017

sum(50000,50000,34000)=134000
CupsSum(550+550)=110056100/1100=51sum(30250+25850)=56100

 

I tried several methods but stil no success. Not sure if i have explained it clearly.

 

Can someone help?

3 REPLIES 3
harshnathani
Community Champion
Community Champion

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
    )

 

 

1.jpg2.JPG

 

Regards,
Harsh Nathani

Did I answer your question? Mark my post as a solution! Appreciate with a Kudos!! (Click the Thumbs Up Button)

 

kriscoupe
Responsive Resident
Responsive Resident

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

AllisonKennedy
Super User
Super User

What you have explained will result in a circular reference error as Cost at product level needs Price to be calculated, so we can't use that same cost to calculate the price again without it being in a separate field/measure /column.

You will need to use something like SUMX ultimately to do what you want.

Please @mention me in your reply if you want a response.

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

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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

Top Solution Authors