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
Hi
I have two tables: Calendar and Values
The Calendar has date and year-month field, something like:
Date | Year-Month
01-01-2019 | 2019-01
25-02-2019 | 2019-02
...
And the values table has the values for each day:
Date | Value
01-01-2019 | 19233
31-01-2019 | 16000
25-02-2019 | 18000
...
I need to create an expression in DAX to get the last value for each year-month in a graph that has the year-month dimension as axis.
How can I achieve this?
Thanks!
Solved! Go to Solution.
Hi @Anonymous
First of all, you should make sure you Calendar table contains contiguous dates (wasn't quite sure from the sample you posted).
Then with your Value table related to you Calendar table on the Date column, here are a few ways you could write the measure depending on the exact requirements:
First define
Value Sum =
SUM ( 'Value'[Value] )
Measure 1: Return Value sum on the last date of whatever date range is selected:
Value on last date of selected period =
CALCULATE (
[Value Sum],
LASTDATE ( 'Calendar'[Date] )
)
Measure 2: Return Value sum on the last date of whatever date range is selected for which the sum is nonblank:
Value on last date of selected period containing data in Value table =
LASTNONBLANKVALUE ( 'Calendar'[Date], [Value Sum] )
Measure 3: Return Value sum on the last date of the month of the max date selected (could be outside the filtered date range):
Value on last day of month of max selected date =
CALCULATE (
[Value Sum],
ENDOFMONTH ( 'Calendar'[Date] )
)
Regards,
Owen
You may also try this: On you calendar table, create a new Column called myEOM
Hi @Anonymous
First of all, you should make sure you Calendar table contains contiguous dates (wasn't quite sure from the sample you posted).
Then with your Value table related to you Calendar table on the Date column, here are a few ways you could write the measure depending on the exact requirements:
First define
Value Sum =
SUM ( 'Value'[Value] )
Measure 1: Return Value sum on the last date of whatever date range is selected:
Value on last date of selected period =
CALCULATE (
[Value Sum],
LASTDATE ( 'Calendar'[Date] )
)
Measure 2: Return Value sum on the last date of whatever date range is selected for which the sum is nonblank:
Value on last date of selected period containing data in Value table =
LASTNONBLANKVALUE ( 'Calendar'[Date], [Value Sum] )
Measure 3: Return Value sum on the last date of the month of the max date selected (could be outside the filtered date range):
Value on last day of month of max selected date =
CALCULATE (
[Value Sum],
ENDOFMONTH ( 'Calendar'[Date] )
)
Regards,
Owen
Hi @Anonymous
try a measure
Measure =
var _lastMonthDay = calculate(MAX(Table2[Date]);FILTER(ALL('Table2');YEAR('Table2'[Date])=YEAR(SELECTEDVALUE(Table1[Date])) && MONTH('Table2'[Date])=MONTH(SELECTEDVALUE(Table1[Date]))))
RETURN
CALCULATE(LASTNONBLANK(Table2[Value];1);Table2[Date]=_lastMonthDay)
do not hesitate to give a kudo to useful posts and mark solutions as solution
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 |
---|---|
110 | |
79 | |
71 | |
48 | |
41 |
User | Count |
---|---|
138 | |
108 | |
71 | |
64 | |
58 |