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


Find First and Last Period without holes


Find First and Last Period without holes

Author
Message
Umfriend
Umfriend
Forum Newbie
Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)

Group: General Forum Members
Points: 2 Visits: 14
OK, first post and Subject I can not phrase any better.

1. I have a table where all records have a field for period.
2. For each record I want to know what the first and last periods are in which the period of the current record falls, without missing periods.

Assume Table t1:
KEY Period Data (Key is three fields + Period)
A 5 data
A 6 data
A 8 data

I want a query that yields:
KEY Period Data FirstPeriod LastPeriod
A 5 data 5 6
A 6 data 5 6
A 8 data 8 8

I have got it but it must be extremely inefficient. I do (for FP (FirstPeriod) only, LP is similar):
UPDATE t1
SET FP = (
SELECT MAX(Period)
FROM
( SELECT t2.KEY, t2.Period
FROM vAT t2
LEFT JOIN vAT t3
ON t2.KEY = t3.KEY
AND t2.Per = t3.Per+1
WHERE t3.Per IS NULL
AND t1.KEY = t2.KEY AND t1.Per >= t2.Per
) as tfp
)

FROM vAT t1

It does what I need but this can't be right/efficient, can it?

Kind rgds,
Umf
Umfriend
Umfriend
Forum Newbie
Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)

Group: General Forum Members
Points: 2 Visits: 14
Oh well. I have many many rows with but (relatively) few distinct occurences of KEY (without Period). Using temporary tables solved the performance thing (5 mins to 12 secs). May integrate in some subquery structure again but for now I am fine.

Many thanks.
dwain.c
dwain.c
SSCertifiable
SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)

Group: General Forum Members
Points: 7479 Visits: 6431
I understand you already have a solution but this might be a bit more efficient. The technique is based on an article by Jeff Moden on Grouping Islands of Contiguous Dates (your periods are like dates).


DECLARE @Test TABLE
([KEY] VARCHAR(5), Period INT, Data VARCHAR(10))

INSERT INTO @Test
SELECT 'A',5,'data'
UNION ALL SELECT 'A',6,'data'
UNION ALL SELECT 'A',8,'data'

;WITH CTE AS (
SELECT [Key], FirstPeriod=MIN(Period), LastPeriod=MAX(Period)
FROM (
SELECT [KEY], Period, Data
,n=Period-ROW_NUMBER() OVER (PARTITION BY [KEY] ORDER BY Period)
FROM @Test) a
GROUP BY [Key], n)
SELECT b.[KEY], Period, Data, FirstPeriod, LastPeriod
FROM CTE a
INNER JOIN @Test b ON a.[KEY] = b.[KEY] AND b.Period BETWEEN FirstPeriod AND LastPeriod




Hope this helps!


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
Bhanu Prakash T
Bhanu Prakash T
SSC-Enthusiastic
SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)SSC-Enthusiastic (107 reputation)

Group: General Forum Members
Points: 107 Visits: 36
You can check this as well. Slightly improved version. Is n't it ?


DECLARE @Test TABLE
([KEY] VARCHAR(5), Period INT, Data VARCHAR(10))

INSERT INTO @Test
SELECT 'A',5,'data'
UNION ALL SELECT 'A',6,'data'
UNION ALL SELECT 'A',8,'data'

;WITH CTE AS (
SELECT [Key], Period, Data, FirstPeriod=MIN(Period) OVER (partition by [key], n), LastPeriod=MAX(Period) OVER (partition by [key], n)
FROM (
SELECT [KEY], Period, Data, n=Period-ROW_NUMBER() OVER (PARTITION BY [KEY] ORDER BY Period)
FROM @Test) a
)
SELECT [Key], Period, Data, FirstPeriod, LastPeriod
FROM CTE a;


Thank you.
Sergiy
Sergiy
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10654 Visits: 11970
dwain.c (1/15/2013)
I understand you already have a solution but this might be a bit more efficient. The technique is based on an article by Jeff Moden on Grouping Islands of Contiguous Dates (your periods are like dates).


DECLARE @Test TABLE
([KEY] VARCHAR(5), Period INT, Data VARCHAR(10))

INSERT INTO @Test
SELECT 'A',5,'data'
UNION ALL SELECT 'A',6,'data'
UNION ALL SELECT 'A',8,'data'

;WITH CTE AS (
SELECT [Key], FirstPeriod=MIN(Period), LastPeriod=MAX(Period)
FROM (
SELECT [KEY], Period, Data
,n=Period-ROW_NUMBER() OVER (PARTITION BY [KEY] ORDER BY Period)
FROM @Test) a
GROUP BY [Key], n)
SELECT b.[KEY], Period, Data, FirstPeriod, LastPeriod
FROM CTE a
INNER JOIN @Test b ON a.[KEY] = b.[KEY] AND b.Period BETWEEN FirstPeriod AND LastPeriod




Hope this helps!


The script goes nuts if you add another record to the table;

INSERT INTO @Test
SELECT 'A',5,'data'
UNION ALL SELECT 'A',6,'data'
UNION ALL SELECT 'A',6,'other data'
UNION ALL SELECT 'A',8,'data'


dwain.c
dwain.c
SSCertifiable
SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)SSCertifiable (7.5K reputation)

Group: General Forum Members
Points: 7479 Visits: 6431
Sergiy (2/13/2013)
dwain.c (1/15/2013)
I understand you already have a solution but this might be a bit more efficient. The technique is based on an article by Jeff Moden on Grouping Islands of Contiguous Dates (your periods are like dates).


DECLARE @Test TABLE
([KEY] VARCHAR(5), Period INT, Data VARCHAR(10))

INSERT INTO @Test
SELECT 'A',5,'data'
UNION ALL SELECT 'A',6,'data'
UNION ALL SELECT 'A',8,'data'

;WITH CTE AS (
SELECT [Key], FirstPeriod=MIN(Period), LastPeriod=MAX(Period)
FROM (
SELECT [KEY], Period, Data
,n=Period-ROW_NUMBER() OVER (PARTITION BY [KEY] ORDER BY Period)
FROM @Test) a
GROUP BY [Key], n)
SELECT b.[KEY], Period, Data, FirstPeriod, LastPeriod
FROM CTE a
INNER JOIN @Test b ON a.[KEY] = b.[KEY] AND b.Period BETWEEN FirstPeriod AND LastPeriod




Hope this helps!


The script goes nuts if you add another record to the table;

INSERT INTO @Test
SELECT 'A',5,'data'
UNION ALL SELECT 'A',6,'data'
UNION ALL SELECT 'A',6,'other data'
UNION ALL SELECT 'A',8,'data'



I guess that would depend on whether the OPs data contains duplicates on KEY. In which case I'd agree that this approach won't work.


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
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