Microsoft Fabric Community Conference 2025, March 31 - April 2, Las Vegas, Nevada. Use code FABINSIDER for a $400 discount.
Register nowThe Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.
Hello,
I am creating a matrix that looks at sales by month from a specific start date, but I also need to add custom date ranges that look at months 1-6 combined, 1-12 combined, all months after the first year combined, and total months. I am not sure how to create the custom aggregated rows. Ultimately looking for how to calculate something like the last three rows below...
Month | Sales Count | Total Sales |
3/1/2020 | 6 | $84 |
4/30/2020 | 5 | $210 |
5/31/2020 | 6 | $126 |
6/30/2020 | 3 | $75 |
7/31/2020 | 9 | $279 |
8/31/2020 | 8 | $168 |
3/2020 - 5/2020 | 17 | $420 |
6/2020 - 8/2021 | 20 | $522 |
3/2020 - 8/31/2020 | 37 | $942 |
Solved! Go to Solution.
Not part of the standard visual functionality. Consider using separate visuals.
Hi, @Nashville1986
Thanks for @lbendlin reply. You can refer to the following DAX.
Create a Table:
User this DAX to the matrix:
Sales counts =
VAR _JanuaryMonthStartDate =
MIN ( 'Table'[Date] )
VAR _JuneMonthEndDate =
EOMONTH ( _JanuaryMonthStartDate, 5 )
VAR _JulyMonthStartDate =
EOMONTH ( _JuneMonthEndDate, 5 ) + 1
VAR _DecemberMonthEndDate =
EOMONTH ( _JanuaryMonthStartDate, 11 )
VAR _secondYearJanuaryStartDate =
EOMONTH ( _JanuaryMonthStartDate, 11 ) + 1
VAR _maxDate =
MAX ( 'Table'[Date] )
VAR _FirstYear1To6Months =
CALCULATE (
SUM ( 'Table'[Sales Count] ),
FILTER (
'Table',
'Table'[Date] >= _JanuaryMonthStartDate
&& 'Table'[Date] <= _JuneMonthEndDate
)
)
VAR _FirstYear7To12Months =
CALCULATE (
SUM ( 'Table'[Sales Count] ),
FILTER (
'Table',
'Table'[Date] >= _JulyMonthStartDate
&& 'Table'[Date] <= _DecemberMonthEndDate
)
)
VAR _AfterFirstYearMonths =
CALCULATE (
SUM ( 'Table'[Sales Count] ),
FILTER (
'Table',
'Table'[Date] >= _secondYearJanuaryStartDate
&& 'Table'[Date] <= _maxDate
)
)
VAR _AllMonths =
CALCULATE (
SUM ( 'Table'[Sales Count] ),
FILTER (
'Table',
'Table'[Date] >= _JanuaryMonthStartDate
&& 'Table'[Date] <= _maxDate
)
)
VAR _categories =
SELECTEDVALUE ( 'Table 2'[Categories] )
VAR _result =
SWITCH (
_categories,
"First Year 1-6 Months", _FirstYear1To6Months,
"First Year 7-12 Months", _FirstYear7To12Months,
"After First Year Months", _AfterFirstYearMonths,
"All Months", _AllMonths
)
RETURN
_result
Best Regards,
Yang
Community Support Team
If there is any post helps, then please consider Accept it as the solution to help the other members find it more quickly.
If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!
How to get your questions answered quickly -- How to provide sample data in the Power BI Forum
Hi, @Nashville1986
Thanks for @lbendlin reply. You can refer to the following DAX.
Create a Table:
User this DAX to the matrix:
Sales counts =
VAR _JanuaryMonthStartDate =
MIN ( 'Table'[Date] )
VAR _JuneMonthEndDate =
EOMONTH ( _JanuaryMonthStartDate, 5 )
VAR _JulyMonthStartDate =
EOMONTH ( _JuneMonthEndDate, 5 ) + 1
VAR _DecemberMonthEndDate =
EOMONTH ( _JanuaryMonthStartDate, 11 )
VAR _secondYearJanuaryStartDate =
EOMONTH ( _JanuaryMonthStartDate, 11 ) + 1
VAR _maxDate =
MAX ( 'Table'[Date] )
VAR _FirstYear1To6Months =
CALCULATE (
SUM ( 'Table'[Sales Count] ),
FILTER (
'Table',
'Table'[Date] >= _JanuaryMonthStartDate
&& 'Table'[Date] <= _JuneMonthEndDate
)
)
VAR _FirstYear7To12Months =
CALCULATE (
SUM ( 'Table'[Sales Count] ),
FILTER (
'Table',
'Table'[Date] >= _JulyMonthStartDate
&& 'Table'[Date] <= _DecemberMonthEndDate
)
)
VAR _AfterFirstYearMonths =
CALCULATE (
SUM ( 'Table'[Sales Count] ),
FILTER (
'Table',
'Table'[Date] >= _secondYearJanuaryStartDate
&& 'Table'[Date] <= _maxDate
)
)
VAR _AllMonths =
CALCULATE (
SUM ( 'Table'[Sales Count] ),
FILTER (
'Table',
'Table'[Date] >= _JanuaryMonthStartDate
&& 'Table'[Date] <= _maxDate
)
)
VAR _categories =
SELECTEDVALUE ( 'Table 2'[Categories] )
VAR _result =
SWITCH (
_categories,
"First Year 1-6 Months", _FirstYear1To6Months,
"First Year 7-12 Months", _FirstYear7To12Months,
"After First Year Months", _AfterFirstYearMonths,
"All Months", _AllMonths
)
RETURN
_result
Best Regards,
Yang
Community Support Team
If there is any post helps, then please consider Accept it as the solution to help the other members find it more quickly.
If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!
How to get your questions answered quickly -- How to provide sample data in the Power BI Forum
Not part of the standard visual functionality. Consider using separate visuals.
Can you elaborate? So if the visual doesn't have the functionality then I would need to import another facts/data table with the aggregated date values and then have a separate visual referencing just that table. Is that a correct assumption? Thanks for the help!