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
Anonymous
Not applicable

Dax Help- Subtotals and totals not adding up correctly in matrix report

Subtotals and totals not working with Sclier, I'm trying to calculate Prior Year Sales WTD calc using Dax , Here is the code.

SalesAmtPY:=
VAR DateRange =
    FILTER (
        ALL ( 'DimDate' ),
        'DimDate'[AdjustedYearNumber]
            = VALUES ( 'DimDate'[AdjustedYearNumber] ) - 1
            && CONTAINS (
                VALUES ( 'DimDate'[AdjustedWeekofYearNumber] ),
                'DimDate'[AdjustedWeekofYearNumber], 'DimDate'[AdjustedWeekofYearNumber]
            )
            && CONTAINS (
                VALUES ( 'DimDate'[AdjustedWeekofYearandDayofWeekNumber] ),
                'DimDate'[AdjustedWeekofYearandDayofWeekNumber], 'DimDate'[AdjustedWeekofYearandDayofWeekNumber]
            )
    )

     
RETURN
    IF (
        ISBLANK ( [SalesAmt] ),
        BLANK (),
        CALCULATE ( 'FactSales'[SalesAmt], DateRange, ALL ( DimStatus[StatusDescription],DimStatus[Status] ) )
    )

I'm ignoring Status by selecting ALL in Dax Measure. Status will change over time so when Calculating PY I should ignore Previous Year status . Here is sample data for Prior and current year.prioryear.pngcurrentyear.png

 

 

 

 

 

 

 

Here is output I would like to see, Its working as I want but when I select the "Status" in Sclier Grand totals and SubTotals doesn't change and they show same value and status will be always showing current year status. At the lowest level it working good.

report.png

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

@Anonymous ,

 

Because you have used ALL() function in your code, this will remove the filter on [status] column, modify the part of your measure like below and check if it can meet your requirement:

SalesAmtPY :=
VAR DateRange =
    FILTER (
        ALL ( 'DimDate' ),
        'DimDate'[AdjustedYearNumber]
            = VALUES ( 'DimDate'[AdjustedYearNumber] ) - 1
            && CONTAINS (
                VALUES ( 'DimDate'[AdjustedWeekofYearNumber] ),
                'DimDate'[AdjustedWeekofYearNumber], 'DimDate'[AdjustedWeekofYearNumber]
            )
            && CONTAINS (
                VALUES ( 'DimDate'[AdjustedWeekofYearandDayofWeekNumber] ),
                'DimDate'[AdjustedWeekofYearandDayofWeekNumber], 'DimDate'[AdjustedWeekofYearandDayofWeekNumber]
            )
    )
RETURN
    IF (
        ISBLANK ( [SalesAmt] ),
        BLANK (),
        CALCULATE ( 'FactSales'[SalesAmt], DateRange, ALLSELECTED ( DimStatus ) )
    )

Community Support Team _ Jimmy Tao

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

1 REPLY 1
v-yuta-msft
Community Support
Community Support

@Anonymous ,

 

Because you have used ALL() function in your code, this will remove the filter on [status] column, modify the part of your measure like below and check if it can meet your requirement:

SalesAmtPY :=
VAR DateRange =
    FILTER (
        ALL ( 'DimDate' ),
        'DimDate'[AdjustedYearNumber]
            = VALUES ( 'DimDate'[AdjustedYearNumber] ) - 1
            && CONTAINS (
                VALUES ( 'DimDate'[AdjustedWeekofYearNumber] ),
                'DimDate'[AdjustedWeekofYearNumber], 'DimDate'[AdjustedWeekofYearNumber]
            )
            && CONTAINS (
                VALUES ( 'DimDate'[AdjustedWeekofYearandDayofWeekNumber] ),
                'DimDate'[AdjustedWeekofYearandDayofWeekNumber], 'DimDate'[AdjustedWeekofYearandDayofWeekNumber]
            )
    )
RETURN
    IF (
        ISBLANK ( [SalesAmt] ),
        BLANK (),
        CALCULATE ( 'FactSales'[SalesAmt], DateRange, ALLSELECTED ( DimStatus ) )
    )

Community Support Team _ Jimmy Tao

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

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.