cancel
Showing results for 
Search instead for 
Did you mean: 

Fabric is Generally Available. Browse Fabric Presentations. Work towards your Fabric certification with the Cloud Skills Challenge.

Reply
Sjon1791
Regular Visitor

Calculate active years from a customer

I am trying to calculate the amount of active years for customers.

 

We have different tables like "documents transaction date", "customer" and "sales values" .

 

The Tranaction date table is a calender, Customer is all customer information and both are linked to Sales values where are all transactions.

I can see the Active years in a matrix per year.

Cumulative Distinct Count Until this YTD = TOTALYTD(DISTINCTCOUNT([Related Customer]),'SALES VALUES'[Related Date])

But it is not giving me

Customer  years active.

       A               2

      B                1

       c                 3

Etc.

1 ACCEPTED SOLUTION
lc_finance
Solution Sage
Solution Sage

Hi @Sjon1791 ,

 

thank you for the interesting question.

You can solve this by adding a calculated column to your customer table.

 

The formula is the following:

Years active = 
VAR currentCustomer = CALCULATE(SELECTEDVALUE('CUSTOMERS'[Customer]))
VAR lastYearActive = CALCULATE(MAX('SALES VALUE'[Related Date]),'SALES VALUE'[Customer]=currentCustomer)
VAR firstYearActive = CALCULATE(MIN('SALES VALUE'[Related Date]),'SALES VALUE'[Customer]=currentCustomer)

RETURN YEAR(lastYearActive)- YEAR(firstYearActive)

And here is what it looks like:

Years Active.png

 

Finally, you can also find a Power BI file with an example here.

 

Let me know if this helps you!

 

Regards,

 

LC

Interested in Power BI templates? Check out my blog at www.finance-bi.com

View solution in original post

1 REPLY 1
lc_finance
Solution Sage
Solution Sage

Hi @Sjon1791 ,

 

thank you for the interesting question.

You can solve this by adding a calculated column to your customer table.

 

The formula is the following:

Years active = 
VAR currentCustomer = CALCULATE(SELECTEDVALUE('CUSTOMERS'[Customer]))
VAR lastYearActive = CALCULATE(MAX('SALES VALUE'[Related Date]),'SALES VALUE'[Customer]=currentCustomer)
VAR firstYearActive = CALCULATE(MIN('SALES VALUE'[Related Date]),'SALES VALUE'[Customer]=currentCustomer)

RETURN YEAR(lastYearActive)- YEAR(firstYearActive)

And here is what it looks like:

Years Active.png

 

Finally, you can also find a Power BI file with an example here.

 

Let me know if this helps you!

 

Regards,

 

LC

Interested in Power BI templates? Check out my blog at www.finance-bi.com

Helpful resources

Announcements
PBI November 2023 Update Carousel

Power BI Monthly Update - November 2023

Check out the November 2023 Power BI update to learn about new features.

Community News

Fabric Community News unified experience

Read the latest Fabric Community announcements, including updates on Power BI, Synapse, Data Factory and Data Activator.

Power BI Fabric Summit Carousel

The largest Power BI and Fabric virtual conference

130+ sessions, 130+ speakers, Product managers, MVPs, and experts. All about Power BI and Fabric. Attend online or watch the recordings.

Top Solution Authors
Top Kudoed Authors