Saturday, March 22, 2025

How to calculate Total No. of Tasks Active at the end of Selected Period using DAX in Power BI

How to calculate Total No. of Active Tasks during the Selected Period using DAX in Power BI
Scenario:
Let's say we have the Tasks Summary dataset with details like [No. of Tasks] as of [Task Start Date] and their [Task End Date].


The sample data in the Dataset, with No. of Tasks and their Start Dates and End Dates are as follows:

There is a one 1 task with start date as 01-Jan-2021 and end date as 05-Jan-2021.
There are 5 tasks with start date as 03-Jan-2021 and end date as 10-Jan-2021.
There is one 1 task with start date as 03-Jan-2021 and end date as 07-Jan-2021.
There are 4 tasks with start date as 04-Jan-2021 and end date as 07-Jan-2021.

There are 3 tasks with start date as 05-Jan-2021 and end date as 12-Jan-2021.
There are 2 tasks with start date as 06-Jan-2021 and end date as 15-Jan-2021.
There are 4 tasks with start date as 07-Jan-2021 and end date as 18-Jan-2021.

There are 3 tasks with start date as 08-Jan-2021 and end date as 11-Jan-2021.
There are 4 tasks with start date as 08-Jan-2021 and end date as 12-Jan-2021.
There are 4 tasks with start date as 08-Jan-2021 and end date as 20-Jan-2021.

There is one 1 task with start date as 12-Jan-2021 and end date as 23-Jan-2021.
There is one 1 task with start date as 12-Jan-2021 and end date as 26-Jan-2021.
There is one 1 task with start date as 12-Jan-2021 and end date as 19-Jan-2021.

From this Sample, we understand that some tasks are staring on a Start Date and some tasks are close on the same Start Date.
Examples:
On Task_Start_Date: 05-Jan-2021, 3 new tasks are Starting and 1 previous task is Closing as its 
Task_End_Date is 05-Jan-2021.

Similarly, on Task_Start_Date: 07-Jan-2021, 4 new tasks are Starting and 5 previous tasks are Closing as their Task_End_Date is 07-Jan-2021.

Similarly, on Task_Start_Date: 12-Jan-2021, 3 new tasks are Starting and 7 previous tasks are Closing as their Task_End_Date is 12-Jan-2021.

With this understanding, now we will calculate the Total No. of Tasks that are active during the Selected Period, and the actual No. of Tasks active at the end of the Selected Period using the below DAX Logics based on the following Data Model:



[No. of Tasks on StartDate] = SUM(Tasks_Summary[No_of_Tasks])

The following Measure returns the Cumulative Total No. of Tasks by dim_Date[Date]:
Cumulative No. of Tasks on StartDate =
VAR _MaxSelectDate = MAX(dim_Date[Date])
VAR _Cumulative_Tasks =
CALCULATE( [No. of Tasks on StartDate],
    dim_Date[Date] <= _MaxSelectDate,
    REMOVEFILTERS(Tasks_Summary)    
    )
RETURN
IF(NOT ISBLANK([No. of Tasks on StartDate]),_Cumulative_Tasks)

The following measure returns "Y", if any Tasks are Closing on that selected Task_Start_Date:
Is any Task Closing on Selected StartDate =
VAR _Max_Date = MAX(Tasks_Summary[Task_StartDate])
VAR _Min_Task_Date =
CALCULATE(
        MIN(Tasks_Summary[Task_EndDate]),
        FILTER(
            ALL(Tasks_Summary),
            Tasks_Summary[Task_EndDate] = _Max_Date
        )
    )
VAR _Result = IF ( NOT ISBLANK(_Min_Task_Date),"Y","N")
RETURN
IF( NOT ISBLANK(_Max_Date), _Result)

The following measure returns No. of Tasks that are Closing on that selected Task_Start_Date:
No. of Tasks Closing on Selected StartDate =
VAR _Max_Date = MAX(Tasks_Summary[Task_StartDate])
VAR _Result =
    CALCULATE(
        [No. of Tasks on StartDate],
        FILTER(
            ALL(Tasks_Summary),
            Tasks_Summary[Task_EndDate] =_Max_Date
        )
    )
RETURN
IF( NOT ISBLANK(_Max_Date), _Result)

The below measure returns the total No. of  Active Tasks including Closed tasks during the selected Date Period.
No. of Tasks Active during the Selected Period =
VAR _MinSelectDate = MIN(dim_Date[Date])
VAR _MaxSelectDate = MAX(dim_Date[Date])
VAR _MaxTaskDate = MAX(Tasks_Summary[Task_StartDate])
VAR _Result =
    CALCULATE(
        [No. of Tasks on StartDate],
        REMOVEFILTERS(dim_Date[Date]),
        Tasks_Summary[Task_StartDate] <= _MaxSelectDate,
        (
        Tasks_Summary[Task_EndDate] > _MinSelectDate
        ||
        ISBLANK(Tasks_Summary[Task_EndDate])
        )
    )
RETURN
IF(NOT ISBLANK(_MaxTaskDate),_Result)

The below measure returns the total No. of Active Tasks excluding Closed tasks at the end of the selected Date Period.
No. of Tasks Active at the end of Selected Period =
VAR _MaxSelectDate = MAX(dim_Date[Date])
VAR _MaxTaskDate = MAX(Tasks_Summary[Task_EndDate])
VAR _Result =
    CALCULATE(
        [No. of Tasks on StartDate],
        REMOVEFILTERS(dim_Date[Date]),
        Tasks_Summary[Task_StartDate] <= _MaxSelectDate,
        (
        Tasks_Summary[Task_EndDate] > _MaxSelectDate
        ||
        ISBLANK(Tasks_Summary[Task_EndDate])
        )
    )
RETURN
IF( NOT ISBLANK(_MaxTaskDate), _Result )

Result:
The result of the above Measures are as per below:
The fields [Date], [Month_Year] are considered from Dim_Date table.
The fields [Task_StartDate] and [Task_EndDate] are considered from Task_Summary table.


The results of the following measures are seems to be similar in the above Table visual. However, when we look at the Totals, they returns different results.

[No. of Tasks Active during the Selected Period] : It Sum up all the Active Tasks, including all the Closed tasks and returns the total no. of tasks during the selected date period.
[No. of Tasks Active at the end of Selected Period] : It Sum up the Active Tasks, excluding all the Closed Tasks and returns the final total no. of tasks at the end of the selected date period.

The result of Total No. of Tasks from the above measure can be viewed using Column Charts as shown below:


--------------------------------------------------------------------------------------------------------
Thanks, TAMATAM ; Business Intelligence & Analytics Professional
--------------------------------------------------------------------------------------------------------

No comments:

Post a Comment

Hi User, Thank You for visiting My Blog. If you wish, please share your genuine Feedback or comments only related to this Blog Posts. It is my humble request that, please do not post any Spam comments or Advertising kind of comments, which will be Ignored.

Featured Post from this Blog

How to compare Current Snapshot Data with Previous Snapshot in Power BI

How to Dynamically compare two Snapshots Data in Power BI Scenario: Suppose we have a sample Sales data, which is stored with Monthly Snapsh...

Popular Posts from this Blog