Microsoft Fabric Community Conference 2025, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount.
Register nowThe Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.
I am trying to count all those that have reached 24 months milestone in a given date range.
My data has a row of data per person, per day with a column that indicates months service. So someone will have 24 months service for approximately 30 (give or take) rows. I would like to count just the first time the number 24 appears so I can show, for example, how many people reached this milestone in a given time period. Each period I have is roughly 28 days long so someones 30ish rows of data will likey span more than one period - I want to count them the first period their 24 appears.
This is a large data set so a calculated column is to slow.
I've gone DAX blind this afternoon so can't see wood for the trees.
This is my current attempt (which I know is off) but highlights the route I'm trying to take - I think.
#CurrentCustomerAchieving24Months =
VAR First24 =
CALCULATE(
MIN('Data'[DateKey]),
FILTER('Data', 'Data'[ServiceLength_Months] = 24 )
)
VAR Counter =
CALCULATE(
COUNTROWS('Data'),
FILTER(
'Data', 'Data'[ServiceLength_Months] = 24 )
&& 'Data'[DateKey] = First24 )
RETURN
Counter
Example Data in the attached.
In the attached I would want to be able to count person 12345 in Period 1 and Person 67891 in Period 2
This should be a link to the very simplified example
Solved! Go to Solution.
Hi @EWBWEBB ,
According to your description, here are my steps you can follow as a solution.
(1) My test data is the same as yours.
(2) We can create measures.
Period =
var _min= CALCULATE(MIN('Table'[DateKey]),FILTER(ALLSELECTED('Table'),'Table'[ServiceLength_Months]=24 && 'Table'[ID]=MAX('Table'[ID])))
var _Period=CALCULATE(MAX('Table (2)'[Period]),FILTER(ALLSELECTED('Table (2)'),'Table (2)'[DateKey]=_min))
return _Period
Count =
var _table=SUMMARIZE(ALL('Table'),'Table'[ID],"per",[Period])
return COUNTROWS(FILTER(_table,[per] = MAX('Table (2)'[Period])))
(3) Then the result is as follows.
If the above one can't help you get the desired result, please provide some sample data in your tables (exclude sensitive data) with Text format and your expected result with backend logic and special examples. It is better if you can share a simplified pbix file. Thank you.
Best Regards,
Neeko Tang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @EWBWEBB ,
According to your description, here are my steps you can follow as a solution.
(1) My test data is the same as yours.
(2) We can create measures.
Period =
var _min= CALCULATE(MIN('Table'[DateKey]),FILTER(ALLSELECTED('Table'),'Table'[ServiceLength_Months]=24 && 'Table'[ID]=MAX('Table'[ID])))
var _Period=CALCULATE(MAX('Table (2)'[Period]),FILTER(ALLSELECTED('Table (2)'),'Table (2)'[DateKey]=_min))
return _Period
Count =
var _table=SUMMARIZE(ALL('Table'),'Table'[ID],"per",[Period])
return COUNTROWS(FILTER(_table,[per] = MAX('Table (2)'[Period])))
(3) Then the result is as follows.
If the above one can't help you get the desired result, please provide some sample data in your tables (exclude sensitive data) with Text format and your expected result with backend logic and special examples. It is better if you can share a simplified pbix file. Thank you.
Best Regards,
Neeko Tang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
This worked perfectly thank you.
Is there a reason that you did this as 2 seperate measures rather than using a Variable for the 'Period' mesaure, or just preference?
Just help inform my thinking next time.
Thanks
Ben
User | Count |
---|---|
21 | |
20 | |
14 | |
10 | |
8 |
User | Count |
---|---|
30 | |
28 | |
13 | |
12 | |
11 |