March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
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.
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.
Solved! Go to Solution.
@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.
@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.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
114 | |
76 | |
57 | |
52 | |
44 |
User | Count |
---|---|
164 | |
116 | |
63 | |
57 | |
50 |