cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
mk720x Regular Visitor
Regular Visitor

DAX: Counting the Number Between Milestones, Aggregating by Month

Hi!

I'm trying to create a monthly view of how many unique projects were "in progress" that month.
I got something working that will show how many projects were in progress on a particular day, but haven't cracked the code on how to show it accurately by month.

Currently, this is what I have:

 

TABLE = 
    VAR ExpandedTable = 
        GENERATE(
            CALENDAR(DATE(2018,1,1),TODAY()),
            
            FILTER(
                'Other Table',
                [Date]>='Other Table'[Start Date] &&
                [Date]<= 'Other Table'[END Date])
                )
            
       
    RETURN 
    SUMMARIZE(  
        ExpandedTable,
        [Date],
        "Count",COUNTROWS('Other Table')
        ) 

What do I need to change to have it return the total of unique projects worked that month?

1 ACCEPTED SOLUTION

Accepted Solutions
Community Support Team
Community Support Team

Re: DAX: Counting the Number Between Milestones, Aggregating by Month

Hi @mk720x 

Assume "other table" is your main data table including "project", "start date" and "end date" fields.

I create a new table

calendar = ADDCOLUMNS(CALENDARAUTO(),"year",YEAR([Date]),"month",MONTH([Date]))

Then create two calculated columns in this table

start_month = CALCULATE(MIN('calendar'[Date]),ALLEXCEPT('calendar','calendar'[year],'calendar'[month]))

end_month = CALCULATE(MAX('calendar'[Date]),ALLEXCEPT('calendar','calendar'[year],'calendar'[month]))

Then create a measure in this table

count =
CALCULATE (
    COUNT ( 'other table'[project] ),
    FILTER (
        ALL ( 'other table' ),
        'other table'[start date] <= MAX ( 'calendar'[start_month] )
            && 'other table'[end date] >= MAX ( 'calendar'[end_month] )
    )
)

10.png

Note:

There is no relationship between "calendar" and "other table".

 

In my test, "projects were in progress" in that month means:

it should be in progress during the whole month, 

for example,

project8, start from2019/1/1, end at 2019/3/28,

in 2019/3, this project isn't considered as in progress, for it doesn't work for the whole month.

 

Best Regards

Maggie

 

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

2 REPLIES 2
Super User
Super User

Re: DAX: Counting the Number Between Milestones, Aggregating by Month


Take a look at these two Quick Measures as I think you want something like them.

https://community.powerbi.com/t5/Quick-Measures-Gallery/Open-Tickets/m-p/409364
https://community.powerbi.com/t5/Quick-Measures-Gallery/Periodic-Billing/m-p/409365


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

Proud to be a Datanaut!


Community Support Team
Community Support Team

Re: DAX: Counting the Number Between Milestones, Aggregating by Month

Hi @mk720x 

Assume "other table" is your main data table including "project", "start date" and "end date" fields.

I create a new table

calendar = ADDCOLUMNS(CALENDARAUTO(),"year",YEAR([Date]),"month",MONTH([Date]))

Then create two calculated columns in this table

start_month = CALCULATE(MIN('calendar'[Date]),ALLEXCEPT('calendar','calendar'[year],'calendar'[month]))

end_month = CALCULATE(MAX('calendar'[Date]),ALLEXCEPT('calendar','calendar'[year],'calendar'[month]))

Then create a measure in this table

count =
CALCULATE (
    COUNT ( 'other table'[project] ),
    FILTER (
        ALL ( 'other table' ),
        'other table'[start date] <= MAX ( 'calendar'[start_month] )
            && 'other table'[end date] >= MAX ( 'calendar'[end_month] )
    )
)

10.png

Note:

There is no relationship between "calendar" and "other table".

 

In my test, "projects were in progress" in that month means:

it should be in progress during the whole month, 

for example,

project8, start from2019/1/1, end at 2019/3/28,

in 2019/3, this project isn't considered as in progress, for it doesn't work for the whole month.

 

Best Regards

Maggie

 

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