Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Anonymous
Not applicable

Get the value from last day of month

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!

 

 

 

 

1 ACCEPTED SOLUTION
OwenAuger
Super User
Super User

Hi @Anonymous 

 

Sample pbix here

 

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

 

 


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

View solution in original post

3 REPLIES 3
jo_at_price
Advocate II
Advocate II

You may also try this: On you calendar table, create a new Column called myEOM

myEOM = if(Calendar[Date] = EOMONTH(Calendar[Date],0),Calendar[Date],blank() )
In other words, is this is the last day of the month, return date, otherwise, return Blank() an empty value (not zero, more like NULL). Then reference that column on your report, it should show only values for the end of that month (as long as you have the month's full info, won;t show anyhthing MOnth To Date)
OwenAuger
Super User
Super User

Hi @Anonymous 

 

Sample pbix here

 

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

 

 


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn
az38
Community Champion
Community Champion

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

LinkedIn


do not hesitate to give a kudo to useful posts and mark solutions as solution
LinkedIn

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.