cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
tjalleph
Frequent Visitor

Dynamic filtering in measure with a variable

Hi all,

 

I'm hoping you can shed some light on a behavior in measures that I can't seem to understand. 

 

Context

I'm trying to visualize budget, sales forecast and actuals on a monthly basis. From the selected months in a slicer (say Jan-March), I'd like to show budget and sales forecast for the next three months (Apr, May, Jun) as well. The three numbers are in different tables and are connected through a Calender table.

In table-form, the result should be:

MonthBudgetForecastActuals
Jan100120110
Feb120110100
Mar120123128
Apr120133 
May120105 
Jun12098 

 

However, if I try to dynamically find the last month number of actuals and add 3, and use that calculate forecast and actuals, i only get a resulting table for the months 1-3.

MonthBudgetForecastActuals
Jan100120110
Feb120110100
Mar120123128

 

I guess the slicer is the issue here, how can I circumvent this?

Thanks for the help!

 

Tjalle

1 ACCEPTED SOLUTION
v-robertq-msft
Community Support
Community Support

Hi, @tjalleph 

According to your description, I can roughly understand your requirement, then I created a data model to make a test based on your sample data, you can try my steps:

  1. Create a calculated table for the slicer, which is the same as the calendar table:
Slicer = 'Calendar'

Then keep the table don’t have any relationship with others:

v-robertq-msft_0-1619765125441.png

 

  1. Create three measures in the table:
Budget =

var _minmonth=MINX(ALLSELECTED(Slicer),[Month number])

var _maxmonth=MAXX(ALLSELECTED(Slicer),[Month number])

return

IF(MAX('Calendar'[Month number])>=_minmonth&&MAX('Calendar'[Month number])<=_maxmonth+3,SUM(Budget[Budget]),BLANK())
Forecast =

var _minmonth=MINX(ALLSELECTED(Slicer),[Month number])

var _maxmonth=MAXX(ALLSELECTED(Slicer),[Month number])

return

IF(MAX('Calendar'[Month number])>=_minmonth&&MAX('Calendar'[Month number])<=_maxmonth+3,SUM(Forecast[Forecast]),BLANK())
Actuals =

IF(MAX('Calendar'[Month]) in SELECTCOLUMNS('Slicer',"1",[Month]),SUM(Actuals[Actuals]),BLANK())

Then create a slicer and a table chart to place them like this:

v-robertq-msft_1-1619765125447.png

v-robertq-msft_2-1619765125452.png

 

And you can get what you want.

 

You can download my test pbix file below

Thank you very much!

 

Best Regards,

Community Support Team _Robert Qin

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

3 REPLIES 3
tjalleph
Frequent Visitor

Thanks!
That works like a charm.

v-robertq-msft
Community Support
Community Support

Hi, @tjalleph 

According to your description, I can roughly understand your requirement, then I created a data model to make a test based on your sample data, you can try my steps:

  1. Create a calculated table for the slicer, which is the same as the calendar table:
Slicer = 'Calendar'

Then keep the table don’t have any relationship with others:

v-robertq-msft_0-1619765125441.png

 

  1. Create three measures in the table:
Budget =

var _minmonth=MINX(ALLSELECTED(Slicer),[Month number])

var _maxmonth=MAXX(ALLSELECTED(Slicer),[Month number])

return

IF(MAX('Calendar'[Month number])>=_minmonth&&MAX('Calendar'[Month number])<=_maxmonth+3,SUM(Budget[Budget]),BLANK())
Forecast =

var _minmonth=MINX(ALLSELECTED(Slicer),[Month number])

var _maxmonth=MAXX(ALLSELECTED(Slicer),[Month number])

return

IF(MAX('Calendar'[Month number])>=_minmonth&&MAX('Calendar'[Month number])<=_maxmonth+3,SUM(Forecast[Forecast]),BLANK())
Actuals =

IF(MAX('Calendar'[Month]) in SELECTCOLUMNS('Slicer',"1",[Month]),SUM(Actuals[Actuals]),BLANK())

Then create a slicer and a table chart to place them like this:

v-robertq-msft_1-1619765125447.png

v-robertq-msft_2-1619765125452.png

 

And you can get what you want.

 

You can download my test pbix file below

Thank you very much!

 

Best Regards,

Community Support Team _Robert Qin

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

amitchandak
Super User
Super User

@tjalleph , if you select a small duration and you want to show a larger duration you need to have an independent date table.

 

refer my video on same 

Need of an Independent Date Table:https://www.youtube.com/watch?v=44fGGmg9fHI

Did I answer your question? Mark my post as a solution! Appreciate your Kudos!! !!
Dashboard of My Blogs !! Connect on Linkedin
Want To Learn Power BI
Learn Power BI Beginners !! Advance Power BI Concepts !! Power BI For Tableau User !! Learn Power BI in Hindi !!
Proud to be a Super User!

Helpful resources

Announcements
Power BI December 2021 Update_carousel 768x460.jpg

Check it Out!

Click here to read more about the December 2021 Updates!

User Group Leader Meeting January 768x460.png

Calling all User Group Leaders!

Don't miss the User Group Leader meetings on January, 24th & 25th, 2022.

Jan 2022 Dev Camp 768x460 copy.png

Power BI Dev Camp- January 27th, 2022

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

Top Solution Authors
Top Kudoed Authors