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

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
JRHans09
Resolver II
Resolver II

Revise budget DAX to include last year

I currently have the below DAX to create a budget for the current year, but when we arrive at Jan in the following year, the budget figures no longer appear when viewing data in the previous year (as the budget is always based on Dates = MAX( Dates[Year] ). I have tried multiple adjustments and I am sure there is an easy solution, but how do I change the DAX below to include last year, as well? OR, maybe better yet, to include budget figures for the last X years so that historic data would always include budgeting figures, as well.

 

 

AnnualBudgets = 
FILTER(
    ADDCOLUMNS(
        FILTER(
            CROSSJOIN(
                DISTINCT( Dates[Month MMM and Year YY] ),
                DISTINCT( Dates[Year] ),
                VALUES( FilterBranch[Branch] ),
                VALUES( FilterSalesRep[SR Full Name] ),
                VALUES( FilterCostCenter[JobType1] )
            ),
            Dates[Year] = MAX( Dates[Year] ) //to always keep current year, but would like to include last year as well, or the last X years
        ),
        "GPBudgetL3Y",
            [GP USD Avg L3Y],
        "GPBudgetL2Y",
            [GP USD Avg L2Y],
        "GPBudgetL1Y",
            [GP USD Avg L1Y]
    ),
    NOT(
        ISBLANK( [GPBudgetL3Y] )
    ) &&
    NOT(
        ISBLANK( [GPBudgetL2Y] )
    ) &&
    NOT(
        ISBLANK( [GPBudgetL1Y] )
    )
)

 

 

 

 How do I adjust the filter to include:
Dates = MAX( Dates[Year] ) and

Dates = MAX( Dates[Year] ) -1

Thanks in advance.

2 ACCEPTED SOLUTIONS
Anonymous
Not applicable

Instead of the "=", did you try the "IN" operator?

 

Try changing this 

Dates[Year] = MAX( Dates[Year]

to

Dates[Year] IN {MAX(Dates[Year]), MAX(Dates[Year])-1}

You could add more values within the curly braces { }

View solution in original post

v-deddai1-msft
Community Support
Community Support

Hi @JRHans09 ,

 

You can use the below dax:

 

 

AnnualBudgets =
FILTER (
    ADDCOLUMNS (
        FILTER (
            CROSSJOIN (
                DISTINCT ( Dates[Month MMM and Year YY] ),
                DISTINCT ( Dates[Year] ),
                VALUES ( FilterBranch[Branch] ),
                VALUES ( FilterSalesRep[SR Full Name] ),
                VALUES ( FilterCostCenter[JobType1] )
            ),
            OR ( Dates[Year] = MAX ( Dates[Year] ), Dates[Year] = MAX ( Dates[Year] ) - 1 )
        ),
        "GPBudgetL3Y", [GP USD Avg L3Y],
        "GPBudgetL2Y", [GP USD Avg L2Y],
        "GPBudgetL1Y", [GP USD Avg L1Y]
    ),
    NOT ( ISBLANK ( [GPBudgetL3Y] ) )
        && NOT ( ISBLANK ( [GPBudgetL2Y] ) ) && NOT ( ISBLANK ( [GPBudgetL1Y] ) )
)

 

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

 

Best Regards,

Dedmon Dai

 

View solution in original post

4 REPLIES 4
v-deddai1-msft
Community Support
Community Support

Hi @JRHans09 ,

 

You can use the below dax:

 

 

AnnualBudgets =
FILTER (
    ADDCOLUMNS (
        FILTER (
            CROSSJOIN (
                DISTINCT ( Dates[Month MMM and Year YY] ),
                DISTINCT ( Dates[Year] ),
                VALUES ( FilterBranch[Branch] ),
                VALUES ( FilterSalesRep[SR Full Name] ),
                VALUES ( FilterCostCenter[JobType1] )
            ),
            OR ( Dates[Year] = MAX ( Dates[Year] ), Dates[Year] = MAX ( Dates[Year] ) - 1 )
        ),
        "GPBudgetL3Y", [GP USD Avg L3Y],
        "GPBudgetL2Y", [GP USD Avg L2Y],
        "GPBudgetL1Y", [GP USD Avg L1Y]
    ),
    NOT ( ISBLANK ( [GPBudgetL3Y] ) )
        && NOT ( ISBLANK ( [GPBudgetL2Y] ) ) && NOT ( ISBLANK ( [GPBudgetL1Y] ) )
)

 

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

 

Best Regards,

Dedmon Dai

 

This works, as well. Thank you. I applied the solution provided by @Anonymous. Thank you both for your help. Simple, elegant solutions.

Anonymous
Not applicable

Instead of the "=", did you try the "IN" operator?

 

Try changing this 

Dates[Year] = MAX( Dates[Year]

to

Dates[Year] IN {MAX(Dates[Year]), MAX(Dates[Year])-1}

You could add more values within the curly braces { }

This works perfectly. Thank you.

Helpful resources

Announcements
LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.

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.