The ultimate Microsoft Fabric, Power BI, Azure AI, and SQL learning event: Join us in Stockholm, September 24-27, 2024.
Save €200 with code MSCUST on top of early bird pricing!
Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
Hello! I am needing a DAX formula that will calculate the percentage of goal attained for any given day within a period. For example, if we are 65% through the period and our goal for the period is 15M and we are currently at 10M in sales, how do I calculate the percentage of goal attained for that 65% of the period. At 10M in sales have we achieved 100% in relation to our overall goal of 15M being 65% through the period?
Thank you!
Solved! Go to Solution.
Hi:
Usually you will have a forecast or goal table.(phyiscal or virtual) It also depends on the grain of your forecast. Do you have an annual number that needs to be spread over each day, or perhaps a month goal and you would then spilt that up over the days in each month you are forecasting for.
Assumingyour sales comes in by day in a different table you can do a simple sum of sales and a sum of forecast and working in conjunction with a date table, the to date comparisons are not hard to do.
If you have a table with each month and a total budget for each month, as a separate table e.g.
Month Forecast Amt
Jan 200
Feb 300
etc.
You can use this allocation DAX to break your monthly forecasts into daily amounts. Then you just sum then or do a YTD for both actual values vs. budgeted vales.
Here is a way to allocate a monthly budget to each day. *Note. You have a separate Dates table with all the dates, marked as a date table and connected to your fact table with sales in it. Dates[Date] (one side) is usually connected in a relationship to SalesTable[OrderDate] (many side) as one example.
Here's one allocation measure for spreading out the monthly budget. I hope this helps!
Budget Allocated =
SUMX (
-- Summarize Dates by Year/Month & Days in Month
SUMMARIZE (
Dates,
Dates[Year Month],
Dates[Days In Month]
),
-- For each Year/Month get # days in current filter context for that Year/Month
VAR DayCount =
CALCULATE ( COUNTROWS ( Dates ) )
-- Budget value for the entire month
VAR BudgetValueMonth =
CALCULATE (
SUM ( Budget[Budget Value] ),
ALLEXCEPT ( Dates, Dates[Year Month] )
)
-- Budget value allocated to required number of days (DayCount)
VAR BudgetValueAllocated =
BudgetValueMonth * DayCount / Dates[Days In Month]
RETURN
BudgetValueAllocated
)
Hi:
To answer your question on % of goal.
1. Total Sales = SUM(SalesTable[Sales Amt])
2. Total Budget = SUM(Budget[Budget Amt])
3. % of Goal = DIVIDE([Total Sales], [Total Budget]) Foramt as %.
Hi:
Usually you will have a forecast or goal table.(phyiscal or virtual) It also depends on the grain of your forecast. Do you have an annual number that needs to be spread over each day, or perhaps a month goal and you would then spilt that up over the days in each month you are forecasting for.
Assumingyour sales comes in by day in a different table you can do a simple sum of sales and a sum of forecast and working in conjunction with a date table, the to date comparisons are not hard to do.
If you have a table with each month and a total budget for each month, as a separate table e.g.
Month Forecast Amt
Jan 200
Feb 300
etc.
You can use this allocation DAX to break your monthly forecasts into daily amounts. Then you just sum then or do a YTD for both actual values vs. budgeted vales.
Here is a way to allocate a monthly budget to each day. *Note. You have a separate Dates table with all the dates, marked as a date table and connected to your fact table with sales in it. Dates[Date] (one side) is usually connected in a relationship to SalesTable[OrderDate] (many side) as one example.
Here's one allocation measure for spreading out the monthly budget. I hope this helps!
Budget Allocated =
SUMX (
-- Summarize Dates by Year/Month & Days in Month
SUMMARIZE (
Dates,
Dates[Year Month],
Dates[Days In Month]
),
-- For each Year/Month get # days in current filter context for that Year/Month
VAR DayCount =
CALCULATE ( COUNTROWS ( Dates ) )
-- Budget value for the entire month
VAR BudgetValueMonth =
CALCULATE (
SUM ( Budget[Budget Value] ),
ALLEXCEPT ( Dates, Dates[Year Month] )
)
-- Budget value allocated to required number of days (DayCount)
VAR BudgetValueAllocated =
BudgetValueMonth * DayCount / Dates[Days In Month]
RETURN
BudgetValueAllocated
)
Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.
Check out the August 2024 Power BI update to learn about new features.
User | Count |
---|---|
18 | |
18 | |
17 | |
15 | |
11 |
User | Count |
---|---|
35 | |
34 | |
19 | |
19 | |
14 |