Find First and Last Period without holes

  • 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):

    UPDATEt1

    SETFP =(

    SELECTMAX(Period)

    FROM

    (SELECT t2.KEY, t2.Period

    FROMvAT t2

    LEFT JOINvAT t3

    ONt2.KEY = t3.KEY

    ANDt2.Per= t3.Per+1

    WHEREt3.Per IS NULL

    ANDt1.KEY= t2.KEYANDt1.Per>= t2.Per

    ) as tfp

    )

    FROMvAT t1

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

    Kind rgds,

    Umf

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

  • 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[/url] (your periods are like dates).

    DECLARE @test-2 TABLE

    ( VARCHAR(5), Period INT, Data VARCHAR(10))

    INSERT INTO @test-2

    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 , Period, Data

    ,n=Period-ROW_NUMBER() OVER (PARTITION BY ORDER BY Period)

    FROM @test-2) a

    GROUP BY [Key], n)

    SELECT b., Period, Data, FirstPeriod, LastPeriod

    FROM CTE a

    INNER JOIN @test-2 b ON a. = b. AND b.Period BETWEEN FirstPeriod AND LastPeriod

    Hope this helps!


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    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?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

  • You can check this as well. Slightly improved version. Is n't it ?

    DECLARE @test-2 TABLE

    ( VARCHAR(5), Period INT, Data VARCHAR(10))

    INSERT INTO @test-2

    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 , n), LastPeriod=MAX(Period) OVER (partition by , n)

    FROM (

    SELECT , Period, Data, n=Period-ROW_NUMBER() OVER (PARTITION BY ORDER BY Period)

    FROM @test-2) a

    )

    SELECT [Key], Period, Data, FirstPeriod, LastPeriod

    FROM CTE a;

    Thank you.

  • 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[/url] (your periods are like dates).

    DECLARE @test-2 TABLE

    ( VARCHAR(5), Period INT, Data VARCHAR(10))

    INSERT INTO @test-2

    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 , Period, Data

    ,n=Period-ROW_NUMBER() OVER (PARTITION BY ORDER BY Period)

    FROM @test-2) a

    GROUP BY [Key], n)

    SELECT b., Period, Data, FirstPeriod, LastPeriod

    FROM CTE a

    INNER JOIN @test-2 b ON a. = b. 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-2

    SELECT 'A',5,'data'

    UNION ALL SELECT 'A',6,'data'

    UNION ALL SELECT 'A',6,'other data'

    UNION ALL SELECT 'A',8,'data'

    _____________
    Code for TallyGenerator

  • 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[/url] (your periods are like dates).

    DECLARE @test-2 TABLE

    ( VARCHAR(5), Period INT, Data VARCHAR(10))

    INSERT INTO @test-2

    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 , Period, Data

    ,n=Period-ROW_NUMBER() OVER (PARTITION BY ORDER BY Period)

    FROM @test-2) a

    GROUP BY [Key], n)

    SELECT b., Period, Data, FirstPeriod, LastPeriod

    FROM CTE a

    INNER JOIN @test-2 b ON a. = b. 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-2

    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![/I]

    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?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

Viewing 6 posts - 1 through 5 (of 5 total)

You must be logged in to reply to this topic. Login to reply