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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
gustafwallin
New Member

Dax Cacluate expression with Excel pivot table Grand totals

Hi, 

 

I have two distinct questions relation to solving the following matters. One is pure DAX related, and the other is why the grand totals in my pivot table does not compute accurately. I do hower think they are related in some way. 

 

Basic question: I wish to calculate the total number of "active machines" in a certain year to perform a cost analysis. This means  each machine is active between the time of Purchasing and Decomission. 

 

The following INVENTORY table shows this: 

 

Machine nrPurchaseDateDecomissioned
12017-01-022018-05-10
22018-01-022021-09-13
32010-06-052016-09-13
42018-01-022021-09-13
52018-01-022021-09-13

 

The Dax formula im trying to write should include the active machine to the year it was decomissioned. 

for example: the number of machines active during 2018 would be 4 (Machine number 1, 2, 4, 5) even though machinie 1 was decommisioned during 2018. 

My Dax formula looks like this (using a date table) but it does not seem to work correctly: 

 

(for context  the AO__Tabell is registering costs relating to the machines each year which we sum for each corresponding year. )

 

=VAR maxDate=ENDOFYEAR(AO___Tabell[Reg. date]) -- Filtered by context in the pivot table. 


RETURN CALCULATE(COUNTROWS(INVENTORY);FILTER(INVENTORY;INVENTORY[PurchaseDate] <=maxDate && (INVENTORY[Decomissioned] >maxDate || INVENTORY[Decommisioned] IN DATESINPERIOD('Date'[Date];STARTOFYEAR('Date'[Date]);1;YEAR))))

 

In addition, while this DAX does not work perfectly - I get very wrong Grand totals in my pivot table (see picture below). Im guessing this has to do with the grand totals in pivot tables not taking into account the DAX filters im using. If that is the case, how can the DAX formula be changed to accomodate this?  

 

gustafwallin_0-1665068452352.png

 

Very thankful for any help that is available! 

 

Sincerely, 

Gustaf

 

 

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

Hi @gustafwallin ,

 

According to your description, I made a sample, and here is my solution.

Create a DATE table.

 

DATE =
CALENDAR ( MIN ( 'Table'[PurchaseDate] ), MAX ( 'Table'[Decomissioned] ) )

 

Do not establish a relationship between two tables.

vxiaosunmsft_0-1665135132983.png

Create a measure to display the active machine nr.

 

active machines =
VAR _slice =
    ENDOFYEAR ( 'DATE'[Date] )
RETURN
    IF (
        COUNTROWS (
            FILTER (
                _slice,
                MAX ( 'Table'[PurchaseDate] ) <= _slice
                    && MAX ( 'Table'[Decomissioned] ) > _slice
                    || MAX ( 'Table'[Decomissioned] )
                        IN DATESINPERIOD ( 'DATE'[Date], STARTOFYEAR ( 'DATE'[Date] ), 1, YEAR )
            )
        ) > 0,
        MAX ( 'Table'[Machine nr] ),
        BLANK ()
    )

 

Create a measure to calculate the total numbers of the active machines.

 

number of active machines =
VAR _slice =
    ENDOFYEAR ( 'DATE'[Date] )
RETURN
    CALCULATE (
        COUNTROWS ( 'Table' ),
        FILTER (
            'Table',
            'Table'[PurchaseDate] <= _slice
                && (
                    'Table'[Decomissioned] > _slice
                        || 'Table'[Decomissioned]
                            IN DATESINPERIOD ( 'DATE'[Date], STARTOFYEAR ( 'DATE'[Date] ), 1, YEAR )
                )
        )
    )

 

Put “Year” of DATE into slicer, and then select the year, you will get the Final output:

vxiaosunmsft_1-1665135177067.png

 

I attach my sample below for your reference.

 

Best Regards,
Community Support Team _ xiaosun

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

4 REPLIES 4
v-xiaosun-msft
Community Support
Community Support

Hi @gustafwallin ,

 

According to your description, I made a sample, and here is my solution.

Create a DATE table.

 

DATE =
CALENDAR ( MIN ( 'Table'[PurchaseDate] ), MAX ( 'Table'[Decomissioned] ) )

 

Do not establish a relationship between two tables.

vxiaosunmsft_0-1665135132983.png

Create a measure to display the active machine nr.

 

active machines =
VAR _slice =
    ENDOFYEAR ( 'DATE'[Date] )
RETURN
    IF (
        COUNTROWS (
            FILTER (
                _slice,
                MAX ( 'Table'[PurchaseDate] ) <= _slice
                    && MAX ( 'Table'[Decomissioned] ) > _slice
                    || MAX ( 'Table'[Decomissioned] )
                        IN DATESINPERIOD ( 'DATE'[Date], STARTOFYEAR ( 'DATE'[Date] ), 1, YEAR )
            )
        ) > 0,
        MAX ( 'Table'[Machine nr] ),
        BLANK ()
    )

 

Create a measure to calculate the total numbers of the active machines.

 

number of active machines =
VAR _slice =
    ENDOFYEAR ( 'DATE'[Date] )
RETURN
    CALCULATE (
        COUNTROWS ( 'Table' ),
        FILTER (
            'Table',
            'Table'[PurchaseDate] <= _slice
                && (
                    'Table'[Decomissioned] > _slice
                        || 'Table'[Decomissioned]
                            IN DATESINPERIOD ( 'DATE'[Date], STARTOFYEAR ( 'DATE'[Date] ), 1, YEAR )
                )
        )
    )

 

Put “Year” of DATE into slicer, and then select the year, you will get the Final output:

vxiaosunmsft_1-1665135177067.png

 

I attach my sample below for your reference.

 

Best Regards,
Community Support Team _ xiaosun

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Thank you very much for this elaborate reply. This was way more than I hoped for. This definately does the trick, even though I'll have to sharpen my DAX skills to fully understand the formulas. I'll try and make the connections in Power BI to my larger Data model! 

 

Again, thanks a lot! 

Hi Amit!

Thanks for the links, that is some clean looking variants that seem to somewhat apply to my specific problem. 

I'll have to look into it more closely, but the first example you sent seemed very similar. 

 

Again, Thank you! 

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors