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
kressb
Helper V
Helper V

How do you count # of months *complete* if there are not lines in your dataset for all months?

I need to count "months complete" when Fiscal Year is July 1 - June 30.

Fiscal Year 2020 is complete. Months Complete = 12

Fiscal Year 2021 is not complete. Months Complete = 10 (July-April)

"Total" should equal 22 (12+10)

Problem is there is not necessarily data for every month, ex:

MonthsinDataSet.png

I have tried: 

Var _Num = DistinctCountNoBlank(Amounts[MonthYr])   - returns 3

Var _Num = Calculate(DistinctCountNoBlank(Amounts[MonthYr]),Allselected()) - returns 9 no matter what the column shows

Var_NumExp.png

Is there any possible way to do this?

Relationships between tables:

Relationships-Tester.png

1 ACCEPTED SOLUTION
DataInsights
Super User
Super User

@kressb,

 

Try this measure:

 

Count Months = 
VAR vCurrentYear =
    MAX ( Dates[Fiscal Year] )
VAR vMaxMonthYrInCurrentYear =
    MAX ( Amounts[MonthYr] )
VAR vMaxYear =
    CALCULATE ( YEAR ( MAX ( Amounts[MonthYr] ) ), ALL ( Dates ) )
VAR vMonthCount =
    CALCULATE (
        DISTINCTCOUNT ( Dates[Fiscal Month] ),
        Dates[Date] <= vMaxMonthYrInCurrentYear,
        ALL ( Dates ),
        VALUES ( Dates[Fiscal Year] )
    )
VAR vResult =
    --if the current year is not the latest year, then the current year is complete (i.e. 12 months);
    --otherwise, count the number of months in the current year that are <= the latest month of the current year
    IF (
        vCurrentYear < vMaxYear,
        12,
        vMonthCount
    )
RETURN
    vResult

 

DataInsights_1-1621795187416.png

 





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




View solution in original post

1 REPLY 1
DataInsights
Super User
Super User

@kressb,

 

Try this measure:

 

Count Months = 
VAR vCurrentYear =
    MAX ( Dates[Fiscal Year] )
VAR vMaxMonthYrInCurrentYear =
    MAX ( Amounts[MonthYr] )
VAR vMaxYear =
    CALCULATE ( YEAR ( MAX ( Amounts[MonthYr] ) ), ALL ( Dates ) )
VAR vMonthCount =
    CALCULATE (
        DISTINCTCOUNT ( Dates[Fiscal Month] ),
        Dates[Date] <= vMaxMonthYrInCurrentYear,
        ALL ( Dates ),
        VALUES ( Dates[Fiscal Year] )
    )
VAR vResult =
    --if the current year is not the latest year, then the current year is complete (i.e. 12 months);
    --otherwise, count the number of months in the current year that are <= the latest month of the current year
    IF (
        vCurrentYear < vMaxYear,
        12,
        vMonthCount
    )
RETURN
    vResult

 

DataInsights_1-1621795187416.png

 





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




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.