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

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
Anonymous
Not applicable

Distinct count with previous date criteria

Hi, can anyone help me to understand what logic I need to apply to my existing table in order to return correct data?

 

Example table with underlying data called 'Table 1';

MarjanCRO_0-1669824896416.png

 

This is my current visual/table created in Power BI based on the above table with the date slicer to return data for Quarter 3 only;

MarjanCRO_1-1669825035739.pngMarjanCRO_1-1669820411628.png

 

I need to return the count of distinct postcodes with the time period (Q3) BUT I need to check the previous years' (12 months) data that returned postcodes and if the specific postcodes were queried within 12 months before the start date of Q3 (1st July21), we need to exclude those from the total count for Q3.

 

Just to give you a better context:

I need to bill my clients quarterly based on the number of calls they make, BUT I don't want to charge them for duplicate calls (postcodes) that were made in the past 12 months before the start date of the quarter.

e.g. client 'ABC ltd' had a total of 73 calls in Q3 but i don't want to charge them for all 73 calls, I want to charge them for unique (distinct) postcodes/calls compared with the past 12 months before start of Q3 (from 1st July 2020 to July 2021). This way we would only charge them for the first search of the postcode each time they search it in a year. Hope that makes sense. 

 

Does anyone have any idea how to make this work? I guess I need to get all calls/postcodes from the quarter I am doing plus the 12 of calls/postcodes prior to that quarter and then return the distinct count of postcodes from that quarter with removed postcodes that were included in the 12 months prior data. How to do that?

 

Thanks,

1 ACCEPTED SOLUTION
v-yalanwu-msft
Community Support
Community Support

Hi, @Anonymous ;

I create a simple test file. and create a measure as follow:

Measure = 
COUNTROWS(EXCEPT(VALUES('Table'[ID]),
SUMMARIZE(FILTER(ALL('Table'),
[Date]<=MIN('Table'[Date])&&[Date]>=EDATE(MIN('Table'[Date]),-12)),[ID])))

the final show:

vyalanwumsft_0-1669862128677.png


Best Regards,
Community Support Team _ Yalan Wu
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

2 REPLIES 2
v-yalanwu-msft
Community Support
Community Support

Hi, @Anonymous ;

I create a simple test file. and create a measure as follow:

Measure = 
COUNTROWS(EXCEPT(VALUES('Table'[ID]),
SUMMARIZE(FILTER(ALL('Table'),
[Date]<=MIN('Table'[Date])&&[Date]>=EDATE(MIN('Table'[Date]),-12)),[ID])))

the final show:

vyalanwumsft_0-1669862128677.png


Best Regards,
Community Support Team _ Yalan Wu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Anonymous
Not applicable

Hi @v-yalanwu-msft, thanks for this. Looks really good. I think I will be able to use this in my report.

 

Just one quick question about the measure you provided;

Does this measure return unique, distinct IDs? If not, what and where to add to the measure to return only distinct IDs?

 

Sorry, I am fairly new to Power BI DAX.

Thanks,

 

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

Find out what's new and trending in the Fabric Community.

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

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! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

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