Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Chris2016
Helper III
Helper III

Measure to count the distinct number of months in a date table

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!

1 ACCEPTED SOLUTION
ppm1
Solution Sage
Solution Sage

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

Microsoft Employee

View solution in original post

2 REPLIES 2
ppm1
Solution Sage
Solution Sage

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

Microsoft Employee

Thank you, Pat, that worked very well.

Many thanks for your help!

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.

Top Solution Authors