Create Date Ranges for Consecutive dates in a SQL Server Table

I had recently posted a SQL script to SQL Query to Find out who attended office on Saturday

Shashi commented asking it was possible to create Date Range for all consecutive dates and group them together in such queries. Here is a query to group all the consecutive dates together and create a range out of them.

SAMPLE DATA

DECLARE @TT TABLE (EID int, CheckIn DATETIME)
INSERT INTO @TT VALUES (2, 'April 02, 2010 11:25am')
INSERT INTO @TT VALUES (4, 'April 03, 2010 9:55am')
INSERT INTO @TT VALUES (5, 'April 07, 2010 11:24am')
INSERT INTO @TT VALUES (2, 'April 10, 2010 11:22am')
INSERT INTO @TT VALUES (3, 'April 15, 2010 5:27am')
INSERT INTO @TT VALUES (6, 'April 16, 2010 8:21am')
INSERT INTO @TT VALUES (7, 'April 17, 2010 11:55am')
INSERT INTO @TT VALUES (3, 'April 22, 2010 10:16am')
INSERT INTO @TT VALUES (4, 'April 24, 2010 11:35am')
INSERT INTO @TT VALUES (7, 'April 30, 2010 9:49pm')
INSERT INTO @TT VALUES (2, 'May 01, 2010 9:49am')
INSERT INTO @TT VALUES (5, 'May 02, 2010 10:43am')
INSERT INTO @TT VALUES (3, 'May 03, 2010 11:29am')

QUERY

SELECT MIN(CheckIn) AS BeginRange,
MAX(CheckIn) AS EndRange
FROM (
SELECT CheckIn,
DATEDIFF(D, ROW_NUMBER() OVER(ORDER BY CheckIn), CheckIn) AS DtRange
FROM @TT) AS dt
GROUP BY DtRange;

OUTPUT

Date Range SQL Server


About The Author

Suprotim Agarwal, MCSD, MCAD, MCDBA, MCSE, is the founder of DotNetCurry, DNC Magazine for Developers, SQLServerCurry and DevCurry. He has also authored a couple of books 51 Recipes using jQuery with ASP.NET Controls and a new one recently at The Absolutely Awesome jQuery CookBook.

Suprotim has received the prestigous Microsoft MVP award for nine times in a row now. In a professional capacity, he is the CEO of A2Z Knowledge Visuals Pvt Ltd, a digital group that represents premium web sites and digital publications comprising of Professional web, windows, mobile and cloud developers, technical managers, and architects.

Get in touch with him on Twitter @suprotimagarwal, LinkedIn or befriend him on Facebook

5 comments:

Martin said...

What about this?
This a little bit tricky using NTILE, but split into begin and end range interval.


select min(checkin) as b,
max(checkin) as e

from
(
SELECT CheckIn,
ntile((select (count(*)+1) / 2 from @TT) ) OVER(ORDER BY CheckIn) AS DtRange

FROM @TT) as dt
group by dtrange


Useful?

Jiba said...

Nice work Martin. Did you check the execution plan to see which performs better?

Martin said...

No,
my motivation was a non-logic output.
Why is 2010/04/02 - 03 and 2010/04/07 is alone? And where is 2010/04/16?

I updated my script due small bug.

select min(checkin) as b,
max(checkin) as e
from
(
SELECT CheckIn,
ntile((select (count(*) / 2)+1 from @TT) ) OVER(ORDER BY CheckIn) AS DtRange

FROM @TT
) as dt
group by dtrange

My execution plan costs 12% relative to batch. Original shows 17%.

Martin

Jiba said...

bug? I think the poster mentions that the query 'groups all the consecutive dates together '

and where is 2010/04/02 - 03 alone? It is grouped together.
2010/04/07 and 10 are alone because they do not have any consecutve dates.

Am I missing your point here? Anyways nice query again.

Martin said...

Sorry, it was my mistake. Translations "consecutive" into czech has many variants.

Ok, consecutive means days after day without no day omision.
From Monday to Wednesday if Tuesday I was also in work.

I understood consecutive as a
"first is input", "second one is output".
(funny how misunderstood can produce brand new approach in querying).

Keep coding..