cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
inna_sysco
Helper II
Helper II

DAX to calculate prev month sum and display that value for current month

Hi Dax masters!

Could someone help me to solve a case that I have in my report:
for a particular row in the matrix ("Opening") in the cell for the current month, I need to display the previous month's value. All others rows - current month's value but with some 'filters'
I have a draft of the measure, but it doesn't work...

 

 

Result = 
VAR start_date =
    CALCULATE ( MIN ( Calendar_start[Date] ), ALLSELECTED ( Calendar_start[Date] ) )
VAR end_date =
    CALCULATE ( MAX ( Calendar_end[Date] ), ALLSELECTED ( Calendar_end[Date] ) )
VAR currentdate =
    SELECTEDVALUE ( 'TABLE'[DAYTIME] )
VAR previousdate =
    EDATE ( currentdate, -1 )

var act_value = CALCULATE ( SUM ( 'TABLE'[VALUE] ), 'TABLE'[ITEM] = "ACTUAL",  'TABLE'[DAYTIME] >= start_date  && 'TABLE'[DAYTIME] <= end_date)
var prod_value = CALCULATE ( SUM ( 'TABLE'[VALUE] ), 'TABLE'[ITEM] = "PROD",  'TABLE'[DAYTIME] >= start_date  && 'TABLE'[DAYTIME] <= end_date)

RETURN   

SWITCH(TRUE(),
    SELECTEDVALUE(CONFIG[CHART_SECTION]) = "Opening", CALCULATE ( SUM ( 'TABLE'[VALUE] ), 'TABLE'[DAYTIME] = previousdate, 'TABLE'[ITEM] = "PROD"),
    SELECTEDVALUE(CONFIG[CHART_SECTION]) = "Lifted", act_value,
    SELECTEDVALUE(CONFIG[CHART_SECTION]) = "Production", prod_value,
    SELECTEDVALUE(CONFIG[CHART_SECTION]) = "Closing", prod_value,
    SELECTEDVALUE(CONFIG[CHART_SECTION]) = "Adjustment", prod_value,
    BLANK())

 

 

There are 3 calendar tables in my report :
"Calendar_start", "Calendar_end" tables for the custom date range
and Calendar_table that includes DISTINCT dates from the "main table" (the main table has to be in Direct Query mode so I can't add new columns in it and that's why I need this additional table) and some custom date formats columns.

My matrix looks like this:
image.png

 

I assume that the mechanic for the measure should be like this: measure looks for value in the CONFIG table for a particular row, calculates the sum of this value from the main table (but where month is the "previous month"), and displays the calculated value in the column for the current month...

Please check my sample file for more details.

I really appreciate any help and ideas!
 

Thanks in advance!

Inna

1 ACCEPTED SOLUTION

Hi @inna_sysco ,

 

Try the following formula:

 

Result = 
VAR start_date =
    CALCULATE ( MIN ( Calendar_start[Date] ), ALLSELECTED ( Calendar_start[Date] ) )
VAR end_date =
    CALCULATE ( MAX ( Calendar_end[Date] ), ALLSELECTED ( Calendar_end[Date] ) )
VAR currentdate =
    SELECTEDVALUE ( 'Calendar_table'[DAYTIME] )

var act_value = CALCULATE ( SUM ( 'TABLE'[VALUE] ), 'TABLE'[ITEM] = "ACTUAL",  'TABLE'[DAYTIME] >= start_date  && 'TABLE'[DAYTIME] <= end_date)
var prod_value = CALCULATE ( SUM ( 'TABLE'[VALUE] ), 'TABLE'[ITEM] = "PROD",  'TABLE'[DAYTIME] >= start_date  && 'TABLE'[DAYTIME] <= end_date)
var prev = CALCULATE ( SUM ( 'TABLE'[VALUE] ), ALLSELECTED(Calendar_table[DAYTIME]), FILTER( ALL('TABLE'), 'TABLE'[DAYTIME] <= EOMONTH ( currentdate, -1 ) && 'TABLE'[DAYTIME] > EOMONTH(currentdate,-2)), 'TABLE'[ITEM] = "PROD")

RETURN   

SWITCH(TRUE(),
    SELECTEDVALUE(CONFIG[CHART_SECTION]) = "Opening", IF( MAX(Calendar_table[DAYTIME]) <= end_date && MAX(Calendar_table[DAYTIME]) >= start_date, prev ),
    SELECTEDVALUE(CONFIG[CHART_SECTION]) = "Lifted", act_value,
    SELECTEDVALUE(CONFIG[CHART_SECTION]) = "Production", prod_value,
    SELECTEDVALUE(CONFIG[CHART_SECTION]) = "Closing", prod_value,
    SELECTEDVALUE(CONFIG[CHART_SECTION]) = "Adjustment", prod_value,
    BLANK())

image.png

 

 

If the problem is still not resolved, please provide detailed error information or the expected result you expect. Let me know immediately, looking forward to your reply.

Best Regards,
Winniz

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

6 REPLIES 6
amitchandak
Super User IV
Super User IV

@inna_sysco ,I am not clear on expected output. Why are you suing the second date slicer?

 

You already have month year on column.

 

If need MOM with one date table

MTD Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESMTD('Date'[Date]))
last MTD Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESMTD(dateadd('Date'[Date],-1,MONTH)))

diff = [MTD Sales]-[last MTD Sales]
diff % = divide([MTD Sales]-[last MTD Sales],[last MTD Sales])

 

 

If you need to compare two period of choice from slicers you can refer

How to use two Date/Period slicers :https://www.youtube.com/watch?v=WSeZr_-MiTg



Did I answer your question? Mark my post as a solution! Appreciate your Kudos!!
Dashboard of My Blogs !! YouTube Channel !! Connect on Linkedin

Proud to be a Super User!

Hi @amitchandak , thanks for the reply!
What do you mean by "the second date slicer"? 
For the report, I need the default dates to range in slicers from "6 months ago" to the"previous month". It's the user's requirement.
And default "between " Power BI slicer is not working in this case
As you can see on the picture that I attached - values for the row OPENING are missing, but this row should include SUM of values for the previous month.

Hi @inna_sysco ,

 

Try the following formula:

 

Result = 
VAR start_date =
    CALCULATE ( MIN ( Calendar_start[Date] ), ALLSELECTED ( Calendar_start[Date] ) )
VAR end_date =
    CALCULATE ( MAX ( Calendar_end[Date] ), ALLSELECTED ( Calendar_end[Date] ) )
VAR currentdate =
    SELECTEDVALUE ( 'Calendar_table'[DAYTIME] )

var act_value = CALCULATE ( SUM ( 'TABLE'[VALUE] ), 'TABLE'[ITEM] = "ACTUAL",  'TABLE'[DAYTIME] >= start_date  && 'TABLE'[DAYTIME] <= end_date)
var prod_value = CALCULATE ( SUM ( 'TABLE'[VALUE] ), 'TABLE'[ITEM] = "PROD",  'TABLE'[DAYTIME] >= start_date  && 'TABLE'[DAYTIME] <= end_date)

RETURN   

SWITCH(TRUE(),
    SELECTEDVALUE(CONFIG[CHART_SECTION]) = "Opening", CALCULATE ( SUM ( 'TABLE'[VALUE] ), ALLSELECTED(Calendar_table[DAYTIME]), FILTER( ALL('TABLE'), 'TABLE'[DAYTIME] <= EOMONTH ( currentdate, -1 ) && 'TABLE'[DAYTIME] > EOMONTH(currentdate,-2)), 'TABLE'[ITEM] = "PROD"),
    SELECTEDVALUE(CONFIG[CHART_SECTION]) = "Lifted", act_value,
    SELECTEDVALUE(CONFIG[CHART_SECTION]) = "Production", prod_value,
    SELECTEDVALUE(CONFIG[CHART_SECTION]) = "Closing", prod_value,
    SELECTEDVALUE(CONFIG[CHART_SECTION]) = "Adjustment", prod_value,
    BLANK())

vkkfmsft_0-1627284248733.png

 

If the problem is still not resolved, please provide detailed error information or the expected result you expect. Let me know immediately, looking forward to your reply.

Best Regards,
Winniz

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Hi @v-kkf-msft !
Thanks a lot for your reply!
Your measure works almost perfectly, but it causes one additional issue.
Now the row "OPENING" displays December's value - in the column for January, January's value - in the column for February. It's PERFECT!
image.png
BUT at the same time, I need to control the range of dates by 2 custom slicers: "from date" and "to date".
And as you can see on the screenshot below with the new measure I can't do it, because It displays all values and ignores dates filters...
For example, there is no data for April 2021 and the date slicers are limited by April 2021 and it means, that table has to be empty, but we see this...
image.png

Maybe you know how to fix this?
Really appreciate your help!
Best regards, Inna

PS. I've changed the example dataset, you can find it here.

Hi @inna_sysco ,

 

Try the following formula:

 

Result = 
VAR start_date =
    CALCULATE ( MIN ( Calendar_start[Date] ), ALLSELECTED ( Calendar_start[Date] ) )
VAR end_date =
    CALCULATE ( MAX ( Calendar_end[Date] ), ALLSELECTED ( Calendar_end[Date] ) )
VAR currentdate =
    SELECTEDVALUE ( 'Calendar_table'[DAYTIME] )

var act_value = CALCULATE ( SUM ( 'TABLE'[VALUE] ), 'TABLE'[ITEM] = "ACTUAL",  'TABLE'[DAYTIME] >= start_date  && 'TABLE'[DAYTIME] <= end_date)
var prod_value = CALCULATE ( SUM ( 'TABLE'[VALUE] ), 'TABLE'[ITEM] = "PROD",  'TABLE'[DAYTIME] >= start_date  && 'TABLE'[DAYTIME] <= end_date)
var prev = CALCULATE ( SUM ( 'TABLE'[VALUE] ), ALLSELECTED(Calendar_table[DAYTIME]), FILTER( ALL('TABLE'), 'TABLE'[DAYTIME] <= EOMONTH ( currentdate, -1 ) && 'TABLE'[DAYTIME] > EOMONTH(currentdate,-2)), 'TABLE'[ITEM] = "PROD")

RETURN   

SWITCH(TRUE(),
    SELECTEDVALUE(CONFIG[CHART_SECTION]) = "Opening", IF( MAX(Calendar_table[DAYTIME]) <= end_date && MAX(Calendar_table[DAYTIME]) >= start_date, prev ),
    SELECTEDVALUE(CONFIG[CHART_SECTION]) = "Lifted", act_value,
    SELECTEDVALUE(CONFIG[CHART_SECTION]) = "Production", prod_value,
    SELECTEDVALUE(CONFIG[CHART_SECTION]) = "Closing", prod_value,
    SELECTEDVALUE(CONFIG[CHART_SECTION]) = "Adjustment", prod_value,
    BLANK())

image.png

 

 

If the problem is still not resolved, please provide detailed error information or the expected result you expect. Let me know immediately, looking forward to your reply.

Best Regards,
Winniz

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

Hi @v-kkf-msft!

Thanks a lot for help! Your solution is definitely what I was looking for! 

Helpful resources

Announcements
PBI_User Group Leader_768x460.jpg

Manage your user group events

Check out the News & Announcements to learn more.

Get Ready for Power BI Dev Camp

Microsoft named a Leader in The Forrester Wave

Microsoft received the highest score of any vendor in both the strategy and current offering categories.

Get Ready for Power BI Dev Camp

Power BI Dev Camp - September 30th, 2021

Mark your calendars and join us for our next Power BI Dev Camp!

PowerPlatform 768x460.png

Microsoft Learn

Check out our new Discover Your Career Path blog post series and get all the details.

Top Solution Authors