February 18, 2011 at 1:13 pm
Hi,
I'm looking for a function similar to ROW_NUMBER that will help me partition and count data.
For example, I have data table in sql that's something like:
ShortDateFlowDirection
1/1/20010
1/2/20011
1/3/20011
1/4/20010
1/5/2001-1
1/6/20010
1/7/20010
1/8/2001-1
1/9/2001-1
1/10/2001-1
1/11/20011
And I want to create a query that allows me to look at how many consecutive days the flow has been going in the same direction, i.e. to make a column "ConsecDays" like:
ShortDateFlowDirectionConsecDays
1/1/200101
1/2/200111
1/3/200112
1/4/200101
1/5/2001-11
1/6/200101
1/7/200102
1/8/2001-11
1/9/2001-12
1/10/2001-13
1/11/200111
I'm hoping that someone's got a cool trick or really elegant method with partitioning or ROW_NUMBER that I'm just not seeing...
Thanks in advance for any help!
February 18, 2011 at 1:43 pm
Try this
CREATE TABLE #Data(ShortDate DATETIME,FlowDirection INT)
INSERT INTO #Data(ShortDate,FlowDirection)
SELECT '20010101', 0 UNION ALL
SELECT '20010102', 1 UNION ALL
SELECT '20010103', 1 UNION ALL
SELECT '20010104', 0 UNION ALL
SELECT '20010105', -1 UNION ALL
SELECT '20010106', 0 UNION ALL
SELECT '20010107', 0 UNION ALL
SELECT '20010108', -1 UNION ALL
SELECT '20010109', -1 UNION ALL
SELECT '20010110', -1 UNION ALL
SELECT '20010111', 1;
WITH CTE AS (
SELECT ShortDate,FlowDirection,
ROW_NUMBER() OVER(ORDER BY ShortDate) - ROW_NUMBER() OVER(PARTITION BY FlowDirection ORDER BY ShortDate) AS rnDiff
FROM #Data)
SELECT ShortDate,FlowDirection,
ROW_NUMBER() OVER(PARTITION BY FlowDirection,rnDiff ORDER BY ShortDate) AS ConsecDays
FROM CTE
ORDER BY ShortDate;
____________________________________________________
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/61537February 18, 2011 at 1:52 pm
Thanks! Works in my small example, now I've just got to implement it with everything else!
Viewing 3 posts - 1 through 2 (of 2 total)
You must be logged in to reply to this topic. Login to reply