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

Get Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Learn more

Reply
powerBIpeon
Helper II
Helper II

distinct count of active customers for each year

Hi 

 

I have three fields and would like to calculate the distinct count of active customers per year.

 

  • Account name
  • Start Date
  • End Date 

For example if an account purchases in 2017 and licenses expires in 2019 then it will be active for 2017,2018 and 2019

1 ACCEPTED SOLUTION
jdbuchanan71
Super User
Super User

Hello @powerBIpeon  (I like the name btw).

You can add a calendar table to your model using this formula:  New Table > 

Dates = 
VAR DateRange = CALENDARAUTO()
RETURN 
ADDCOLUMNS(
    DateRange,
    "Year", YEAR([Date])
)

Then write a measure along these lines:

Active Customers = 
VAR MinDate = FIRSTDATE(Dates[Date])
VAR MaxDate = LASTDATE(Dates[Date])
RETURN
CALCULATE(
    DISTINCTCOUNT(Table1[Account Name]),
    Table1[End Date] > MinDate,
    Table1[Start Date] <= MaxDate
)

You will just need to change the name of the table from "Table1" to whatever the name of your table is.  Then pull in the year from the Calendar table and your measure.

customercount.jpg

I uploaded my sample .PBIX file if you want to look at it.  https://www.dropbox.com/s/aep680jne87rk2d/ActiveCustomerCount.pbix?dl=0

 

View solution in original post

7 REPLIES 7
jdbuchanan71
Super User
Super User

Hello @powerBIpeon  (I like the name btw).

You can add a calendar table to your model using this formula:  New Table > 

Dates = 
VAR DateRange = CALENDARAUTO()
RETURN 
ADDCOLUMNS(
    DateRange,
    "Year", YEAR([Date])
)

Then write a measure along these lines:

Active Customers = 
VAR MinDate = FIRSTDATE(Dates[Date])
VAR MaxDate = LASTDATE(Dates[Date])
RETURN
CALCULATE(
    DISTINCTCOUNT(Table1[Account Name]),
    Table1[End Date] > MinDate,
    Table1[Start Date] <= MaxDate
)

You will just need to change the name of the table from "Table1" to whatever the name of your table is.  Then pull in the year from the Calendar table and your measure.

customercount.jpg

I uploaded my sample .PBIX file if you want to look at it.  https://www.dropbox.com/s/aep680jne87rk2d/ActiveCustomerCount.pbix?dl=0

 

@jdbuchanan71  

 

would there be a way to split the revenue amounts using that method?

 

For example if customer purchases a 3 year license for $300K, i want it to show $100K per year.

@powerBIpeon 

Yep, we can do that.  Give this a try.

Amount Split = 
VAR MinDate = FIRSTDATE(Dates[Date])
VAR MaxDate = LASTDATE(Dates[Date])
RETURN
IF ( NOT ISINSCOPE ( Dates[Year] ),
    SUM ( Table1[Amount] ),
    CALCULATE (
        SUMX( Table1, 
            DIVIDE ( Table1[Amount], DATEDIFF( Table1[Start Date], Table1[End Date], YEAR) +1 )
        ),
        Table1[End Date] > MinDate,
        Table1[Start Date] <= MaxDate
    )
)

@jdbuchanan71  - formula works, however i just realized it actually needs to be split by months. Since accounts can sign contracts mid term. For example, if the contract started 6/2018 and ended 6/2019. That means 6 months of revenue would need to be allocated to 2018 while the other 6 months will be allocated to 2019

 

I tried using this solution below, but for some reason can't seem to make it work.

 

https://community.powerbi.com/t5/Desktop/Backlog-contract-Spread-revenue-across-contract-length-Powe...

 

Hi,

Share some data (which can be pasted to an Excel file) and show the expected result.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

Hi,

Share data in a form that can be pasted in an MS Excel file.


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

Thanks! @jdbuchanan71 

Helpful resources

Announcements
Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

October Power BI Update Carousel

Power BI Monthly Update - October 2025

Check out the October 2025 Power BI update to learn about new features.

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Solution Authors