The ultimate Microsoft Fabric, Power BI, Azure AI, and SQL learning event: Join us in Stockholm, September 24-27, 2024.
Save €200 with code MSCUST on top of early bird pricing!
Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
For those haters of CALCULATE like @Greg_Deckler, I challenge you to create a measure without CALCULATE that performs anywhere close to the same speed as this very simple measure that switches to an inactive relationship. It must also not break if a simple filter from any of the dimension tables is applied.
Sales Amount (Delivered) =
CALCULATE (
SUM ( Sales[SalesAmount] ),
USERELATIONSHIP ( Sales[DeliveredDateKey], 'Calendar'[DateKey] )
)
Please use the attached file.
Report preview:
As expected, we can see that sales during periods without a discount promotion have products delivered in promotion months.
Solved! Go to Solution.
Hi @AlexisOlson & @Greg_Deckler
This one uses neither CALCULATE nor CALCULATETABLE and performs faster than the original one
Sales Amount (Delivered) 2 =
VAR SelectedSales = ALLSELECTED ( Sales )
VAR SummarySales =
SUMMARIZE (
SelectedSales,
Sales[DeliveredDateKey],
"@SalesAnount", SUM ( Sales[SalesAmount] )
)
RETURN
SUMX (
VALUES ( 'Calendar'[DateKey] ),
VAR FilteredSales = FILTER ( SummarySales, [DeliveredDateKey] = 'Calendar'[DateKey] )
RETURN
SUMX ( FilteredSales, [@SalesAnount] )
)
@AlexisOlson Good challenge! I am a Pro CALCULATE but recommend users not to stick with a single side.
Here are my solutions:
Solution 1 using INNERJOIN, performs in 40ms without any filter
Delivered Amount AS =
VAR Dates =
SELECTCOLUMNS (
VALUES ( 'Calendar'[DateKey] ),
"DeliveredDateKey", 'Calendar'[DateKey] & ""
)
VAR SalesByDelivery =
SELECTCOLUMNS (
SUMMARIZE (
ALLSELECTED ( Sales ),
Sales[DeliveredDateKey],
"Sum", SUM ( Sales[SalesAmount] )
),
"DeliveredDateKey", [DeliveredDateKey] & "",
"Sales", [Sum]
)
VAR Result =
SUMX (
NATURALINNERJOIN ( Dates, SalesByDelivery ),
[Sales]
)
RETURN
Result
Solution 2 using CONTAINSROW or the IN performs in 23 ms
Delivered Amount AS 2 =
VAR SalesByDeliveryDate =
SUMMARIZE (
ALL ( Sales ),
Sales[DeliveredDateKey],
"TotalSales", SUM ( Sales[SalesAmount] )
)
VAR CurrentYearRows =
FILTER (
SalesByDeliveryDate,
CONTAINSROW (
VALUES ( 'Calendar'[DateKey] ),
Sales[DeliveredDateKey]
)
)
VAR Result =
SUMX ( CurrentYearRows, [TotalSales] )
RETURN
Result
Cumulative Total - I added a YearMonth column in the Dates table, since we are not showing date level I decided to reduce granularity, takes about 50ms.
CT DeliveredAmount AS =
VAR SalesByDelivery =
SUMMARIZE (
ALL ( Sales ),
Sales[DeliveredDateKey],
"@TotalSales", SUM ( Sales[SalesAmount] ),
"@YearMonth", YEAR ( Sales[DeliveredDateKey] ) * 100 + MONTH ( Sales[DeliveredDateKey] )
)
VAR Result =
SUMX (
FILTER (
SalesByDelivery,
[@YearMonth] <= MAX ( 'Calendar'[YearMonth] )
),
[@TotalSales]
)
RETURN
Result
@tamerj1 I tried and your code and it returns incorrect subtotals.
Yes I actually placed the solution of the first problem in a separate reply right before the the solution of the 2nd problem.
@tamerj1 Somehow I missed that, the way these forums do threading is mildly infuriating at times.
@AlexisOlson It's a good more or less single use case where CALCULATE is beneficial but really just because USERELATIONSHIP was coded to work with CALCULATE. USERELATIONSHIP could have been coded to support FILTER as well. It's not really CALCULATE, it's the additional functions that were coded to work with CALCULATE. But, there are plenty of examples of the reverse. Try writing a version of these with only using CALCULATE and no X aggregator that A. Actually works and B. Performs significantly faster.
I could go on, I only got through 3 pages of 11 of the Quick Measure Gallery.
The point here is the the No CALCULATE approach is a far better and more flexible approach to writing DAX that allows you to solve real-world problems, problems that CALCULATE could never hope to touch. Yes, there are times when CALCULATE is a good idea for one reason or another. But, this fixation the DAX community has on CALCULATE is unhealthy. It makes DAX harder to learn and breeds this crazy culture where people want to use it everywhere when it is simply making their lives harder and is absolutely unnecessary the vast majority of the time when the simple approach of:
Will solve the VAST majority of problems in DAX without ever needing CALCULATE. Simple. No reason to worry about the internal workings of CALCULATE or context transition or pretty much any of the stuff that people find "hard" about DAX.
@Greg_Deckler X aggregators are absolutely essential. I have no interest in comparing No CALCULATE vs No X aggregator since I'd rather not handicap myself at all.
Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.
Check out the August 2024 Power BI update to learn about new features.
User | Count |
---|---|
21 | |
21 | |
18 | |
16 | |
13 |
User | Count |
---|---|
39 | |
38 | |
23 | |
21 | |
19 |