The ultimate Fabric, Power BI, SQL, and AI community-led learning event. Save €200 with code FABCOMM.
Get registeredCompete to become Power BI Data Viz World Champion! First round ends August 18th. Get started.
So I'm trying to get a total for salesreps quotas for the current quarter, including dates that havent happened yet so I can create a daily quota requirement and then a QTD quota based on the daily quota for sales reps to see how they are pacing during the quarter.
The formula I've been trying and playing around with is: CALCULATE([Sum of RSM Quotas], 'Quotas Unrelated'[Is this Qtr] = "TRUE") But it keeps giving me the full year total.
Or this formula ends up giving me the month's total so I'm assuming its trying to do QTD with only one date. CALCULATE(SUM('Quotas RSM'[Quota]), 'Combined Table'[Current Quarter] = TRUE())
In my tables, I have the sales reps quotas for each month with 1 date attached. I also have a date table with a relationship to the quota table.
Heres a super simplified example of my quota data.
Quota | Date | Sales rep |
52000 | 7/1/2025 | rep 1 |
98000 | 7/1/2025 | rep 2 |
33000 | 7/1/2025 | rep 3 |
56000 | 8/1/2025 | rep1 |
91000 | 8/1/2025 | rep 2 |
34000 | 8/1/2025 | rep 3 |
54000 | 9/1/2025 | rep1 |
93000 | 9/1/2025 | rep 2 |
32000 | 9/1/2025 | rep 3 |
Solved! Go to Solution.
Hi @CiaraCaryl ,
The issue you're encountering is a common one in DAX and relates to filter context. When you place a measure in a visual that has a date context (like a table row for July), the calculation is filtered to only include data from that month. To get the total for the entire quarter, you need a formula that can ignore the monthly filter from the visual and apply its own filter for the whole quarter.
The correct DAX measure to calculate the total quota for the entire current quarter is:
Full Quarter Quota =
CALCULATE (
SUM ( 'Quotas RSM'[Quota] ),
FILTER (
ALL ( 'Date Table' ),
'Date Table'[Year] = YEAR ( TODAY () )
&& 'Date Table'[Quarter of Year] = QUARTER ( TODAY () )
)
)
This formula works by first using SUM to specify the aggregation of the quota column. The CALCULATE function then modifies the environment in which this sum is performed. The key is the ALL('Date Table') function, which removes any pre-existing filters from the Date Table, such as the filter for a specific month coming from your visual. After clearing the filters, the FILTER function applies a new context, keeping only the rows from your Date Table where the year and quarter match the current date. For today, July 20, 2025, it will find the total for Quarter 3 of 2025.
For this formula to work, your Date Table must have columns for the year and the quarter. If it doesn't, you can add them as calculated columns with these simple expressions: Year = YEAR('Date Table'[Date]) and Quarter of Year = QUARTER('Date Table'[Date]).
With the Full Quarter Quota measure created, you can now proceed to calculate the daily and pacing metrics you need. To find the daily quota requirement, you divide the full quarter's quota by the number of days in that quarter.
Daily Quota =
VAR CurrentQuarter = QUARTER(TODAY())
VAR CurrentYear = YEAR(TODAY())
VAR DaysInQuarter =
COUNTROWS(
FILTER(
ALL('Date Table'),
'Date Table'[Quarter of Year] = CurrentQuarter && 'Date Table'[Year] = CurrentYear
)
)
RETURN
DIVIDE([Full Quarter Quota], DaysInQuarter)
Finally, to see how a sales rep is pacing against their goal, you can create a measure that shows what their quota attainment should be as of today. This is done by multiplying the daily quota requirement by the number of days that have already passed in the quarter.
QTD Pacing Quota =
VAR DaysPassed =
COUNTROWS(
DATESQTD('Date Table'[Date])
)
RETURN
[Daily Quota] * DaysPassed
Best regards,
Hi @CiaraCaryl ,
Thank you for reaching out to the Microsoft Community Forum.
Please follow below stesps.
1. Created Table "Quota" with sample data based on your data. and created " Date" calculated table, please refer snap.
2. Created Calculated column "QuotaQuarterKey" in "Qota" table with below code.
I hope this information helps. Please do let us know if you have any further queries.
Regards,
Dinesh
Hi @CiaraCaryl ,
Thank you for reaching out to the Microsoft Community Forum.
Please follow below stesps.
1. Created Table "Quota" with sample data based on your data. and created " Date" calculated table, please refer snap.
2. Created Calculated column "QuotaQuarterKey" in "Qota" table with below code.
I hope this information helps. Please do let us know if you have any further queries.
Regards,
Dinesh
Hi @CiaraCaryl ,
We haven’t heard from you on the last response and was just checking back to see if you have a resolution yet. And, if you have any further query do let us know.
Regards,
Dinesh
Hi @CiaraCaryl ,
We haven’t heard from you on the last response and was just checking back to see if you have a resolution yet. And, if you have any further query do let us know.
Regards,
Dinesh
Hi @CiaraCaryl ,
We haven’t heard from you on the last response and was just checking back to see if you have a resolution yet. And, if you have any further query do let us know.
Regards,
Dinesh
Hi @CiaraCaryl ,
The issue you're encountering is a common one in DAX and relates to filter context. When you place a measure in a visual that has a date context (like a table row for July), the calculation is filtered to only include data from that month. To get the total for the entire quarter, you need a formula that can ignore the monthly filter from the visual and apply its own filter for the whole quarter.
The correct DAX measure to calculate the total quota for the entire current quarter is:
Full Quarter Quota =
CALCULATE (
SUM ( 'Quotas RSM'[Quota] ),
FILTER (
ALL ( 'Date Table' ),
'Date Table'[Year] = YEAR ( TODAY () )
&& 'Date Table'[Quarter of Year] = QUARTER ( TODAY () )
)
)
This formula works by first using SUM to specify the aggregation of the quota column. The CALCULATE function then modifies the environment in which this sum is performed. The key is the ALL('Date Table') function, which removes any pre-existing filters from the Date Table, such as the filter for a specific month coming from your visual. After clearing the filters, the FILTER function applies a new context, keeping only the rows from your Date Table where the year and quarter match the current date. For today, July 20, 2025, it will find the total for Quarter 3 of 2025.
For this formula to work, your Date Table must have columns for the year and the quarter. If it doesn't, you can add them as calculated columns with these simple expressions: Year = YEAR('Date Table'[Date]) and Quarter of Year = QUARTER('Date Table'[Date]).
With the Full Quarter Quota measure created, you can now proceed to calculate the daily and pacing metrics you need. To find the daily quota requirement, you divide the full quarter's quota by the number of days in that quarter.
Daily Quota =
VAR CurrentQuarter = QUARTER(TODAY())
VAR CurrentYear = YEAR(TODAY())
VAR DaysInQuarter =
COUNTROWS(
FILTER(
ALL('Date Table'),
'Date Table'[Quarter of Year] = CurrentQuarter && 'Date Table'[Year] = CurrentYear
)
)
RETURN
DIVIDE([Full Quarter Quota], DaysInQuarter)
Finally, to see how a sales rep is pacing against their goal, you can create a measure that shows what their quota attainment should be as of today. This is done by multiplying the daily quota requirement by the number of days that have already passed in the quarter.
QTD Pacing Quota =
VAR DaysPassed =
COUNTROWS(
DATESQTD('Date Table'[Date])
)
RETURN
[Daily Quota] * DaysPassed
Best regards,
including dates that havent happened yet
To report on things that are not there you need to use disconnected tables and/or crossjoins
Hi there, assuming your Date table hasn't been properly 'Marked as Date table', i would suggest using below logic for QTD in DAX:
Current Quarter Quota =
VAR _CurrentYear = YEAR(TODAY())
VAR _CurrentQuarter = QUARTER(TODAY())
RETURN
CALCULATE(
SUM(Quota[Quota]),
FILTER(
ALL(Quota),
YEAR(Quota[Date]) = _CurrentYear &&
QUARTER(Quota[Date]) = _CurrentQuarter
)
)
Hope it helps:)
User | Count |
---|---|
16 | |
8 | |
6 | |
6 | |
5 |
User | Count |
---|---|
23 | |
13 | |
13 | |
8 | |
8 |