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

Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM. Register now.

Reply
Anonymous
Not applicable

Count values between dates

Hi all! 

I need a DAX measure to count items between dates, example:

 

itemstartend
A01/01/202203/01/2022
B05/01/202210/01/2022
C04/01/202206/01/2022
D02/01/202208/01/2022
E07/01/202209/01/2022

 

Result with DAX:

 

calendar[date]quantity itemref item
01/01/20221A
02/01/20222A, D
03/01/20222A, D
04/01/20222C, D
05/01/20223B, C, D
06/01/20223B, C, D
07/01/20223B, D, E
08/01/20223B, D, E
09/01/20222B, E
10/01/20221B

Obs: column "ref item" in second table only illustrative, not consider

 

Can you help?

1 ACCEPTED SOLUTION
v-zhangti
Community Support
Community Support

Hi, @Anonymous 

 

You can try the following methods.

Table:

calendar = CALENDAR(MIN('Table'[start]),MAX('Table'[end]))

Measure:

quantity item =
CALCULATE (
    COUNT ( 'Table'[item] ),
    FILTER (
        ALL ( 'Table' ),
        [start] <= SELECTEDVALUE ( 'calendar'[Date] )
            && [end] >= SELECTEDVALUE ( 'calendar'[Date] )
    )
)

vzhangti_0-1660714149324.png

Is this the result you expect?

 

Best Regards,

Community Support Team _Charlotte

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

4 REPLIES 4
v-zhangti
Community Support
Community Support

Hi, @Anonymous 

 

You can try the following methods.

Table:

calendar = CALENDAR(MIN('Table'[start]),MAX('Table'[end]))

Measure:

quantity item =
CALCULATE (
    COUNT ( 'Table'[item] ),
    FILTER (
        ALL ( 'Table' ),
        [start] <= SELECTEDVALUE ( 'calendar'[Date] )
            && [end] >= SELECTEDVALUE ( 'calendar'[Date] )
    )
)

vzhangti_0-1660714149324.png

Is this the result you expect?

 

Best Regards,

Community Support Team _Charlotte

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

Anonymous
Not applicable

Good night @v-zhangti !
This solution works perfectly and solved the problem.

Thanks a lot for the help!

amitchandak
Super User
Super User

@Anonymous , first expand between dates in power query

https://amitchandak.medium.com/power-query-get-all-dates-between-the-start-and-end-date-9ad6a84cf5f2

 

Then you can concat in power query of in DAX

 

Concatenate Text- Measure, DAX Table, and Power Query Table: https://youtu.be/xAh3tz1qo24

 

 

The  first step can be done in DAX too , and a measure with help from cancatenatex

https://community.powerbi.com/t5/Community-Blog/How-to-divide-distribute-values-between-start-date-or-end-date/ba-p/1503785

Share with Power BI Enthusiasts: Full Power BI Video (20 Hours) YouTube
Microsoft Fabric Series 60+ Videos YouTube
Microsoft Fabric Hindi End to End YouTube
Anonymous
Not applicable

@amitchandakthanks for replying!

This solution works perfectly but it expands the table according to the date range.

When you have a lot of data, the load becomes very heavy.

Helpful resources

Announcements
FabCon Global Hackathon Carousel

FabCon Global Hackathon

Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes!

October Power BI Update Carousel

Power BI Monthly Update - October 2025

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

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.