Tie row to previous rows of data

  • I am trying to associate the number value that has a description of SK to the previous rows up to the next SK row. In the first rows of the example below, the value "270641" would be placed in a field for sequence numbers 37-47. Can I do this in a query or an update statement into a table? Thank you

    SequenceNumberDescription
    37873839CN
    3843772CN
    3929643CN
    40480171CN
    41702525CN
    42632336CN
    43400707CN
    44656546CN
    45172415CN
    46102565CN
    47241011CN
    48270641SK
    49965181CN
    50439002CN
    51960643CN
    52913517CN
    53747449CN
    54706935CN
    55686192CN
    56818341CN
    57700803CN
    58688351CN
    59270058SK
    60829483CN
    61931514CN
    62437628CN
    63671635CN
    64904216CN
    65764151CN
    66400180CN
    67989253CN
    68931008CN
    69906772CN
    70237658SK
    71433050CN
    72332802CN
    73864142CN
    74793205CN
    76793216CN
    7740302CN
    7895043CN
    79794445CN
    80793005CN
    81250143SK

    {�_v�

  • You should know that you need to supply data with DDL and in a consumable format.

    Thom~

    Excuse my typos and sometimes awful grammar. My fingers work faster than my brain does.
    Larnu.uk

  • Thom A - Friday, November 3, 2017 5:15 AM

    You should know that you need to supply data with DDL and in a consumable format.

    And when you do this, can you confirm that the only factor which needs to be considered when ordering the rows of data is the 'Sequence' column?

    If you haven't even tried to resolve your issue, please don't expect the hard-working volunteers here to waste their time providing links to answers which you could easily have found yourself.

  • If I'm understanding this correctly, you want to offset the sequence based on the description and the sequence? If that's true, you, you can try to add a new sequence per description and order it by sequence. Treat the sequence you have now as the GlobalSequence for all descriptions. Then create a new field called a LocalSequence, which defines the sequence order per description. For example, the GlobalSequence for this data with SK would be 59, 70, and 81. The LocalSequence would be 1, 2, 3. 

    Then if you want to tie the 70th GlobalSequence to the 59th GlobalSequence for SK only, you can use the LocalSequence to help you do that by doing a LEFT JOIN and OFFSET the LocalSequence like so:


    SELECT *
    FROM MyTable a
    LEFT JOIN MyTable b ON a.[Description] = b.[Description] AND a.[LocalSequence] = b.[LocalSequence] + 1

    This will join the next sequence onto the previous sequence. For example, LocalSequence 1 will have LocalSequence 2 joined on it, effectively attaching the 70th GlobalSequence to the 59th GlobalSequence (i.e.: 1 = 2, 2 = 3, 4 = 5, etc). You can do the opposite with subtracting to tie 70th to the 59th. (2 = 1, 3 = 2, etc).

    Use ROW_NUMBER and PARTITION OVER Description ORDER BY Sequence to create that LocalSequence.

    Then for an UPDATE statement, you can then just do a typical UPDATE JOIN statement to use the JOIN above. But, I would create a new field for the prior and new values just so you can readjust accordingly.

    I may be a bit rusty, but I think that's how I offsetted data before in sequence. Joining the data on top of each other then adding and subtracting the sequence on the JOIN. Do similar to do Month over Month for example.

  • xsevensinzx - Friday, November 3, 2017 6:28 AM

    If I'm understanding this correctly, you want to offset the sequence based on the description and the sequence? If that's true, you, you can try to add a new sequence per description and order it by sequence. Treat the sequence you have now as the GlobalSequence for all descriptions. Then create a new field called a LocalSequence, which defines the sequence order per description. For example, the GlobalSequence for this data with SK would be 59, 70, and 81. The LocalSequence would be 1, 2, 3. 

    Then if you want to tie the 70th GlobalSequence to the 59th GlobalSequence for SK only, you can use the LocalSequence to help you do that by doing a LEFT JOIN and OFFSET the LocalSequence like so:


    SELECT *
    FROM MyTable a
    LEFT JOIN MyTable b ON a.[Description] = b.[Description] AND a.[LocalSequence] = b.[LocalSequence] + 1

    This will join the next sequence onto the previous sequence. For example, LocalSequence 1 will have LocalSequence 2 joined on it, effectively attaching the 70th GlobalSequence to the 59th GlobalSequence (i.e.: 1 = 2, 2 = 3, 4 = 5, etc). You can do the opposite with subtracting to tie 70th to the 59th. (2 = 1, 3 = 2, etc).

    Use ROW_NUMBER and PARTITION OVER Description ORDER BY Sequence to create that LocalSequence.

    Then for an UPDATE statement, you can then just do a typical UPDATE JOIN statement to use the JOIN above. But, I would create a new field for the prior and new values just so you can readjust accordingly.

    I may be a bit rusty, but I think that's how I offsetted data before in sequence. Joining the data on top of each other then adding and subtracting the sequence on the JOIN. Do similar to do Month over Month for example.

    That's the traditional solution, but it requires two scans of the table.  I think this is a classic Gaps and Islands problem.

    John

  • Ahh nice, that works too!

  • John Mitchell-245523 - Friday, November 3, 2017 6:55 AM

    That's the traditional solution, but it requires two scans of the table.  I think this is a classic Gaps and Islands problem.

    John

    Was thinking islands, but didn't use that for my idea:

    WITH VTE AS (
      SELECT *
      FROM (VALUES (1,123123,'CN'),(2,18123,'CN'),(3,12371,'SK'),(4,1242358,'CN'),(5,96734,'SK')) V(S,N,D)),
    Islands AS (
      SELECT *,
        COUNT(CASE D WHEN 'SK' THEN N END) OVER (ORDER BY S ROWS BETWEEN UNBOUNDED PRECEDING AND 1 PRECEDING) AS Grp
      FROM VTE)
    SELECT S, N, D,
       FIRST_VALUE(N) OVER (PARTITION BY Grp ORDER BY S DESC) AS NGrp
    FROM Islands;

    Thom~

    Excuse my typos and sometimes awful grammar. My fingers work faster than my brain does.
    Larnu.uk

  • That's the traditional solution, but it requires two scans of the table.  I think this is a classic Gaps and Islands problem.

    John

    Was thinking islands, but didn't use that for my idea:

    WITH VTE AS (
      SELECT *
      FROM (VALUES (1,123123,'CN'),(2,18123,'CN'),(3,12371,'SK'),(4,1242358,'CN'),(5,96734,'SK')) V(S,N,D)),
    Islands AS (
      SELECT *,
          COUNT(CASE D WHEN 'SK' THEN N END) OVER (ORDER BY S ROWS BETWEEN UNBOUNDED PRECEDING AND 1 PRECEDING) AS Grp
      FROM VTE)
    SELECT S, N, D,
        FIRST_VALUE(N) OVER (PARTITION BY Grp ORDER BY S DESC) AS NGrp
    FROM Islands;

    This requires two sorts: one for the COUNT() and one for the FIRST_VALUE().  The following only requires one sort.

    WITH Vals AS (
      SELECT *
      FROM (VALUES (1,123123,'CN'),(2,18123,'CN'),(3,12371,'SK'),(4,1242358,'CN'),(5,96734,'SK')) V(Seq,Num,Descr)
    )
    SELECT *, CAST(SUBSTRING(MIN(CAST(Seq AS BINARY(4)) + CAST(CASE WHEN Descr = 'SK' THEN Num END AS BINARY(4))) OVER(ORDER BY Seq ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING), 5, 4) AS INT)
    FROM Vals
    ;

    Drew

    J. Drew Allen
    Business Intelligence Analyst
    Philadelphia, PA

Viewing 8 posts - 1 through 7 (of 7 total)

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