Microsoft Fabric Community Conference 2025, March 31 - April 2, Las Vegas, Nevada. Use code FABINSIDER for a $400 discount.
Register nowGet inspired! Check out the entries from the Power BI DataViz World Championships preliminary rounds and give kudos to your favorites. View the vizzies.
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.
Solved! Go to Solution.
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 { }
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
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.
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.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code FABINSIDER for a $400 discount!
Check out the February 2025 Power BI update to learn about new features.
User | Count |
---|---|
126 | |
113 | |
69 | |
59 | |
46 |