Starting December 3, join live sessions with database experts and the Microsoft product team to learn just how easy it is to get started
Learn moreGet certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now
I have a Year Slicer and a Month Slicer, and I have a Matrix visual.
The requirement is: if I select a Year and Month in the slicers, I need the sum of Amount based on the Category as per the Matrix visual below.
Specifically, I need to show the amount for months less than the selected month.
For example, if I select the month number 5, I need to see the values for months 1, 2, 3, and 4. The remaining months should display zero. In the total row, I need the average of these four months.
The values should be shown for months less than the selected month; the remaining months should display zero.
I don't have a calendar table or anything else; I only have one table which includes both the year and month columns.
EXPECTED OUT PUT
I have uploaded a sample PBIX file for your reference.
I really need your help.
@Anonymous
Solved! Go to Solution.
@Learner27 - This is quite complex with one table, so I have added a disconnected table that takes just the month and year columns. This is created by selecting Modeling >> New Table, you can then add the code below:
Date = DISTINCT(SELECTCOLUMNS( 'CVT table', "month", 'CVT table'[Month], "year", 'CVT table'[Year] ))
You then need to change the slicers to use the columns from the new table.
After this you can create the following measure:
VAR selected_month =
SELECTEDVALUE ( 'Date'[month] )
VAR selected_year =
SELECTEDVALUE ( 'Date'[year] )
VAR calc =
0
+ CALCULATE (
SUM ( 'CVT table'[Amount] ),
KEEPFILTERS ( 'CVT table'[Month] < selected_month
&& 'CVT table'[Year] = selected_year )
)
VAR max_month_with_amount =
CALCULATE (
MAX ( 'CVT table'[Month] ),
'CVT table'[Amount] > 0,
'CVT table'[Month] < selected_month
&& 'CVT table'[Year] = selected_year
)
RETURN
IF (
ISINSCOPE ( 'CVT table'[Month] ),
calc,
DIVIDE ( calc, max_month_with_amount, 0 )
)
You will see from the screenshot below this gives you the result you require. There are some missing 0's but this is because there are no values in your table for these months e.g. Adiministration, 2024, 6 - You could solve this by adding blank amount rows in your source table.
If this solution works for you, please mark as the solution.
@Learner27 - This is quite complex with one table, so I have added a disconnected table that takes just the month and year columns. This is created by selecting Modeling >> New Table, you can then add the code below:
Date = DISTINCT(SELECTCOLUMNS( 'CVT table', "month", 'CVT table'[Month], "year", 'CVT table'[Year] ))
You then need to change the slicers to use the columns from the new table.
After this you can create the following measure:
VAR selected_month =
SELECTEDVALUE ( 'Date'[month] )
VAR selected_year =
SELECTEDVALUE ( 'Date'[year] )
VAR calc =
0
+ CALCULATE (
SUM ( 'CVT table'[Amount] ),
KEEPFILTERS ( 'CVT table'[Month] < selected_month
&& 'CVT table'[Year] = selected_year )
)
VAR max_month_with_amount =
CALCULATE (
MAX ( 'CVT table'[Month] ),
'CVT table'[Amount] > 0,
'CVT table'[Month] < selected_month
&& 'CVT table'[Year] = selected_year
)
RETURN
IF (
ISINSCOPE ( 'CVT table'[Month] ),
calc,
DIVIDE ( calc, max_month_with_amount, 0 )
)
You will see from the screenshot below this gives you the result you require. There are some missing 0's but this is because there are no values in your table for these months e.g. Adiministration, 2024, 6 - You could solve this by adding blank amount rows in your source table.
If this solution works for you, please mark as the solution.
Hi @mark_endicott , Wonder full thankyou so much it is exactly satisfying my requirement I really aperciate you. thank you very much.
Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
User | Count |
---|---|
21 | |
20 | |
19 | |
13 | |
12 |
User | Count |
---|---|
42 | |
28 | |
23 | |
22 | |
22 |