Home Forums SQL Server 2008 T-SQL (SS2K8) Help Required to handle multiple employees with overlapping datetimes (concurrent activities) RE: Help Required to handle multiple employees with overlapping datetimes (concurrent activities)

  • Sorry there my friend. I gave you the wrong link. Fortunately I saved a script with this incredibly elegant technique by SQL guru/MVP Itzik Ben-Gan.

    DECLARE @T TABLE

    (DKey INT, EmployeeId INT, LoginTime TIME, LogOutTime TIME)

    INSERT INTO @T

    SELECT 8,501,'07:13:13','07:18:04'

    UNION ALL SELECT 9,501,'07:13:13','07:13:26'

    UNION ALL SELECT 10,501,'08:35:56','08:36:20'

    UNION ALL SELECT 11,501,'08:35:56','09:00:00'

    UNION ALL SELECT 12,501,'14:08:08','18:30:26'

    UNION ALL SELECT 12,501,'15:45:25','18:30:32'

    SELECT *

    FROM @T

    -- Method by Itzik Ben-Gan

    -- http://www.solidq.com/sqj/Pages/2011-March-Issue/Packing-Intervals.aspx

    ;WITH C1 AS (

    SELECT EmployeeId, ts, Type

    ,e=CASE Type WHEN 1 THEN NULL ELSE ROW_NUMBER() OVER (PARTITION BY EmployeeId, Type ORDER BY LogoutTime) END

    ,s=CASE Type WHEN -1 THEN NULL ELSE ROW_NUMBER() OVER (PARTITION BY EmployeeId, Type ORDER BY LoginTime) END

    FROM @T

    CROSS APPLY (

    VALUES (1, LoginTime), (-1, LogoutTime)) a(Type, ts)

    ),

    C2 AS (

    SELECT C1.*

    ,se=ROW_NUMBER() OVER (PARTITION BY EmployeeId ORDER BY ts, Type DESC)

    FROM C1),

    C3 AS (

    SELECT EmployeeId, ts

    ,grpnm=FLOOR((ROW_NUMBER() OVER (PARTITION BY EmployeeId ORDER BY ts)-1) / 2 + 1)

    FROM C2

    WHERE COALESCE(s-(se-s)-1, (se-e)-e) = 0)

    SELECT EmployeeId, StartDate=MIN(ts), EndDate=MAX(ts)

    FROM C3

    GROUP BY EmployeeId, grpnm

    The link to his article is in the code.


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St