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
Anonymous
Not applicable

Count of existing items by year with start date in the past

I have table with a Fund ID and an established date and a possible terminated date. I want a graph that shows a count of active funds during each year. 

 

For example: If a fund was established in 2005 and terminated in 2013,it should be counted in 2005 through 2013. 

 

I tried creating a table containing 1997 to the current year and a calculated field for the fund count but I can't get it to work. 

 

Calculated Measure: 

FundCount_ = CALCULATE(count(Funds[FundID]),
FILTER(Funds, Funds[EstablishedDate]<= CALCULATE(max('DateTable'[Value]))
&& Funds[TerminatedDate] >= CALCULATE(min('DateTable'[Value]))))

1 ACCEPTED SOLUTION
v-xicai
Community Support
Community Support

Hi @Anonymous ,

 

According to your description, I create sample data to test the scenario. Firstly, create Calendar table DateTable, and then create measure FundCount_ to meet your demand.

 

1.png

 

 

 

 

 

 

 

DateTable = CALENDAR("1997,01,01",TODAY())

 

FundCount_ = CALCULATE(COUNT(Funds[Fund ID]),FILTER(ALLSELECTED(Funds),Funds[EstablishedDate]<=MAX(DateTable[Value])&&Funds[TerminatedDate]>=MIN(DateTable[Value])))

 

Choose Clustered column chart visual to display the result.

 

2.jpg

 

 

 

 

 

 

 

 

 

Here is my test pbix: https://qiuyunus-my.sharepoint.com/:u:/g/personal/pbipro_qiuyunus_onmicrosoft_com/ESSqoq2uMhRFsISy1HjIE_YB67CS4GC4hd5p98n4MKqCKw?e=RaccGj

 

Best Regards,

Amy

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

1 REPLY 1
v-xicai
Community Support
Community Support

Hi @Anonymous ,

 

According to your description, I create sample data to test the scenario. Firstly, create Calendar table DateTable, and then create measure FundCount_ to meet your demand.

 

1.png

 

 

 

 

 

 

 

DateTable = CALENDAR("1997,01,01",TODAY())

 

FundCount_ = CALCULATE(COUNT(Funds[Fund ID]),FILTER(ALLSELECTED(Funds),Funds[EstablishedDate]<=MAX(DateTable[Value])&&Funds[TerminatedDate]>=MIN(DateTable[Value])))

 

Choose Clustered column chart visual to display the result.

 

2.jpg

 

 

 

 

 

 

 

 

 

Here is my test pbix: https://qiuyunus-my.sharepoint.com/:u:/g/personal/pbipro_qiuyunus_onmicrosoft_com/ESSqoq2uMhRFsISy1HjIE_YB67CS4GC4hd5p98n4MKqCKw?e=RaccGj

 

Best Regards,

Amy

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

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.