Querying two time columns for sum of datediff

  • Hi,

    I have a table with two columns of datetime. The first is considered the 'startdate' and the second the 'enddate' time.

    I want to capture the SUM of the DATEDIFF between all the ons to off and can do so by:

    SELECT ISNULL(SUM(DATEDIFF(second,startdate,enddate) /60.0),0)

    WHERE startdate > xxxx and enddate < xxxxx

    Is there a way to do the same but take into account should the start or end date (xxxx) for the query cross a record. I.e. if the start date for the query was 0101/12 10:00 and there is a row of

    startdate: 0101/12 08:00 enddate 0101/12 12:00

    this row would be ignored but I would want the 2 hours 10-12 to be included, same would apply for an overlap on the end date. (just to complicate things the query would need to be able to handle the start xxxx and end xxx both being in the 'middle' of one row and returning basically the DATEDIFF of start xxxx and end xxx as the result.

    Any shove in the right direction welcome 🙂

  • DECLARE @T TABLE

    (StartDate DATETIME,

    EndDate DATETIME,

    Comments VARCHAR(255));

    INSERT INTO @T VALUES ('2013-01-01 08:00', '2013-01-01 16:00', 'Overlapping Both Ends');

    INSERT INTO @T VALUES ('2013-01-01 08:00', '2013-01-01 12:00', 'Overlapping Front');

    INSERT INTO @T VALUES ('2013-01-01 13:00', '2013-01-01 18:00', 'Overlapping End');

    INSERT INTO @T VALUES ('2013-01-01 11:00', '2013-01-01 13:00', 'Not Overlapping');

    DECLARE @StartDate DATETIME = '2013-01-01 10:00',

    @EndDate DATETIME = '2013-01-01 14:00';

    SELECT

    SUM(CASE

    WHEN StartDate < @StartDate AND EndDate > @EndDate THEN DATEDIFF(SECOND, @StartDate, @EndDate)

    WHEN StartDate >= @StartDate AND EndDate <= @EndDate THEN DATEDIFF(SECOND, StartDate, EndDate)

    WHEN StartDate < @StartDate THEN DATEDIFF(SECOND, @StartDate, EndDate)

    WHEN EndDate > @EndDate THEN DATEDIFF(SECOND, StartDate, @EndDate)

    END * 60.)

    FROM

    @T;

    The SQL Guy @ blogspot[/url]

    @SeanPearceSQL

    About Me[/url]

  • Sean,

    That is absolutely brilliant. Thank you so much. I should have tried this forum before wasting around 3 days and getting nowhere!!!!!! I have modified the code with some extras to suit the last row where the off time has not net been recored.

    DECLARE @T TABLE

    (StartDate DATETIME,

    EndDate DATETIME,

    Comments VARCHAR(255));

    INSERT INTO @T VALUES ('2013-01-01 01:00', '2013-01-01 04:00', 'Not needed');

    INSERT INTO @T VALUES ('2013-01-01 08:00', '2013-01-01 16:00', 'Overlapping Both Ends');

    INSERT INTO @T VALUES ('2013-01-01 08:00', '2013-01-01 12:00', 'Overlapping Front');

    INSERT INTO @T VALUES ('2013-01-01 13:00', '2013-01-01 18:00', 'Overlapping End');

    INSERT INTO @T VALUES ('2013-01-01 11:00', '2013-01-01 13:00', 'Not Overlapping');

    INSERT INTO @T VALUES ('2013-01-01 11:00', NULL, 'Not Overlapping');

    INSERT INTO @T VALUES ('2013-01-01 16:00', '2013-01-01 20:00', 'Not needed');

    DECLARE @StartDate DATETIME

    SET @StartDate = '2013-01-01 10:00'

    DECLARE @EndDate DATETIME

    SET @EndDate= '2013-01-01 14:00';

    SELECT

    SUM(CASE

    WHEN StartDate < @StartDate AND EndDate > @EndDate THEN DATEDIFF(SECOND, @StartDate, @EndDate)--Area4

    WHEN StartDate >= @StartDate AND EndDate <= @EndDate THEN DATEDIFF(SECOND, StartDate, EndDate)

    WHEN StartDate < @StartDate AND EndDate < @EndDate AND EndDate > @StartDate THEN DATEDIFF(SECOND, @StartDate, EndDate)

    WHEN StartDate > @StartDate AND StartDate < @EndDate AND EndDate > @EndDate THEN DATEDIFF(SECOND, StartDate, @EndDate)

    WHEN StartDate > @StartDate AND EndDate IS NULL THEN DATEDIFF(SECOND, StartDate, @Enddate)

    WHEN StartDate < @StartDate AND EndDate IS NULL THEN DATEDIFF(SECOND, @StartDate, @Enddate)

    END / 60.)

    FROM

    @T;

    Thanks again Sean.

  • You are welcome.

    You can also use ISNULL instead of creating a new condition.

    DECLARE @T TABLE

    (StartDate DATETIME,

    EndDate DATETIME,

    Comments VARCHAR(255));

    INSERT INTO @T VALUES ('2013-01-01 01:00', '2013-01-01 04:00', 'Not needed');

    INSERT INTO @T VALUES ('2013-01-01 08:00', '2013-01-01 16:00', 'Overlapping Both Ends');

    INSERT INTO @T VALUES ('2013-01-01 08:00', '2013-01-01 12:00', 'Overlapping Front');

    INSERT INTO @T VALUES ('2013-01-01 13:00', '2013-01-01 18:00', 'Overlapping End');

    INSERT INTO @T VALUES ('2013-01-01 11:00', '2013-01-01 13:00', 'Not Overlapping');

    INSERT INTO @T VALUES ('2013-01-01 11:00', NULL, 'Not Overlapping');

    INSERT INTO @T VALUES ('2013-01-01 16:00', '2013-01-01 20:00', 'Not needed');

    DECLARE @StartDate DATETIME

    SET @StartDate = '2013-01-01 10:00'

    DECLARE @EndDate DATETIME

    SET @EndDate= '2013-01-01 14:00';

    SELECT

    SUM(CASE

    WHEN StartDate < @StartDate AND ISNULL(EndDate, '2099-12-31') > @EndDate THEN DATEDIFF(SECOND, @StartDate, @EndDate)--Area4

    WHEN StartDate >= @StartDate AND EndDate <= @EndDate THEN DATEDIFF(SECOND, StartDate, EndDate)

    WHEN StartDate < @StartDate AND EndDate < @EndDate AND EndDate > @StartDate THEN DATEDIFF(SECOND, @StartDate, EndDate)

    WHEN StartDate > @StartDate AND StartDate < @EndDate AND ISNULL(EndDate, '2099-12-31') > @EndDate THEN DATEDIFF(SECOND, StartDate, @EndDate)

    END / 60.)

    FROM

    @T;

    The SQL Guy @ blogspot[/url]

    @SeanPearceSQL

    About Me[/url]

Viewing 4 posts - 1 through 3 (of 3 total)

You must be logged in to reply to this topic. Login to reply