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

Prepping for a Fabric certification exam? Join us for a live prep session with exam experts to learn how to pass the exam. Register now.

Reply
Learner27
Helper III
Helper III

Sum of amount of Previous months and remaining months should display zero


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.

Learner27_0-1716450326640.png

 



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

Learner27_0-1716449740841.png

 


I have uploaded a sample PBIX file for your reference.

I really need your help.
@Anonymous 

DVT Report.pbix

1 ACCEPTED SOLUTION
mark_endicott
Super User
Super User

@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. 

 

mark_endicott_0-1716461556574.png

If this solution works for you, please mark as the solution. 

View solution in original post

2 REPLIES 2
mark_endicott
Super User
Super User

@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. 

 

mark_endicott_0-1716461556574.png

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.

Helpful resources

Announcements
PBIApril_Carousel

Power BI Monthly Update - April 2025

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

Notebook Gallery Carousel1

NEW! Community Notebooks Gallery

Explore and share Fabric Notebooks to boost Power BI insights in the new community notebooks gallery.

April2025 Carousel

Fabric Community Update - April 2025

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