March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
Register NowGet certified in Microsoft Fabric—for free! For a limited time, the Microsoft Fabric Community team will be offering free DP-600 exam vouchers. Prepare now
I have three calendar tables: DimDate is the dimension table in the warehouse that brings in dates to the fact tables, Calendar was created so that I could define a "Week Start" value, and YTD/QTD/MTD is for filtering on distinct intervals of time.
I'm trying to create KPI cards that measure the sum of revenue over the selected period (in this case MTD) and then sum of revenue over the same time period but in the previous year. My DAX formula is:
Revenue Prior = CALCULATE([Revenue], SAMEPERIODLASTYEAR('Calendar'[Date]))
When I pull in the Revenue Prior data to a card and filter with Calendar[Date] it works perfectly, but when I throw in YTD/QTD/MTD/WTD[Selection] it gives me a (blank) error. For the selection field I chose "QTD" which should auto filter all the subsequent calendar dates. I'm not sure what the issue could be since all three date tables should be properly connected to each other. Am I missing something obvious?
Solved! Go to Solution.
@Anonymous Sample data would help tremendously. Caution though, when you stray outside the very confined boundaries of time intelligence functions things start to get weird.
Here are some typical date intelligence measures written in the form of Calculation groups (below) These will work with calendar dates or fiscal dates and are much more flexible than default time intelligence functions. You may find this helpful - https://community.powerbi.com/t5/Community-Blog/To-bleep-With-Time-Intelligence/ba-p/1260000
Also, see if my Time Intelligence the Hard Way provides a different way of accomplishing what you are going for.
https://community.powerbi.com/t5/Quick-Measures-Gallery/Time-Intelligence-quot-The-Hard-Way-quot-**bleep**...
YTD
CALCULATE(SELECTEDMEASURE(),
FILTER(ALL('Dates'),
'Dates'[CalendarYear] = MAX('Dates'[CalendarYear]) &&
'Dates'[Date] <= MAX('Dates'[Date])))
MTD
CALCULATE(SELECTEDMEASURE(),
FILTER(ALL('Dates'),
'Dates'[CalendarYear] = MAX('Dates'[CalendarYear]) &&
'Dates'[MonthNumberOfYear] = MAX('Dates'[MonthNumberOfYear])
&& 'Dates'[Date] <= MAX('Dates'[Date])))
QTD
CALCULATE(SELECTEDMEASURE(),
FILTER(ALL('Dates'),
'Dates'[CalendarYear] = MAX('Dates'[CalendarYear]) &&
'Dates'[CalendarQuarter] = MAX('Dates'[CalendarQuarter]) &&
'Dates'[Date] <= MAX('Dates'[Date])))
PY
VAR __MaxDate = MAX('Dates'[Date])
VAR __MinDate = MIN('Dates'[Date])
RETURN
CALCULATE(SELECTEDMEASURE(),
FILTER(ALL('Dates'),
'Dates'[Date] >=
DATE(YEAR(__MinDate)-1,MONTH(__MinDate),DAY(__MinDate)) &&
'Dates'[Date] <=
DATE(YEAR(__MaxDate)-1,MONTH(__MaxDate),DAY(__MaxDate))))
PY YTD
VAR __MaxDate = MAX('Dates'[Date])
RETURN
CALCULATE(SELECTEDMEASURE(),
FILTER(ALL('Dates'),
'Dates'[CalendarYear] =
MAX('Order Dates'[CalendarYear])-1 &&
'Dates'[Date] <=
DATE(
YEAR(__MaxDate)-1,
MONTH(__MaxDate),
DAY(__MaxDate))))
YOY
SELECTEDMEASURE()
- CALCULATE(SELECTEDMEASURE(),'Date Intelligence Group'[Name] = "PY")
YOY %
DIVIDE(
CALCULATE(SELECTEDMEASURE(),'Date Intelligence Group'[Name] ="YOY"),
CALCULATE(SELECTEDMEASURE(),'Date Intelligence Group'[Name] ="PY"))
Equivalent measures using DAX Time Intelligence functions are the following:
Hi @Anonymous
"When I pull in the Revenue Prior data to a card and filter with Calendar[Date] it works perfectly, but when I throw in YTD/QTD/MTD/WTD[Selection] it gives me a (blank) error."
Well, the above behavior is obvious when you know how time-intel calcs and proper calendars work in PBI :)) By filtering the left-most table you are also placing filters (through filter injection, not through table expansion, which is important to understand) implicitly on Calendar. When you then use the time-intel functions they operate only on the Calendar table and can't reach the other table that still filters Calendar. Hence, the intersection of what the function does and the filters coming from the other table ends in an empty set and thus your blanks.
My question would be this: Why do you join the "YTD/..." table to Calendar? To my mind, it should be a disconnected table. If that were the case, you wouldn't have this problem at all. You'd only need to code the measures correctly in such a model (maybe using calculation groups to stop the proliferation of measures).
I was under the impression that the "YTD/..." table would have to be connected to Calendar or else it won't work. If I wanted to see month-to-date values and I select "MTD" without the connection to Calendar nothing happens.
@Anonymous Sample data would help tremendously. Caution though, when you stray outside the very confined boundaries of time intelligence functions things start to get weird.
Here are some typical date intelligence measures written in the form of Calculation groups (below) These will work with calendar dates or fiscal dates and are much more flexible than default time intelligence functions. You may find this helpful - https://community.powerbi.com/t5/Community-Blog/To-bleep-With-Time-Intelligence/ba-p/1260000
Also, see if my Time Intelligence the Hard Way provides a different way of accomplishing what you are going for.
https://community.powerbi.com/t5/Quick-Measures-Gallery/Time-Intelligence-quot-The-Hard-Way-quot-**bleep**...
YTD
CALCULATE(SELECTEDMEASURE(),
FILTER(ALL('Dates'),
'Dates'[CalendarYear] = MAX('Dates'[CalendarYear]) &&
'Dates'[Date] <= MAX('Dates'[Date])))
MTD
CALCULATE(SELECTEDMEASURE(),
FILTER(ALL('Dates'),
'Dates'[CalendarYear] = MAX('Dates'[CalendarYear]) &&
'Dates'[MonthNumberOfYear] = MAX('Dates'[MonthNumberOfYear])
&& 'Dates'[Date] <= MAX('Dates'[Date])))
QTD
CALCULATE(SELECTEDMEASURE(),
FILTER(ALL('Dates'),
'Dates'[CalendarYear] = MAX('Dates'[CalendarYear]) &&
'Dates'[CalendarQuarter] = MAX('Dates'[CalendarQuarter]) &&
'Dates'[Date] <= MAX('Dates'[Date])))
PY
VAR __MaxDate = MAX('Dates'[Date])
VAR __MinDate = MIN('Dates'[Date])
RETURN
CALCULATE(SELECTEDMEASURE(),
FILTER(ALL('Dates'),
'Dates'[Date] >=
DATE(YEAR(__MinDate)-1,MONTH(__MinDate),DAY(__MinDate)) &&
'Dates'[Date] <=
DATE(YEAR(__MaxDate)-1,MONTH(__MaxDate),DAY(__MaxDate))))
PY YTD
VAR __MaxDate = MAX('Dates'[Date])
RETURN
CALCULATE(SELECTEDMEASURE(),
FILTER(ALL('Dates'),
'Dates'[CalendarYear] =
MAX('Order Dates'[CalendarYear])-1 &&
'Dates'[Date] <=
DATE(
YEAR(__MaxDate)-1,
MONTH(__MaxDate),
DAY(__MaxDate))))
YOY
SELECTEDMEASURE()
- CALCULATE(SELECTEDMEASURE(),'Date Intelligence Group'[Name] = "PY")
YOY %
DIVIDE(
CALCULATE(SELECTEDMEASURE(),'Date Intelligence Group'[Name] ="YOY"),
CALCULATE(SELECTEDMEASURE(),'Date Intelligence Group'[Name] ="PY"))
Equivalent measures using DAX Time Intelligence functions are the following:
This is great stuff. Thanks for sharing! I'll dive more into these measures to see if I can make them work. If not I'll get some sample data together to share.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
Check out the November 2024 Power BI update to learn about new features.
User | Count |
---|---|
116 | |
83 | |
77 | |
66 | |
57 |
User | Count |
---|---|
132 | |
113 | |
98 | |
78 | |
78 |