How to select range of consecutive events

  • This is my first cry for help, so be gentle with me. 🙂

    I've been searching the forum for a clue but I'm still having trouble figuring out how to produce the query results I need. and boy does it hurt my pride to say that... 🙂

    The data is fairly simple, a Station ID and a Start & End time. (along with a bunch of other data that needs to be added or dissected.)

    I have a list of events for every day and I need to identify blocks of two or more consecutive events and return the first start time and the last end time. This would also be the MIN(start) and MAX(End) of those group of consecutive events.

    I can identify the first, last and "middle" records by doing a join back to the table linking the start time of one record to the end time of the other, but I can't figure out how to group one "group" of consecutive events, as there could be multiple groups in a day.

    There are some events which are "singular", meaning that they have no adjoining records, and the group could be 2 or 20 consecutive events, and could span midnight if a show runs over.

    Here is what the sample data would look like and the output I'm trying to accomplish below that.

    I can turn all of this into a make table & insert statements if you want data to play with.

    I appreciate the help.

    Thanks,

    Tad

    StationStart End

    WKBW7/5/13 11:00 AM7/5/13 11:30 AM

    WKBW7/5/13 12:00 PM7/5/13 12:30 PM

    WKBW7/5/13 12:30 PM7/5/13 1:00 PM

    WKBW7/5/13 1:00 PM 7/5/13 1:30 PM

    WKBW7/5/13 1:30 PM 7/5/13 2:00 PM

    WKBW7/9/13 11:30 AM7/9/13 12:00 PM

    WKBW7/9/13 12:00 PM7/9/13 12:30 PM

    WKBW7/12/13 12:30 PM7/12/13 1:00 PM

    WKBW7/12/13 1:00 PM7/12/13 1:30 PM

    WKBW7/12/13 1:30 PM7/12/13 2:00 PM

    WKBW7/17/13 12:00 PM7/17/13 1:00 PM

    WKBW7/18/13 1:30 PM7/18/13 2:00 PM

    WKBW7/19/13 12:30 PM7/19/13 1:00 PM

    WKBW7/19/13 1:00 PM7/19/13 1:30 PM

    WKBW7/19/13 1:30 PM7/19/13 2:00 PM

    WKBW7/19/13 3:00 PM7/19/13 4:00 PM

    KFUN 7/22/13 4:30 AM7/22/13 7:00 AM

    KFUN 7/22/13 7:00 AM7/22/13 9:00 AM

    KFUN 7/22/13 12:00 PM7/22/13 12:30 PM

    KFUN 7/22/13 5:00 PM7/22/13 6:30 PM

    KFUN 7/23/13 4:30 AM7/23/13 7:00 AM

    KFUN 7/23/13 7:00 AM7/23/13 9:00 AM

    KFUN 7/23/13 9:30 AM7/23/13 10:00 AM

    KFUN 7/23/13 10:00 AM7/23/13 10:47 AM

    KFUN 7/23/13 10:53 AM7/23/13 11:18 AM

    KFUN 7/23/13 11:18 AM7/23/13 11:54 AM

    KFUN 7/23/13 12:00 PM7/23/13 12:30 PM

    KFUN 7/23/13 5:00 PM7/23/13 6:30 PM

    KFUN 7/23/13 9:00 PM7/23/13 10:30 PM

    KFUN 7/24/13 4:30 AM7/24/13 7:00 AM

    KFUN 7/24/13 7:00 AM7/24/13 9:00 AM

    KFUN 7/24/13 9:00 PM7/24/13 10:30 PM

    KFUN 7/25/13 4:30 AM7/25/13 7:00 AM

    KFUN 7/25/13 7:00 AM7/25/13 9:00 AM

    OUTPUT

    KFUN 7/22/13 4:30 AM7/22/13 9:00 AM

    KFUN 7/23/13 4:30 AM7/23/13 9:00 AM

    KFUN 7/23/13 9:30 AM7/23/13 10:47 AM

    KFUN 7/23/13 10:53 AM7/23/13 11:54 AM

    KFUN 7/24/13 4:30 AM7/24/13 9:00 AM

    KFUN 7/25/13 4:30 AM7/25/13 9:00 AM

    WKBW7/5/13 12:00 PM7/5/13 2:00 PM

    WKBW7/9/13 11:30 AM7/9/13 12:30 PM

    WKBW7/12/13 12:30 PM7/12/13 2:00 PM

    WKBW7/19/13 12:30 PM7/19/13 2:00 PM

  • Hi and welcome to the forums. What you are describing is generally known as gaps and islands. For finding groups of contiguous dates this article does a great job explaining how to do that.

    http://www.sqlservercentral.com/articles/T-SQL/71550/[/url]

    If you find that you need help putting all the pieces together it would be very helpful if you could post ddl and sample data.

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • Thanks for the reply Sean. I think I have read this article at one time but couldn't figure out how to apply it in this scenario. The problem is that there is nothing to unique records on or to group by. Each combination of Station + Start time will be unique, and since there could be multiple islands per day, you can't group on the date.

    Here is the ddl and sample data.

    Let me know what creative ideas you have.

    Thanks,

    Tad

    DECLARE @Events TABLE(StationID VARCHAR(10), dtmStart DateTime, dtmEnd DateTime)

    INSERT INTO @Events(StationID, dtmStart, dtmEnd)

    VALUES

    ('WKBW','7/05/13 11:00','7/05/13 11:30'),

    ('WKBW','7/05/13 12:00','7/05/13 12:30'),

    ('WKBW','7/05/13 12:30','7/05/13 13:00'),

    ('WKBW','7/05/13 13:00','7/5/13 1:30 PM'),

    ('WKBW','7/05/13 13:30','7/5/13 2:00 PM'),

    ('WKBW','7/09/13 11:30','7/09/13 12:00'),

    ('WKBW','7/09/13 12:00','7/09/13 12:30'),

    ('WKBW','7/12/13 12:30','7/12/13 13:00'),

    ('WKBW','7/12/13 13:00','7/12/13 13:30'),

    ('WKBW','7/12/13 13:30','7/12/13 14:00'),

    ('WKBW','7/17/13 12:00','7/17/13 13:00'),

    ('WKBW','7/18/13 13:30','7/18/13 14:00'),

    ('WKBW','7/19/13 12:30','7/19/13 13:00'),

    ('WKBW','7/19/13 13:00','7/19/13 13:30'),

    ('WKBW','7/19/13 13:30','7/19/13 14:00'),

    ('WKBW','7/19/13 15:00','7/19/13 16:00'),

    ('KFUN','7/22/13 04:30','7/22/13 07:00'),

    ('KFUN','7/22/13 07:00','7/22/13 09:00'),

    ('KFUN','7/22/13 12:00','7/22/13 12:30'),

    ('KFUN','7/22/13 17:00','7/22/13 18:30'),

    ('KFUN','7/23/13 04:30','7/23/13 07:00'),

    ('KFUN','7/23/13 07:00','7/23/13 09:00'),

    ('KFUN','7/23/13 09:30','7/23/13 10:00'),

    ('KFUN','7/23/13 10:00','7/23/13 10:47'),

    ('KFUN','7/23/13 10:53','7/23/13 11:18'),

    ('KFUN','7/23/13 11:18','7/23/13 11:54'),

    ('KFUN','7/23/13 12:00','7/23/13 12:30'),

    ('KFUN','7/23/13 17:00','7/23/13 18:30'),

    ('KFUN','7/23/13 21:00','7/23/13 22:30'),

    ('KFUN','7/24/13 04:30','7/24/13 07:00'),

    ('KFUN','7/24/13 07:00','7/24/13 09:00'),

    ('KFUN','7/24/13 21:00','7/24/13 22:30'),

    ('KFUN','7/25/13 04:30','7/25/13 07:00'),

    ('KFUN','7/25/13 07:00','7/25/13 09:00')

  • Thanks for the ddl and data. What I don't understand is the desired output. Since WKBW has a bit fewer rows let's look at that one.

    OUTPUT

    WKBW 7/5/13 12:00 PM 7/5/13 2:00 PM

    WKBW 7/9/13 11:30 AM 7/9/13 12:30 PM

    WKBW 7/12/13 12:30 PM 7/17/13 1:00 PM

    WKBW 7/19/13 12:30 PM 7/19/13 2:00 PM

    Not sure why your skip the first row 11am - 11:30am and start with the row that begins at noon. Do you only want groups where there are least 2 consecutive times or am I missing something?

    Also, why do you have one row that starts on 7/12 but end on 7/17? There is nothing in the data to suggest that. What about the 18th?

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • My bad on the copied output data. (I was copying from a slug of events and just manually copying start/end times for my output. The output for WKBW on 7/12 should be: WKBW 7/12/13 12:30 PM 7/12/13 2:00 PM.

    Yes, I am only wanting events which have a consecutive events, and grouping them by all of the events in that consecutive string. So any "individual" events (having no consecutive event before or after) would be ignored. If it would be easier to include them, if there is a count of events in the group then I can ignore the "groups" where there is just one event.

    Clear as mud now? 🙂

  • Try this

    WITH Starts AS (

    SELECT a.StationID,a.dtmStart,

    ROW_NUMBER() OVER(PARTITION BY a.StationID ORDER BY a.dtmStart) AS rn

    FROM @Events a

    WHERE NOT EXISTS(SELECT * FROM @Events b

    WHERE b.StationID = a.StationID

    AND b.dtmEnd = a.dtmStart)),

    Ends AS (

    SELECT a.StationID,a.dtmEnd,

    ROW_NUMBER() OVER(PARTITION BY a.StationID ORDER BY a.dtmEnd) AS rn

    FROM @Events a

    WHERE NOT EXISTS(SELECT * FROM @Events b

    WHERE b.StationID=a.StationID

    AND b.dtmStart = a.dtmEnd))

    SELECT s.StationID,s.dtmStart,e.dtmEnd

    FROM Starts s

    INNER JOIN Ends e ON e.StationID=s.StationID

    AND e.rn=s.rn

    INNER JOIN @Events t ON t.StationID=s.StationID

    AND t.dtmStart BETWEEN s.dtmStart AND e.dtmEnd

    GROUP BY s.StationID,s.dtmStart,e.dtmEnd

    HAVING COUNT(*) > 1

    ORDER BY s.StationID,s.dtmStart,e.dtmEnd;

    ____________________________________________________

    Deja View - The strange feeling that somewhere, sometime you've optimised this query before

    How to get the best help on a forum

    http://www.sqlservercentral.com/articles/Best+Practices/61537
  • Mark, IT WORKS!!!! I never would have figured that out and now I've learned a new "trick" on how to query data. Now I just have to add all of the other columns to it and then duplicate it again so I can add an additional clause to the group by.

    Thank you so much for taking the time to help me figure this out.

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

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