Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Find First and Last Period without holes Expand / Collapse
Author
Message
Posted Monday, January 14, 2013 6:02 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, June 24, 2014 2:36 AM
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
Post #1406679
Posted Monday, January 14, 2013 8:10 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, June 24, 2014 2:36 AM
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.
Post #1406752
Posted Tuesday, January 15, 2013 7:30 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Thursday, December 18, 2014 9:53 PM
Points: 3,438, Visits: 5,390
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!
Post #1407546
Posted Thursday, January 17, 2013 3:56 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Monday, January 28, 2013 12:49 AM
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.
Post #1408304
Posted Wednesday, February 13, 2013 7:06 PM
SSCarpal Tunnel

SSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal Tunnel

Group: General Forum Members
Last Login: Monday, November 3, 2014 4:30 PM
Points: 4,574, Visits: 8,366
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'

Post #1419795
Posted Wednesday, February 13, 2013 7:14 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Thursday, December 18, 2014 9:53 PM
Points: 3,438, Visits: 5,390
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!
Post #1419797
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse