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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
klintala
Frequent Visitor

Count of Max Schedule Overlap

Basic Example pbix 

 

Given the columns: vendor, startdate, and duration, is there a way to return the the maximum count of simultaneous tasks?

example:

Vendor A

5/1/20207
Vendor A5/2/20207
Vendor A5/15/20207
Vendor A6/1/20207
Vendor B5/1/20205
Vendor B5/15/20205
Vendor B5/17/20205
Vendor B5/18/20205
Vendor C6/1/202010
Vendor C6/20/202010

Vendor A will have a maximum of 2 tasks happening at the same time.

Vendor B will have a maximum of 3 tasks happening at the same time.

Vendor C will have a maximum of 1 task happening at the same time.

 

In the attached pbix example I have a similar table with more instances, along with a date table. 

1 ACCEPTED SOLUTION
Icey
Community Support
Community Support

Hi @klintala ,

 

Try this:

 

1. Create [EndDate] column.

EndDate = [StartDate]+[Duration]

 

2. Create a Measure.

Measure = 
VAR t1 =
    SELECTCOLUMNS (
        'Table',
        "Vendor_", 'Table'[Vendor],
        "StartDate_", 'Table'[StartDate],
        "EndDate_", 'Table'[EndDate]
    )
VAR t2 =
    FILTER (
        CROSSJOIN ( 'Table', t1 ),
        [Vendor] = [Vendor_]
            && NOT ( [EndDate] <= [EndDate_] )
    )
VAR t3 =
    ADDCOLUMNS (
        t2,
        "MinDate_", IF ( [StartDate] >= [StartDate_], [StartDate], [StartDate_] ),
        "MaxDate", IF ( [EndDate] >= [EndDate_], [EndDate_], [EndDate] )
    )
VAR t4 =
    ADDCOLUMNS ( t3, "OverlapDay", DATEDIFF ( [MinDate_], [MaxDate], DAY ) )
VAR t5 =
    ADDCOLUMNS (
        t4,
        "Count_", COUNTAX (
            FILTER (
                t4,
                [Vendor] = EARLIER ( [Vendor] )
                    && [StartDate] = EARLIER ( [StartDate] )
                    && [OverlapDay] > 0
            ),
            [Vendor]
        )
    )
RETURN
    MAXX ( t5, [Count_] + 1 )

vendor.PNG

 

For more details, please check the attached PBIX file,

 

 

Best Regards,

Icey

 

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
Icey
Community Support
Community Support

Hi @klintala ,

 

Is this problem solved?

 

 

Best Regards,

Icey

Icey
Community Support
Community Support

Hi @klintala ,

 

Try this:

 

1. Create [EndDate] column.

EndDate = [StartDate]+[Duration]

 

2. Create a Measure.

Measure = 
VAR t1 =
    SELECTCOLUMNS (
        'Table',
        "Vendor_", 'Table'[Vendor],
        "StartDate_", 'Table'[StartDate],
        "EndDate_", 'Table'[EndDate]
    )
VAR t2 =
    FILTER (
        CROSSJOIN ( 'Table', t1 ),
        [Vendor] = [Vendor_]
            && NOT ( [EndDate] <= [EndDate_] )
    )
VAR t3 =
    ADDCOLUMNS (
        t2,
        "MinDate_", IF ( [StartDate] >= [StartDate_], [StartDate], [StartDate_] ),
        "MaxDate", IF ( [EndDate] >= [EndDate_], [EndDate_], [EndDate] )
    )
VAR t4 =
    ADDCOLUMNS ( t3, "OverlapDay", DATEDIFF ( [MinDate_], [MaxDate], DAY ) )
VAR t5 =
    ADDCOLUMNS (
        t4,
        "Count_", COUNTAX (
            FILTER (
                t4,
                [Vendor] = EARLIER ( [Vendor] )
                    && [StartDate] = EARLIER ( [StartDate] )
                    && [OverlapDay] > 0
            ),
            [Vendor]
        )
    )
RETURN
    MAXX ( t5, [Count_] + 1 )

vendor.PNG

 

For more details, please check the attached PBIX file,

 

 

Best Regards,

Icey

 

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

amitchandak
Super User
Super User

@klintala ,

You can create end date

end Date = [Start Date]+7

 

and refer to this article that can help: https://community.powerbi.com/t5/Community-Blog/HR-Analytics-Active-Employee-Hire-and-Termination-tr...

parry2k
Super User
Super User

@klintala what is the logic to get task happening at the same time?



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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