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
DaxNovice
Frequent Visitor

Month to date comparison with previous month line chart

Hi experts

 

I have been trying and failing for a while so thought I would post here.

 

I am trying to compare current month to date with the 2 previous periods.

 

I have:

 

Total MTD = TOTALMTD([Sales],DimDate[Date])
MTD -1 = CALCULATE([Total MTD],DATEADD( DimDate[Date],-1,MONTH))
MTD -2 = CALCULATE([Total MTD],DATEADD(DimDate[Date],-2,MONTH))
 
This works fine in the line chart where the x axis = day as expected.  The issue is, when the current month is a shorter month, it limits all months to the same day (e.g. current month = Feb, lines stop at 28)
 
Is there a way to show either all months carrying on to 31 regardless of month, or each month stopping at their last day (e.g. feb stops 28, May stops 31, June stops 30 etc)
 
Thanks in advance
 
 
1 ACCEPTED SOLUTION
sturlaws
Resident Rockstar
Resident Rockstar

Are you comparing month by month, or are you looking at the whole year?

If you are looking at the whole year, you would have to insert additional days in you time dimension. But in doing so, I am not sure the time intelligence functions, like TOTALMTD, will work. But it is possible to recreate that with other functions.

If you comparing month by month, you can add a table with just 1 to 31 on the rows. And add a day of month-column in your date dimension as sell.  And use this column on the axis, and create the measures like this

Total MTD =
VAR maxday =
    MAX ( dimDate[dayofmonth] )
RETURN
    IF (
        SELECTEDVALUE ( Daysofmonths[dayofmonth] ) <= maxday,
        CALCULATE (
            SUM ( [Sales] ),
            FILTER (
                ALL ( Daysofmonths[dayofmonth] ),
                Daysofmonths[dayofmonth] <= MIN ( Daysofmonths[dayofmonth] )
            )
        ),
        BLANK ()
    )



Total MTD - 1 =
VAR maxday =
    CALCULATE (
        MAX ( dimDate[dayofmonth] ),
        FILTER ( ALL ( dimDate ), dimDate[month] = MIN ( dimDate[month] ) - 1 )
    )
RETURN
    IF (
        MIN ( Daysofmonths[dayofmonth] ) <= maxday,
        CALCULATE (
            SUM ( [Sales] ),
            FILTER ( ALL ( dimDate ), dimDate[month] = MIN ( dimDate[month] ) - 1 ),
            FILTER (
                ALL ( Daysofmonths ),
                Daysofmonths[dayofmonth] <= MIN ( Daysofmonths[dayofmonth] )
            )
        ),
        BLANK ()
    )

View solution in original post

3 REPLIES 3
DaxNovice
Frequent Visitor

I believe I have figured it out now.  Thanks, your solution got me on the way to what I needed.

 

I managed to do it without the need for variables (as I always want the chart to go to 31 even if both months finish before then.

 

Code below for anyone interested and needing the same solution

 

MTD = CALCULATE (TOTALMTD([Sales],DimDate[Date]),
            FILTER (
                ALL (Daysofmonths[dayofmonth] ),
                Daysofmonths[dayofmonth] <= MIN ( Daysofmonths[dayofmonth] )
            ))
MTD -1 = CALCULATE(TOTALMTD([Sales],DATEADD(DimDate[Date],-1,MONTH)),FILTER (
                ALL ( Daysofmonths ),
                Daysofmonths[dayofmonth] <= max ( Daysofmonths[dayofmonth] )))
sturlaws
Resident Rockstar
Resident Rockstar

Are you comparing month by month, or are you looking at the whole year?

If you are looking at the whole year, you would have to insert additional days in you time dimension. But in doing so, I am not sure the time intelligence functions, like TOTALMTD, will work. But it is possible to recreate that with other functions.

If you comparing month by month, you can add a table with just 1 to 31 on the rows. And add a day of month-column in your date dimension as sell.  And use this column on the axis, and create the measures like this

Total MTD =
VAR maxday =
    MAX ( dimDate[dayofmonth] )
RETURN
    IF (
        SELECTEDVALUE ( Daysofmonths[dayofmonth] ) <= maxday,
        CALCULATE (
            SUM ( [Sales] ),
            FILTER (
                ALL ( Daysofmonths[dayofmonth] ),
                Daysofmonths[dayofmonth] <= MIN ( Daysofmonths[dayofmonth] )
            )
        ),
        BLANK ()
    )



Total MTD - 1 =
VAR maxday =
    CALCULATE (
        MAX ( dimDate[dayofmonth] ),
        FILTER ( ALL ( dimDate ), dimDate[month] = MIN ( dimDate[month] ) - 1 )
    )
RETURN
    IF (
        MIN ( Daysofmonths[dayofmonth] ) <= maxday,
        CALCULATE (
            SUM ( [Sales] ),
            FILTER ( ALL ( dimDate ), dimDate[month] = MIN ( dimDate[month] ) - 1 ),
            FILTER (
                ALL ( Daysofmonths ),
                Daysofmonths[dayofmonth] <= MIN ( Daysofmonths[dayofmonth] )
            )
        ),
        BLANK ()
    )

Hi @sturlaws  

 

Thanks for the reply but I still am having the same issue with this.  I.e. if I filter by Feb, the Jan line will also stop at 28 instead of 31.

 

I have attached a link of what I am trying to achieve, would be great if you could have a look

 

Link to dropbox

 

Thanks in advance

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.