SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Group by with min and max dates


Group by with min and max dates

Author
Message
cidr
cidr
SSC-Addicted
SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)

Group: General Forum Members
Points: 498 Visits: 273
Hi All and Merry Christmas!
I have what I thought was a simple requirement.

I have to modify a table that has three columns (for simplicity sake I'll use the following made up columns)
Name, shift, sundayshift_date. This example is based on shift work that employees do each sunday and they can have morning, afternoon or late shift. I'd want to find the min and max date for the contigous blocks of shift work they do in a row. Here's an example.

This displays Graham working three Lates in a row and then a morning the following week. The second table (which is what I want to achieve) displays the 3 weeks contiguous Late shift as start and end dates.

Name shift_type sunday_shift_date
Graham Late 22/10/2017
Graham Late 29/10/2017
Graham Late 05/11/2017
Graham Morning 12/11/2017
Graham Afternoon 19/11/2017
Graham Afternoon 26/11/2017
Graham Afternoon 03/12/2017
Tracy Late 10/12/2017
Tracy Late 17/12/2017



name Shift From To
Graham Late 22/10/2017 05/11/2017
Graham Late 12/11/2017 12/11/2017
Graham Late 19/11/2017 03/12/2017
Tracy ...... (and so on)


Obviously this code wont work a it just group the dates together ignoring the contiguous date blocks

SELECT
name ,
Shift,
MIN(sunday_shift_date) fromdate,
MAX(sunday_shift_date) todate
FROM
tblShift
GROUP BY name, Shift


Any help with this would be appreciated, perhaps you have old code lying around that does this??
Thanks


Thom A
Thom A
SSC-Forever
SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)

Group: General Forum Members
Points: 46226 Visits: 15719
Why is the 2nd and 3rd entries for Graham Late? I would have expected these to be Morning and Afternoon respectively.


Thom~
Excuse my typos and sometimes awful grammar. My fingers work faster than my brain does :-P

Please always remember to encapsulate your code in IFCode Markup. For example [code=sql] [/code].
Click here to read Jeffs Guide on how to post SQL questions, and get swift and helpful answers from the community
cidr
cidr
SSC-Addicted
SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)

Group: General Forum Members
Points: 498 Visits: 273
Thom A - Tuesday, December 26, 2017 8:20 AM
Why is the 2nd and 3rd entries for Graham Late? I would have expected these to be Morning and Afternoon respectively.

Hi, it means that Graham has worked the Late shift consecutively three weeks in a row. On the following week he has worked on the morning shift and so on.
The first three weeks should be grouped as they are consecutive late shifts. The morning shift should be a row on it's own.

Hope that makes sense.

Thom A
Thom A
SSC-Forever
SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)

Group: General Forum Members
Points: 46226 Visits: 15719
No, this doesn't make sense. The 2nd entry in your expected result set states Late 12/11/2012, however, in your first dataset it's morning on 12/11/2017. Can you provide a full expected result set, as "and so on" doesn't give us enough to represent values other than Late.

Thanks.


Thom~
Excuse my typos and sometimes awful grammar. My fingers work faster than my brain does :-P

Please always remember to encapsulate your code in IFCode Markup. For example [code=sql] [/code].
Click here to read Jeffs Guide on how to post SQL questions, and get swift and helpful answers from the community
cidr
cidr
SSC-Addicted
SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)

Group: General Forum Members
Points: 498 Visits: 273
Thom A - Tuesday, December 26, 2017 8:29 AM
No, this doesn't make sense. The 2nd entry in your expected result set states Late 12/11/2012, however, in your first dataset it's morning on 12/11/2017. Can you provide a full expected result set, as "and so on" doesn't give us enough to represent values other than Late.

Thanks.

OOps my bad -


name  Shift         From          To
Graham Late 22/10/2017 05/11/2017
Graham Morning 12/11/2017 12/11/2017
Graham Afternoon 19/11/2017 03/12/2017

Tracy ...... (and so on)


Sorry about that

cidr
cidr
SSC-Addicted
SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)

Group: General Forum Members
Points: 498 Visits: 273
To keep it a bit more simple, let's just stick with Graham



name shift_type sunday_shift_date
Graham Late 22/10/2017
Graham Late 29/10/2017
Graham Late 05/11/2017
Graham Morning 12/11/2017
Graham Afternoon 19/11/2017
Graham Afternoon 26/11/2017
Graham Afternoon 03/12/2017
Graham Late 10/12/2017
Graham Late 17/12/2017


--Expected
name Shift From To
Graham Late 22/10/2017 05/11/2017
Graham Morning 12/11/2017 12/11/2017
Graham Afternoon 19/11/2017 03/12/2017
Graham Late 10/12/2017 17/12/2017

drew.allen
drew.allen
SSC-Dedicated
SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)SSC-Dedicated (37K reputation)

Group: General Forum Members
Points: 37094 Visits: 13737
This is a fairly straitforward gaps and islands problem. Here is a solution. There may also be a solution with LAG, but I don't have access to a SQL 2012 environment right now to test it.

I've set up your table using a TABLE VALUE CONSTRUCTOR. You'll want to replace that with your actual table.

WITH shift_groups AS
(
SELECT *,
grp = ROW_NUMBER() OVER(PARTITION BY [name] ORDER BY dt, shift_type)
- ROW_NUMBER() OVER(PARTITION BY [name], shift_type ORDER BY dt)
FROM
(
VALUES
('Graham', 'Late', '22/10/2017')
, ('Graham', 'Late', '29/10/2017')
, ('Graham', 'Late', '05/11/2017')
, ('Graham', 'Morning', '12/11/2017')
, ('Graham', 'Afternoon', '19/11/2017')
, ('Graham', 'Afternoon', '26/11/2017')
, ('Graham', 'Afternoon', '03/12/2017')
, ('Graham', 'Late', '10/12/2017')
, ('Graham', 'Late', '17/12/2017')
) m([name], shift_type, sunday_shift_date)
CROSS APPLY (VALUES(CONVERT(DATE, sunday_shift_date, 103))) dt(dt)
)
SELECT [name], shift_type, MIN(dt), MAX(dt)
FROM shift_groups
GROUP BY [name], shift_type, grp
ORDER BY [name], MIN(dt)


Drew


J. Drew Allen
Business Intelligence Analyst
Philadelphia, PA
How to post data/code on a forum to get the best help.
How to Post Performance Problems
Make sure that you include code in the appropriate IFCode tags, e.g. [code=sql]<your code here>[/code]. You can find the IFCode tags under the INSERT options when you are writing a post.
cidr
cidr
SSC-Addicted
SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)SSC-Addicted (498 reputation)

Group: General Forum Members
Points: 498 Visits: 273
drew.allen - Tuesday, December 26, 2017 9:49 AM
This is a fairly straitforward gaps and islands problem. Here is a solution. There may also be a solution with LAG, but I don't have access to a SQL 2012 environment right now to test it.

I've set up your table using a TABLE VALUE CONSTRUCTOR. You'll want to replace that with your actual table.

WITH shift_groups AS
(
SELECT *,
grp = ROW_NUMBER() OVER(PARTITION BY [name] ORDER BY dt, shift_type)
- ROW_NUMBER() OVER(PARTITION BY [name], shift_type ORDER BY dt)
FROM
(
VALUES
('Graham', 'Late', '22/10/2017')
, ('Graham', 'Late', '29/10/2017')
, ('Graham', 'Late', '05/11/2017')
, ('Graham', 'Morning', '12/11/2017')
, ('Graham', 'Afternoon', '19/11/2017')
, ('Graham', 'Afternoon', '26/11/2017')
, ('Graham', 'Afternoon', '03/12/2017')
, ('Graham', 'Late', '10/12/2017')
, ('Graham', 'Late', '17/12/2017')
) m([name], shift_type, sunday_shift_date)
CROSS APPLY (VALUES(CONVERT(DATE, sunday_shift_date, 103))) dt(dt)
)
SELECT [name], shift_type, MIN(dt), MAX(dt)
FROM shift_groups
GROUP BY [name], shift_type, grp
ORDER BY [name], MIN(dt)


Drew

This is brilliant Drew! spot on solution and thanks so much!!

Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (226K reputation)SSC Guru (226K reputation)SSC Guru (226K reputation)SSC Guru (226K reputation)SSC Guru (226K reputation)SSC Guru (226K reputation)SSC Guru (226K reputation)SSC Guru (226K reputation)

Group: General Forum Members
Points: 226373 Visits: 40443

So, is this what you are looking for?


IF OBJECT_ID('dbo.TestTable','U') IS NOT NULL
DROP TABLE [dbo].[TestTable];

CREATE TABLE [dbo].[TestTable](
[name] VARCHAR(30)
, [ShiftType] VARCHAR(30)
, [SundayShiftDate] DATE);

INSERT INTO [dbo].[TestTable]([name],[ShiftType],[SundayShiftDate])
VALUES ('Graham','Late','2017-10-22')
,('Graham','Late','2017-10-29')
,('Graham','Late','2017-11-05')
,('Graham','Morning','2017-11-12')
,('Graham','Afternoon','2017-11-19')
,('Graham','Afternoon','2017-11-26')
,('Graham','Afternoon','2017-12-03')
,('Graham','Late','2017-12-10')
,('Graham','Late','2017-12-17');

SELECT [tt].[name], [tt].[ShiftType], [tt].[SundayShiftDate] FROM [dbo].[TestTable] AS [tt];

WITH base AS (
SELECT
[tt].[name]
, [tt].[ShiftType]
, [tt].[SundayShiftDate]
, [rn] = ROW_NUMBER() OVER (PARTITION BY [tt].[name], [tt].[ShiftType] ORDER BY [tt].[SundayShiftDate])
FROM
[dbo].[TestTable] AS [tt]
), Interim AS (
SELECT
[b].[name]
, [b].[ShiftType]
, [b].[SundayShiftDate]
, [GroupDate] = DATEADD(DAY,-(7 * [rn]), [b].[SundayShiftDate])
FROM
[base] AS [b]
)
SELECT
[i].[name]
, [i].[ShiftType]
, [From] = MIN([i].[SundayShiftDate])
, [To] = MAX([i].[SundayShiftDate])
FROM
[Interim] AS [i]
GROUP BY
[i].[name]
, [i].[ShiftType]
, [i].[GroupDate]
ORDER BY
[i].[name]
, MIN([i].[GroupDate]);



Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum








































































































































































SQLServerCentral


Search