Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


T-SQl help...


T-SQl help...

Author
Message
hunchback
hunchback
SSC-Enthusiastic
SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)

Group: General Forum Members
Points: 117 Visits: 639
This problem is known as "Finding Islands", but this case is a special one because there is no other column that we could use to break ties based on (CID, cDate) other than column [Dept].

I added one more column, an identity one, to break this tie, and here is the code.


SET NOCOUNT ON;
USE tempdb;
GO
CREATE TABLE #tTable(
sk int NOT NULL IDENTITY UNIQUE CLUSTERED,
CID INT,
CDate DATETIME,
Dept VARCHAR(10)
);

INSERT INTO #tTable(CID, CDate, Dept)
VALUES
(111, '2012-10-05 00:00:00.000','A'),
(111, '2012-10-18 00:00:00.000','C'),
(111, '2012-11-01 00:00:00.000','B'),
(111, '2012-11-01 00:00:00.000','C'),
(111, '2012-11-20 00:00:00.000','C'),
(111, '2012-12-09 00:00:00.000','C'),
(111, '2012-12-11 00:00:00.000','A'),
(111, '2013-02-21 00:00:00.000','B'),
(111, '2013-03-22 00:00:00.000','B'),
(111, '2013-03-22 00:00:00.000','C'),
(111, '2013-04-12 00:00:00.000','C'),
(111, '2013-04-26 00:00:00.000','B'),
(111, '2013-04-26 00:00:00.000','C'),
(222, '2012-02-13 00:00:00.000','C'),
(222, '2012-03-02 00:00:00.000','B'),
(222, '2012-06-16 00:00:00.000','C'),
(222, '2012-07-12 00:00:00.000','C'),
(222, '2013-04-26 00:00:00.000','B'),
(222, '2013-05-23 00:00:00.000','C'),
(222, '2013-07-11 00:00:00.000','C'),
(222, '2013-09-19 00:00:00.000','C'),
(222, '2013-09-20 00:00:00.000','A'),
(444, '2013-01-14 00:00:00.000','C'),
(444, '2013-02-14 00:00:00.000','C'),
(444, '2013-03-14 00:00:00.000','B'),
(444, '2013-04-14 00:00:00.000','C'),
(444, '2013-05-14 00:00:00.000','C');

WITH C1 AS (
SELECT
CID,
CDate,
Dept,
DENSE_RANK() OVER(PARTITION BY CID ORDER BY CDate, sk) -
DENSE_RANK() OVER(PARTITION BY CID ORDER BY Dept, CDate, sk) AS grp
FROM
#tTable
)
, C2 AS (
SELECT
CID,
grp,
MIN(cDate) dt
FROM
C1
GROUP BY
CID, grp
HAVING
SUM(CASE WHEN Dept <> 'C' THEN 1 ELSE 0 END) = 0
AND COUNT(*) > 1
)
SELECT
A.CID,
A.cDate,
A.Dept,
DENSE_RANK() OVER(PARTITION BY B.CID ORDER BY B.dt) AS grpnum
FROM
C1 AS A
INNER JOIN
C2 AS B
ON B.CID = A.CID
AND B.grp = A.grp
ORDER BY
A.CID, A.CDate;
GO
DROP TABLE #tTable
GO

/*
Result

CID cDate Dept grpnum
111 2012-11-01 00:00:00.000 C 1
111 2012-11-20 00:00:00.000 C 1
111 2012-12-09 00:00:00.000 C 1
111 2013-03-22 00:00:00.000 C 2
111 2013-04-12 00:00:00.000 C 2
222 2012-06-16 00:00:00.000 C 1
222 2012-07-12 00:00:00.000 C 1
222 2013-05-23 00:00:00.000 C 2
222 2013-07-11 00:00:00.000 C 2
222 2013-09-19 00:00:00.000 C 2
444 2013-01-14 00:00:00.000 C 1
444 2013-02-14 00:00:00.000 C 1
444 2013-04-14 00:00:00.000 C 2
444 2013-05-14 00:00:00.000 C 2

*/




The idea is to enumerate rows based on two criteria that together will yield a group number. Then you need to solve a second problem known as Relational Division.


You can learn more about solving this problem, in the last book from Itzik Ben-Gan about T-SQL Querying.

Inside Microsoft® SQL Server® 2008: T-SQL Querying



dwain.c
dwain.c
SSCarpal Tunnel
SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)SSCarpal Tunnel (4.2K reputation)

Group: General Forum Members
Points: 4249 Visits: 6431
Not sure but perhaps this is a simpler approach?


CREATE TABLE #tTable(
sk int NOT NULL IDENTITY UNIQUE CLUSTERED,
CID INT,
CDate DATETIME,
Dept VARCHAR(10)
);

INSERT INTO #tTable(CID, CDate, Dept)
VALUES
(111, '2012-10-05 00:00:00.000','A'),
(111, '2012-10-18 00:00:00.000','C'),
(111, '2012-11-01 00:00:00.000','B'),
(111, '2012-11-01 00:00:00.000','C'),
(111, '2012-11-20 00:00:00.000','C'),
(111, '2012-12-09 00:00:00.000','C'),
(111, '2012-12-11 00:00:00.000','A'),
(111, '2013-02-21 00:00:00.000','B'),
(111, '2013-03-22 00:00:00.000','B'),
(111, '2013-03-22 00:00:00.000','C'),
(111, '2013-04-12 00:00:00.000','C'),
(111, '2013-04-26 00:00:00.000','B'),
(111, '2013-04-26 00:00:00.000','C'),
(222, '2012-02-13 00:00:00.000','C'),
(222, '2012-03-02 00:00:00.000','B'),
(222, '2012-06-16 00:00:00.000','C'),
(222, '2012-07-12 00:00:00.000','C'),
(222, '2013-04-26 00:00:00.000','B'),
(222, '2013-05-23 00:00:00.000','C'),
(222, '2013-07-11 00:00:00.000','C'),
(222, '2013-09-19 00:00:00.000','C'),
(222, '2013-09-20 00:00:00.000','A'),
(444, '2013-01-14 00:00:00.000','C'),
(444, '2013-02-14 00:00:00.000','C'),
(444, '2013-03-14 00:00:00.000','B'),
(444, '2013-04-14 00:00:00.000','C'),
(444, '2013-05-14 00:00:00.000','C');

WITH GroupedRows AS (
SELECT CID, Dept, sk=1+MIN(sk)
FROM (
SELECT sk, CID, CDate, Dept
,rn=sk-ROW_NUMBER() OVER (PARTITION BY CID, Dept ORDER BY cDATE)
FROM #tTable
WHERE Dept = 'C'
) a
GROUP BY CID, Dept, rn
HAVING MIN(sk) <> MAX(sk))
SELECT a.sk, a.CID, a.cDate, a.Dept
FROM #tTable a
JOIN GroupedRows b ON a.sk=b.sk;

GO
DROP TABLE #tTable;




Edit: Adding my results:


sk CID cDate Dept
5 111 2012-11-20 00:00:00.000 C
11 111 2013-04-12 00:00:00.000 C
17 222 2012-07-12 00:00:00.000 C
20 222 2013-07-11 00:00:00.000 C
24 444 2013-02-14 00:00:00.000 C
27 444 2013-05-14 00:00:00.000 C




My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
etirem
etirem
SSC Journeyman
SSC Journeyman (80 reputation)SSC Journeyman (80 reputation)SSC Journeyman (80 reputation)SSC Journeyman (80 reputation)SSC Journeyman (80 reputation)SSC Journeyman (80 reputation)SSC Journeyman (80 reputation)SSC Journeyman (80 reputation)

Group: General Forum Members
Points: 80 Visits: 517
mickyT (9/22/2013)
Hi

I think this covers what you want to do. I suspect the performance will be poor.
WITH groupit AS (
-- Group up the Depts on data
SELECT CID, CDate, Dept,
ROW_NUMBER() OVER (PARTITION BY CID ORDER BY CDate ASC) - ROW_NUMBER() OVER (PARTITION BY CID, Dept ORDER BY CDate ASC) GroupNum
FROM #tTable t
),
getDeptGC AS (
-- Do counts in the groups for dept C
SELECT CID, CDate, Dept, GroupNum,
COUNT(*) OVER (PARTITION BY CID, Dept, GroupNum) C
FROM groupit a
WHERE Dept = 'C'
),
getDeptR AS (
-- Number the rows in groups of more than 1
SELECT CID, CDate, Dept, GroupNum,
ROW_NUMBER() OVER (PARTITION BY CID, Dept ORDER BY CDate ASC) N
FROM getDeptGC
WHERE C > 1
)
SELECT CID, CDate, Dept FROM getDeptR WHERE N = 2
ORDER BY CID;



Thank You!!
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