Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!Calling all Data Engineers! Fabric Data Engineer (Exam DP-700) live sessions are back! Starting October 16th. Sign up.
Hi,
Could someone help with a measure to count the distinct number of months in a date column (not coming from a Date table)? I need this to calculate an average per month. I know that I could just create a calculated column of Y&Mo from Date, but the report is already heavy and don't want to burden it unnecessarily.
I already tried using DATEDIFF, but I don't think that will work properly if I start missing months in the Date column going forward (e.g. the current month of May is almost over, and I still do not have any data for this month - I expect it to be blank starting June 1st, and the calculation will be off when I start getting data in June).
NoofMo = CALCULATE(DATEDIFF( CALCULATE( MIN('Table'[Date]), ALLEXCEPT('Table', 'Table'[Date])), CALCULATE( MAX('Table'[Date]), ALLEXCEPT('Table', 'Table'[Date])), MONTH)+1, FILTER('Table',NOT(ISBLANK([Date]))))
Though this calculation works for now, I just need an actual distinct count of months in the Date column.
Many thanks for any idea!
Solved! Go to Solution.
Here's a measure expression that shows one way to do it. Although, I would consider adding a proper date table or yearmonth column and optimize your model in other areas.
MonthsInColumn =
VAR dateswithmonth =
ADDCOLUMNS (
DISTINCT ( Sales[SaleDate] ),
"cMon", EOMONTH ( Sales[SaleDate], 0 )
)
RETURN
COUNTROWS ( SUMMARIZE ( dateswithmonth, [cMon] ) )
Pat
Here's a measure expression that shows one way to do it. Although, I would consider adding a proper date table or yearmonth column and optimize your model in other areas.
MonthsInColumn =
VAR dateswithmonth =
ADDCOLUMNS (
DISTINCT ( Sales[SaleDate] ),
"cMon", EOMONTH ( Sales[SaleDate], 0 )
)
RETURN
COUNTROWS ( SUMMARIZE ( dateswithmonth, [cMon] ) )
Pat
Thank you, Pat, that worked very well.
Many thanks for your help!
Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes!
Check out the October 2025 Power BI update to learn about new features.
User | Count |
---|---|
12 | |
11 | |
9 | |
8 | |
8 |