Make Sequential numbers into ranges

  • I have a data look like this -

    Note: have to be breakdown per TNID field

    TNID TN

    3011170 4402787100

    3011170 4402787101

    3011170 4402787102

    3011170 4402787103

    3011171 4402787104

    3011171 4402787105

    3011175 4402787118

    3011175 4402787119

    3011175 4405165555

    3011175 4405165556

    3011175 4405165557

    3011175 4405165558

    3011175 4409447976

    How to write a T-SQL that the output will in ranges -

    TNID TN1 TN2

    3011170 44027871004402787103

    3011171 44027871044402787105

    3011175 44027871184402787119

    3011175 44051655554405165558

    3011175 44094479764409447976

    Thanks in advance.

  • This should work in SQL 2000:

    CREATE TABLE #Temp

    (TNID INT, TN VARCHAR(20))

    INSERT INTO #Temp

    SELECT 3011170, '4402787100'

    UNION ALL SELECT 3011170, '4402787101'

    UNION ALL SELECT 3011170, '4402787102'

    UNION ALL SELECT 3011170, '4402787103'

    UNION ALL SELECT 3011171, '4402787104'

    UNION ALL SELECT 3011171, '4402787105'

    UNION ALL SELECT 3011175, '4402787118'

    UNION ALL SELECT 3011175, '4402787119'

    UNION ALL SELECT 3011175, '4405165555'

    UNION ALL SELECT 3011175, '4405165556'

    UNION ALL SELECT 3011175, '4405165557'

    UNION ALL SELECT 3011175, '4405165558'

    UNION ALL SELECT 3011175, '4409447976'

    SELECT TNID, TNMIN=MIN(TN), TNMAX=MAX(TN)

    FROM #Temp

    GROUP BY TNID

    DROP TABLE #Temp


    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

  • I tried your query but it came out like this. The 3rd row is not correct.

    TNID TNMIN TNMAX

    3011170 44027871004402787103

    3011171 44027871044402787105

    3011175 44027871184409447976

    here's the missing recs:

    TNID TN1 TN2

    3011175 4402787118 4402787119

    3011175 4405165555 4405165558

    3011175 4409447976 4409447976

    Thanks for trying :-). Anyone out there have other ideas.

  • Since the data depends on sequentiality, which isn't a property of relational data, you'll need a non-relational solution. That means a simple cursor.

    Step through the rows, if the TN increments by more than 1, or the TNID changes to a new value, insert the new values into a temp table as the start-range value, and update the prior row of the temp table with the last value, as the end-of-range. Then select from the temp table.

    - Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
    Property of The Thread

    "Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon

  • Here is my shot at the solution.

    CREATE TABLE #Temp

    (TNID INT, TN BIGINT);

    INSERT INTO #Temp

    SELECT 3011170, 4402787100

    UNION ALL SELECT 3011170, 4402787101

    UNION ALL SELECT 3011170, 4402787102

    UNION ALL SELECT 3011170, 4402787103

    UNION ALL SELECT 3011171, 4402787104

    UNION ALL SELECT 3011171, 4402787105

    UNION ALL SELECT 3011175, 4402787118

    UNION ALL SELECT 3011175, 4402787119

    UNION ALL SELECT 3011175, 4405165555

    UNION ALL SELECT 3011175, 4405165556

    UNION ALL SELECT 3011175, 4405165557

    UNION ALL SELECT 3011175, 4405165558

    UNION ALL SELECT 3011175, 4409447976;

    with rCTE as (

    select

    row_number() over (order by (select null)) rn,

    t1.TNID,

    t1.TN

    from

    #Temp t1

    left outer join #Temp t2

    on t1.TNID = t2.TNID and t1.TN = t2.TN + 1

    where

    t2.TNID is null

    union all

    select

    rn,

    t1.TNID,

    t1.TN

    from

    #Temp t1

    inner join rCTE t2

    on t1.TNID = t2.TNID and t1.TN = t2.TN + 1

    )

    select TNID, min(TN) TN1, max(TN) TN2 from rCTE group by rn, TNID order by rn,TNID;

    go

    drop table #Temp;

    go

  • Lynn Pettis (8/28/2012)


    Here is my shot at the solution.

    CREATE TABLE #Temp

    (TNID INT, TN BIGINT);

    INSERT INTO #Temp

    SELECT 3011170, 4402787100

    UNION ALL SELECT 3011170, 4402787101

    UNION ALL SELECT 3011170, 4402787102

    UNION ALL SELECT 3011170, 4402787103

    UNION ALL SELECT 3011171, 4402787104

    UNION ALL SELECT 3011171, 4402787105

    UNION ALL SELECT 3011175, 4402787118

    UNION ALL SELECT 3011175, 4402787119

    UNION ALL SELECT 3011175, 4405165555

    UNION ALL SELECT 3011175, 4405165556

    UNION ALL SELECT 3011175, 4405165557

    UNION ALL SELECT 3011175, 4405165558

    UNION ALL SELECT 3011175, 4409447976;

    with rCTE as (

    select

    row_number() over (order by (select null)) rn,

    t1.TNID,

    t1.TN

    from

    #Temp t1

    left outer join #Temp t2

    on t1.TNID = t2.TNID and t1.TN = t2.TN + 1

    where

    t2.TNID is null

    union all

    select

    rn,

    t1.TNID,

    t1.TN

    from

    #Temp t1

    inner join rCTE t2

    on t1.TNID = t2.TNID and t1.TN = t2.TN + 1

    )

    select TNID, min(TN) TN1, max(TN) TN2 from rCTE group by rn, TNID order by rn,TNID;

    go

    drop table #Temp;

    go

    You'll run into maxrecursion issues if the actual data has any significant size to it at all, with this solution.

    - Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
    Property of The Thread

    "Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon

  • GSquared (8/28/2012)


    Lynn Pettis (8/28/2012)


    Here is my shot at the solution.

    CREATE TABLE #Temp

    (TNID INT, TN BIGINT);

    INSERT INTO #Temp

    SELECT 3011170, 4402787100

    UNION ALL SELECT 3011170, 4402787101

    UNION ALL SELECT 3011170, 4402787102

    UNION ALL SELECT 3011170, 4402787103

    UNION ALL SELECT 3011171, 4402787104

    UNION ALL SELECT 3011171, 4402787105

    UNION ALL SELECT 3011175, 4402787118

    UNION ALL SELECT 3011175, 4402787119

    UNION ALL SELECT 3011175, 4405165555

    UNION ALL SELECT 3011175, 4405165556

    UNION ALL SELECT 3011175, 4405165557

    UNION ALL SELECT 3011175, 4405165558

    UNION ALL SELECT 3011175, 4409447976;

    with rCTE as (

    select

    row_number() over (order by (select null)) rn,

    t1.TNID,

    t1.TN

    from

    #Temp t1

    left outer join #Temp t2

    on t1.TNID = t2.TNID and t1.TN = t2.TN + 1

    where

    t2.TNID is null

    union all

    select

    rn,

    t1.TNID,

    t1.TN

    from

    #Temp t1

    inner join rCTE t2

    on t1.TNID = t2.TNID and t1.TN = t2.TN + 1

    )

    select TNID, min(TN) TN1, max(TN) TN2 from rCTE group by rn, TNID order by rn,TNID;

    go

    drop table #Temp;

    go

    You'll run into maxrecursion issues if the actual data has any significant size to it at all, with this solution.

    True, and I didn't ad the option to cap it either, but it was my first shot. I am looking at some other alternatives as well.

  • Here is another option that appears to work for the given test data:

    CREATE TABLE #Temp

    (TNID INT, TN BIGINT);

    INSERT INTO #Temp

    SELECT 3011170, 4402787100

    UNION ALL SELECT 3011170, 4402787101

    UNION ALL SELECT 3011170, 4402787102

    UNION ALL SELECT 3011170, 4402787103

    UNION ALL SELECT 3011171, 4402787104

    UNION ALL SELECT 3011171, 4402787105

    UNION ALL SELECT 3011175, 4402787118

    UNION ALL SELECT 3011175, 4402787119

    UNION ALL SELECT 3011175, 4405165555

    UNION ALL SELECT 3011175, 4405165556

    UNION ALL SELECT 3011175, 4405165557

    UNION ALL SELECT 3011175, 4405165558

    UNION ALL SELECT 3011175, 4409447976;

    with basedata as (

    select

    TNID,

    TN,

    TN - row_number() over (order by TNID, TN) as grp

    from

    #Temp

    )

    select

    TNID,

    min(TN) as TN1,

    max(TN) as TN2

    from

    basedata

    group by

    grp, TNID

    ;

    go

    drop table #Temp;

    go

  • Lynn, your solutions are great :-D. But this is the 7,2000 forum 🙁

    I wonder if that helps the OP.

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • Now someone tells me! Time to hit the desk with my head.

  • Anybody have a SQL Server 2000 instance? Please give this a try:

    CREATE TABLE #Source

    (TNID INT, TN BIGINT);

    INSERT INTO #Source

    SELECT 3011170, 4402787100

    UNION ALL SELECT 3011170, 4402787101

    UNION ALL SELECT 3011170, 4402787102

    UNION ALL SELECT 3011170, 4402787103

    UNION ALL SELECT 3011171, 4402787104

    UNION ALL SELECT 3011171, 4402787105

    UNION ALL SELECT 3011175, 4402787118

    UNION ALL SELECT 3011175, 4402787119

    UNION ALL SELECT 3011175, 4405165555

    UNION ALL SELECT 3011175, 4405165556

    UNION ALL SELECT 3011175, 4405165557

    UNION ALL SELECT 3011175, 4405165558

    UNION ALL SELECT 3011175, 4409447976;

    select

    identity(int,1,1) as RN,

    TNID,

    TN

    into #Temp

    from #Source

    order by TNID, TN;

    select

    TNID,

    min(TN) as TN1,

    max(TN) as TN2

    from

    #Temp

    group by

    TN - RN, TNID;

    go

    drop table #Temp;

    drop table #Source;

    go

  • Lynn,

    I tried your second query and it works perfectly. Great work. Will I run to a maxrecursion with this too? What is the max data for the maxrecursion happens? I will be dealing with hundreds of thousand records.

  • fsr645 (8/28/2012)


    Lynn,

    I tried your second query and it works perfectly. Great work. Will I run to a maxrecursion with this too? What is the max data for the maxrecursion happens? I will be dealing with hundreds of thousand records.

    First, what version of SQL Server are you using?

    Second, if you are talking about the row_number version, there is no recursion so no problem.

  • I'm using SQL 2008. I tried the 3rd version and it works too. Which version do you recommend the 2nd or 3rd one specially dealing hundreds of thousand records? Thanks.

  • My last was a SQL Server 2000 version. Since you are using SQL Server 2008, I'd use the ROW_NUMBER() version (the 2nd).

Viewing 15 posts - 1 through 15 (of 20 total)

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