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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Chris2016
Helper II
Helper II

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
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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

Top Solution Authors