query to find timgaps between rows

  • Basically I want missing timegaps between the @startdate and @enddate

    with tbl_book and also in between tbl_book (do not care about the bookid column in the resultset)

    ---------------------------------

    CREATE TABLE [dbo].[book](

    [bookid] [int] IDENTITY(1,1),

    [starttime] [datetime] NULL,

    [endtime] [datetime] NULL

    ) ON [PRIMARY]

    GO

    INSERT INTO [dbo].[book] ('2013-03-05 16:30:00.000','2013-03-05 16:45:00.000')

    INSERT INTO [dbo].[book] ('2013-03-05 17:30:00.000','2013-03-05 17:45:00.000')

    declare @startdate datetime

    set @startdate='2013-03-05 16:00:00.000'

    declare @enddate datetime

    set @enddate='2013-03-05 19:00:00.000';

    Resultset may look like:

    AvailableStart_time AvailableEnd_time

    ---------------------- ----------------------------

    2013-03-05 16:00:00.000 2013-03-05 16:30:00.000

    2013-03-05 16:45:00.000 2013-03-05 17:30:00.000

    2013-03-05 17:45:00.000 2012-03-05 19:00:00.000

  • Your data was going to drive me crazy, until I realized that there was an error on the year for the variables.

    This is what I did:

    First, I created a "table" with all the dates including the limits established by the variables.

    Then, I generated a new ID to avoid gaps between rows and ensure the correct order.

    Finally, there's a self join to obtain the timegaps between one row and another and eliminated the rows with no gaps between them. There's an easier solution on 2012, but I'm not posting it since you used the 2008 forum.

    WITH AllDates AS(

    SELECT starttime, endtime

    FROM dbo.book

    UNION ALL

    SELECT @startdate, @startdate

    UNION ALL

    SELECT @enddate, @enddate),

    ContinuousIDs AS(

    SELECT *, ROW_NUMBER() OVER( ORDER BY starttime) row_id

    FROM AllDates)

    SELECT c1.endtime, c2.starttime

    FROM ContinuousIDs c1

    JOIN ContinuousIDs c2 ON c1.row_id +1 = c2.row_id

    WHERE DATEDIFF( MINUTE, c1.endtime, c2.starttime) > 0

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • Thanks so much

  • Thanks so much, i progressed a lot with your inputs, but now i need to loop this whole thing with a table that has multiple startdate and enddate instead of previous question where it was one variable value.

    create table [vendor_sched]

    ([id] [int] IDENTITY(1,1) NOT NULL,

    [FromTime] [varchar](10) NULL,

    [ToTime] [varchar](10) NULL,

    [vendorid] [int] NOT NULL,

    [schedid] [int] NULL)---in a day multiple schedule

    INSERT INTO vendor_sched VALUES('2013-04-03 14:00:00.000','2013-04-03 16:00:00.000',4,1)

    INSERT INTO vendor_sched VALUES('2013-04-04 17:00:00.000','2013-04-04 19:00:00.000',4,2)

    INSERT INTO vendor_sched VALUES('2013-04-04 15:00:00.000','2013-04-04 16:00:00.000',5,1)

    INSERT INTO vendor_sched VALUES('2013-04-04 17:00:00.000','2013-04-04 19:00:00.000',5,2)

    CREATE TABLE [dbo].[book](

    [bookid] [int] IDENTITY(1,1),

    [starttime] [datetime] NULL,

    [endtime] [datetime] NULL,

    [customerid] [int] NULL,

    [vendorid] [int] NULL,

    [timeslotid] [int] NULL,

    ) ON [PRIMARY]

    GO

    INSERT INTO [dbo].[book] VALUES ('2013-04-03 14:00:00.000','2013-04-03 14:30:00.000',100,4,1)

    INSERT INTO [dbo].[book] VALUES ('2013-04-04 18:00:00.000','2013-04-04 18:30:00.000',101,4,2)

    INSERT INTO [dbo].[book] VALUES ('2013-04-04 15:30:00.000','2013-04-04 15:45:00.000',100,5,1)

    Resultset

    --------------

    [vendor_sched].Fromtime [vendor_sched].totime vendorid schedid [book].starttime[book].endtime customerid

    -------------------------------------------------------------------------------------------------------------------------------

    2013-04-03 14:00:00.000 2013-04-03 16:00:00.000 4 1 2013-04-03 14:00:00.000 2013-04-03 14:30:00.000 100

    2013-04-03 14:00:00.000 2013-04-03 16:00:00.000 4 1 2013-04-03 14:30:00.000 2013-04-03 16:00:00.000 NULL

    2013-04-04 17:00:00.000 2013-04-04 19:00:00.000 4 2 2013-04-04 17:00:00.000 2013-04-04 18:00:00.000 NULL

    2013-04-04 17:00:00.000 2013-04-04 19:00:00.000 4 2 2013-04-04 18:00:00.000 2013-04-04 18:30:00.000 101

    2013-04-04 17:00:00.000 2013-04-04 19:00:00.000 4 2 2013-04-04 18:30:00.000 2013-04-04 19:00:00.000 NULL

  • I'm willing to help you (as a matter of fact, I already have a solution for you). However, I want you to show me what have you done so far. I'd like to know what are the problems that you're having.

    There's a problem with your vendor_sched definition because you're using varchar instead of datetime columns.

    The problem you're posting now is a bit different from the original as you don't need only the free spaces, you also need the booked spaces. As a hint, I can tell you that you need more rows and less columns.

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • The definition was a typo, actually it is in a table with datetime columns.

    Your previous day code works fine with specified vendorid and specified schedid, but i am having trouble getting the resultset for ALL matching vendorid and schedid in the Book table.

    Right now I am trying to only find the free spaces for only the dates there were bookings for matching vendor and schedid.I can do an union all at the end with this (free spaces) resultset to display free and booked spaces for all vendorid and schedids ,hope it makes sense to you.

  • Maybe we're thinking a little bit different. Here's the solution I came with and a possible improvement using a temp table. If you're going to filter your information remember to do it during the load of the data into the CTE or temp table and not after.

    --CTE Version

    WITH AllDates AS(

    SELECT starttime, vendorid, timeslotid, customerid

    FROM dbo.book

    UNION ALL

    SELECT endtime, vendorid, timeslotid, NULL

    FROM dbo.book

    UNION ALL

    SELECT FromTime, vendorid, schedid, NULL

    FROM vendor_sched

    UNION ALL

    SELECT ToTime, vendorid, schedid, NULL

    FROM vendor_sched

    ),

    ContinuousIDs AS(

    SELECT *, ROW_NUMBER() OVER( ORDER BY vendorid, timeslotid, starttime, customerid) row_id

    FROM AllDates)

    SELECT MIN( c1.starttime) OVER(PARTITION BY c1.vendorid, c1.timeslotid) AS SchedStartTime,

    MAX( c2.starttime) OVER(PARTITION BY c1.vendorid, c1.timeslotid) AS SchedEndTime,

    c1.VendorId,

    c1.timeslotid AS SchedId,

    c1.starttime AS StartTime,

    c2.starttime AS EndTime,

    c1.CustomerId

    FROM ContinuousIDs c1

    JOIN ContinuousIDs c2 ON c1.row_id +1 = c2.row_id AND c1.vendorid = c2.vendorid AND c1.timeslotid = c2.timeslotid

    WHERE DATEDIFF( MINUTE, c1.starttime, c2.starttime) > 0

    --Temp table version

    CREATE TABLE #Temp(

    rowid int IDENTITY,

    starttimedatetime,

    vendoridint,

    timeslotidint,

    customeridint,

    CONSTRAINT PK_Temp PRIMARY KEY( rowid, vendorid, timeslotid))

    INSERT INTO #Temp

    SELECT starttime, vendorid, timeslotid, customerid

    FROM dbo.book

    UNION ALL

    SELECT endtime, vendorid, timeslotid, NULL

    FROM dbo.book

    UNION ALL

    SELECT FromTime, vendorid, schedid, NULL

    FROM vendor_sched

    UNION ALL

    SELECT ToTime, vendorid, schedid, NULL

    FROM vendor_sched

    ORDER BY vendorid, timeslotid, starttime, customerid;

    SELECT MIN( c1.starttime) OVER(PARTITION BY c1.vendorid, c1.timeslotid) AS SchedStartTime,

    MAX( c2.starttime) OVER(PARTITION BY c1.vendorid, c1.timeslotid) AS SchedEndTime,

    c1.VendorId,

    c1.timeslotid AS SchedId,

    c1.starttime AS StartTime,

    c2.starttime AS EndTime,

    c1.CustomerId

    FROM #Temp c1

    JOIN #Temp c2 ON c1.rowid +1 = c2.rowid AND c1.vendorid = c2.vendorid AND c1.timeslotid = c2.timeslotid

    WHERE DATEDIFF( MINUTE, c1.starttime, c2.starttime) > 0

    DROP TABLE #Temp

    Remember to test and understand every part of the code before implementing it. If you have more questions, feel free to ask them.

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2

Viewing 7 posts - 1 through 6 (of 6 total)

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