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

The ultimate Microsoft Fabric, Power BI, Azure AI & SQL learning event! Join us in Las Vegas from March 26-28, 2024. Use code MSCUST for a $100 discount. Register Now

Reply
Anonymous
Not applicable

DAX - Distinct count with a relative date formula

Hi, 

 

I have spent hours trying every solution I can find online to no avail. 

 

I need a formula to count the number of distinct values in a column (distinct not critical if something like 'countrows' can make the formula work) while filtering a table using a date column so that it provides a single figure count of how many items were created in the last month from that date (calander month). 

 

I need a formula because I have different dates in my data & I need counts from each of them & I would like it in a single chart/table visualization. Also I need it relative to minimise manual input during monthly report runs. 

 

My data is:

[unique identifier] 

[Created Date]

[Closed Date]

 

Any help would be appreciated! 

Thank you. 

1 ACCEPTED SOLUTION
v-jingzhang
Community Support
Community Support

Hi @Anonymous 

 

I recommend to use PREVIOUSMONTH function. You can use the following measures

Count on Created Date = CALCULATE(DISTINCTCOUNT('Table'[Index]),PREVIOUSMONTH('Date'[Date]))
Count on Closed Date = CALCULATE(DISTINCTCOUNT('Table'[Index]),PREVIOUSMONTH('Date'[Date]),USERELATIONSHIP('Date'[Date],'Table'[Closed Date]))

Relationship

vjingzhang_0-1644919313477.png

Result

vjingzhang_1-1644919331439.png

I attched a pbix at bottom. 

 

Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.

View solution in original post

2 REPLIES 2
v-jingzhang
Community Support
Community Support

Hi @Anonymous 

 

I recommend to use PREVIOUSMONTH function. You can use the following measures

Count on Created Date = CALCULATE(DISTINCTCOUNT('Table'[Index]),PREVIOUSMONTH('Date'[Date]))
Count on Closed Date = CALCULATE(DISTINCTCOUNT('Table'[Index]),PREVIOUSMONTH('Date'[Date]),USERELATIONSHIP('Date'[Date],'Table'[Closed Date]))

Relationship

vjingzhang_0-1644919313477.png

Result

vjingzhang_1-1644919331439.png

I attched a pbix at bottom. 

 

Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.

DataInsights
Super User
Super User

@Anonymous,

 

Try this measure:

 

Row Count Created =
CALCULATE ( COUNTROWS ( Table1 ), PARALLELPERIOD ( DimDate[Date], -1, MONTH ) )

 

Since you have multiple date columns in the fact table, create one active relationship with the date table (DimDate), and inactive relationships for the other date columns. To use an inactive relationship, use USERELATIONSHIP:

 

Row Count Closed =
CALCULATE (
    COUNTROWS ( Table1 ),
    PARALLELPERIOD ( DimDate[Date], -1, MONTH ),
    USERELATIONSHIP ( Table1[Closed Date], DimDate[Date] )
)

 

In these examples, Created Date has an active relationship and Closed Date has an inactive relationship. The date slicer should use DimDate[Date].





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

Proud to be a Super User!




Helpful resources

Announcements
Fabric Community Conference

Microsoft Fabric Community Conference

Join us at our first-ever Microsoft Fabric Community Conference, March 26-28, 2024 in Las Vegas with 100+ sessions by community experts and Microsoft engineering.

February 2024 Update Carousel

Power BI Monthly Update - February 2024

Check out the February 2024 Power BI update to learn about new features.

Fabric Career Hub

Microsoft Fabric Career Hub

Explore career paths and learn resources in Fabric.

Fabric Partner Community

Microsoft Fabric Partner Community

Engage with the Fabric engineering team, hear of product updates, business opportunities, and resources in the Fabric Partner Community.