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

Be one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now

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
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.

ArunFabCon

Microsoft Fabric Community Conference 2025

Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.