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

Join us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.

Reply
AsnateKalnina
Frequent Visitor

How to count cases per date based on their status on that date

Hi, 

I have a "main table" with cases and their creation date and final status.

then I have a  "change table" with the same cases and each change in status Old Status -> New Status and date on which it happened. 

And of course I have a "calendar table" with all dates. 

 

I need to calculate for each date in calendar how many cases were in each status.

 

Problem is that the "change table" does not have records in between status changes. Only the date for particular change. 

Moreover, there can be several status changes in one day for one case. Only the last one is relevant. 

 

I imagine the calculated result could be something like this. 

I am interested in the Total rows. But how to get the '1's and count for each date and each status?

Can you please help?

AsnateKalnina_0-1641574528175.png

 

1 ACCEPTED SOLUTION
ValtteriN
Super User
Super User

Hi,

This post by SQLBI contains a good explanation on how to do this: https://www.sqlbi.com/blog/alberto/2011/03/08/thinking-in-dax-counting-products-in-the-current-statu...

Note that to use this DAX there can't be an active relationship between the calendar table and your fact table.

Data:

ValtteriN_0-1641583484643.png

Dax:

Stage =
CALCULATE (
COUNTROWS (
FILTER (
'Cases',
'Cases'[Index]
= CALCULATE (
MAX ( 'Cases'[Index] ),
ALL ( 'Cases' ),
'Cases'[Case]= EARLIER ( 'Cases'[Case] ),
'Cases'[Date] <= VALUES ( 'Calendar'[Date])
)
)
),LASTDATE( ( 'Calendar'[Date])
))
 
End result:
ValtteriN_2-1641585723762.png

 

I hope this helps and if it does consider accpeting this as a solution and giving the post a thumbs up!

 





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

Proud to be a Super User!




View solution in original post

2 REPLIES 2
ValtteriN
Super User
Super User

Hi,

This post by SQLBI contains a good explanation on how to do this: https://www.sqlbi.com/blog/alberto/2011/03/08/thinking-in-dax-counting-products-in-the-current-statu...

Note that to use this DAX there can't be an active relationship between the calendar table and your fact table.

Data:

ValtteriN_0-1641583484643.png

Dax:

Stage =
CALCULATE (
COUNTROWS (
FILTER (
'Cases',
'Cases'[Index]
= CALCULATE (
MAX ( 'Cases'[Index] ),
ALL ( 'Cases' ),
'Cases'[Case]= EARLIER ( 'Cases'[Case] ),
'Cases'[Date] <= VALUES ( 'Calendar'[Date])
)
)
),LASTDATE( ( 'Calendar'[Date])
))
 
End result:
ValtteriN_2-1641585723762.png

 

I hope this helps and if it does consider accpeting this as a solution and giving the post a thumbs up!

 





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

Proud to be a Super User!




Thank you, works very well!

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

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