Prev and Next Row Without RowNumber

  • Khalid Hanif-458693 (7/16/2013)


    The rownumber is very costly on a large table,

    The Order By can be By Cost_Center_Code, Payment_Code, Inv_No

    Thanks

    You are going to have to use RowNumber somewhere along the way to know which row is previous. Maybe you should try it before you simply refuse it. Unless you are numbering the entire table it really is not a big deal.

    From what I am interpreting you would want to partition by Cost_Center_Code, Payment_Code, Inv_No and Order by Payment_Code.

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • I don't see how you can force the order without using an ordering column of some kind so it seems the easiest solution is to just add an IDENTITY column to the target table. Then we can query the data in the order it was entered. (You could probably also use a TIMESTAMP column, a DATETIME, or a NEWSEQUENTIALID for ordering as well...but you will need something that indicates the order of the rows since SQL doesn't necessarily store them in the order they are entered.)

    With that addition then, this query will do what you want:

    --Sample data

    IF OBJECT_ID('tempdb..#Invoice_t') IS NOT NULL

    DROP TABLE #Invoice_t

    CREATE TABLE #Invoice_t (

    [RowID] INT IDENTITY(1,1) NOT NULL,

    [Cost_Center_code] [int] NOT NULL,

    [Payment_code] [int] NOT NULL,

    [INV_No] [int] NOT NULL,

    PRIMARY KEY CLUSTERED ([RowID],[Cost_Center_code],[Payment_code],[INV_No]))

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (1, 1, 2)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (1, 2, 2)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (1, 3, 2)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (1, 4, 2)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (1, 5, 2)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (1, 6, 2)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (1, 7, 2)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (1, 8, 2)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (1, 9, 2)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (1, 10, 2)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (1, 1, 1)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (1, 1, 2)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (1, 1, 3)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (2, 1, 1)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (2, 1, 2)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (2, 2, 1)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (2, 2, 2)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (1, 2, 1)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (3, 2, 1)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (3, 1, 1)

    SET NOCOUNT ON

    ;WITH

    cteInvoices

    AS

    (

    SELECT

    RowID

    ,RowID+1 AS PrevRowID

    ,RowID-1 AS NextRowID

    ,Cost_Center_code

    ,Payment_code

    ,INV_No

    FROM

    #Invoice_t

    )

    SELECT

    i.Cost_Center_code

    ,i.Payment_code

    ,i.INV_No

    ,p.Cost_Center_code AS [prev_cost_center_code]

    ,p.Payment_code AS [prev_payment_code]

    ,p.INV_No AS [prev_Inv_no]

    ,n.Cost_Center_code AS [next_cost_center_code]

    ,n.Payment_code AS [next_payment_code]

    ,n.INV_No AS [next_Inv_no]

    FROM

    cteInvoices AS i

    LEFT OUTER JOIN

    cteInvoices AS p

    ON i.RowID = p.PrevRowID

    LEFT OUTER JOIN

    cteInvoices AS n

    ON i.RowID = n.NextRowID

    WHERE

    i.RowID > 0

     

  • If the use the identity column, it will mess up the order since sql will order it differently.

    I need data ordered by how sql orders it.

  • Khalid Hanif-458693 (7/16/2013)


    I need data ordered by how sql orders it.

    SQL doesn't order it, that's what people are trying to tell you.

    There is no default ordering. There is no concept of order of inserts. There is no implied order of rows in a table.

    If you want any concept of 'previous', 'next', or 'order', you need to define that order based on a column in the table.

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • Khalid Hanif-458693 (7/16/2013)


    If i upgrade to SQL Server 2012, Can I use the new analytical Functions?

    You could use the new functions in 2012 to do this, but I'm not sure that this would be any cheaper than using a ROW_NUMBER()

    SELECT

    i.Cost_Center_code

    ,i.Payment_code

    ,i.INV_No

    ,LAG(i.Cost_Center_code, 1) OVER (ORDER BY Cost_Center_Code, Payment_Code, Inv_No) AS [prev_cost_center_code]

    ,LAG(i.Payment_code, 1) OVER (ORDER BY Cost_Center_Code, Payment_Code, Inv_No) AS [prev_payment_code]

    ,LAG(i.INV_No, 1) OVER (ORDER BY Cost_Center_Code, Payment_Code, Inv_No) AS [prev_Inv_no]

    ,LEAD(i.Cost_Center_code, 1) OVER (ORDER BY Cost_Center_Code, Payment_Code, Inv_No) AS [next_cost_center_code]

    ,LEAD(i.Payment_code, 1) OVER (ORDER BY Cost_Center_Code, Payment_Code, Inv_No) AS [next_payment_code]

    ,LEAD(i.INV_No, 1) OVER (ORDER BY Cost_Center_Code, Payment_Code, Inv_No) AS [next_Inv_no]

    FROM

    #Invoice_t AS i;

  • No ROW_NUMBER() necessary.

    If you know the largest value stored in each of the 3 columns of interest, you could create a COMPUTED PERSISTED column that is INDEXed and do it something like this:

    CREATE TABLE #Invoice_t(

    [Cost_Center_code] [int] NOT NULL,

    [Payment_code] [int] NOT NULL,

    [INV_No] [int] NOT NULL,

    [Composite_key] AS (RIGHT('0000000000'+CAST([Cost_Center_code] AS VARCHAR(9)),10) +

    RIGHT('0000000000'+CAST([Payment_code] AS VARCHAR(9)),10) +

    RIGHT('0000000000'+CAST([INV_No] AS VARCHAR(9)),10)) PERSISTED,

    CONSTRAINT [PK_Invoice_t] PRIMARY KEY CLUSTERED

    (

    [Cost_Center_code] ASC,

    [Payment_code] ASC,

    [INV_No] ASC

    )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]

    ) ON [PRIMARY]

    GO

    CREATE INDEX composite_index

    ON #Invoice_t ([Composite_key]);

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (1, 1, 1)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (1, 1, 2)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (1, 1, 3)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (2, 1, 1)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (2, 1, 2)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (2, 2, 1)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (2, 2, 2)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (1, 2, 1)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (3, 2, 1)

    INSERT #Invoice_t ([Cost_Center_code], [Payment_code], [INV_No]) VALUES (3, 1, 1)

    ---------------------------------------------------------------

    SELECT *

    FROM #Invoice_t;

    SELECT a.Cost_Center_Code, a.Payment_code, a.Inv_NO

    ,Prev.Cost_Center_Code, Prev.Payment_code, Prev.Inv_NO

    ,Next.Cost_Center_Code, Next.Payment_code, Next.Inv_NO

    FROM #Invoice_t a

    OUTER APPLY (

    SELECT TOP 1 Cost_Center_Code, Payment_code, Inv_NO

    FROM #Invoice_t b

    WHERE b.Composite_key < a.Composite_key

    ORDER BY Composite_key DESC) Prev

    OUTER APPLY (

    SELECT TOP 1 Cost_Center_Code, Payment_code, Inv_NO

    FROM #Invoice_t b

    WHERE b.Composite_key > a.Composite_key

    ORDER BY Composite_key ASC) Next

    ORDER BY a.Cost_Center_Code, a.Payment_code, a.Inv_NO;

    GO

    DROP TABLE #Invoice_t;

    Note that the execution plan this produced for the admittedly tiny sample data set showed two INDEX seeks and a CLUSTERED INDEX scan.

    You don't even really need the COMPUTED column, but it does make the final query a bit more terse.

    Edit: Note that originally I overall ordered by Composite_key which generated a NON-CLUSTERED INDEX scan instead of the above stated CLUSTERED INDEX scan.


    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

  • Khalid Hanif-458693 (7/16/2013)


    patrickmcginnis59 10839 (7/16/2013)


    keebler96 (7/16/2013)


    The order of the previous and the next rows should be ordered just like the SQL has inserted according to the primary keys.

    This is the problem. There is no default order by in SQL Server. You MUST order your data by the use of the order by clause. You must define the proper order for your result set.

    Just because you inserted records in a particular order does not mean that the table stores them in that order.

    From what you have provided us, you have to use Row_Number, and you have to order your composite primary key in the way you want the rows to be ordered.

    Hope that helps.

    I was able to get the previous and next rows with the SQL I posted and not use row number. I suspect the row number version would be more concise because I had to build up the comparison criteria to account for all keys.

    I was not able to get the Previous or the next row, the where condition should include all the columns.

    Cost_Center_Code,Payment_Code,Inv_No.

    Can you check your code with the updated OP code.

    Never mind, it was my mistake, I was only working with one row and trying to take that route for a query doesn't work well at all compared to using row numbers.

  • Dwain,

    Thanks for the great idea, instead of the computed column, I used the bigint column with all the values.

    working like a charm with index seek.

  • Khalid Hanif-458693 (7/18/2013)


    Dwain,

    Thanks for the great idea, instead of the computed column, I used the bigint column with all the values.

    working like a charm with index seek.

    Khalid, I'd be fascinated to see the actual execution plan for your solution, if you have the time to post it up as an attachment. Thanks!

    “Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • Khalid Hanif-458693 (7/18/2013)


    Dwain,

    Thanks for the great idea, instead of the computed column, I used the bigint column with all the values.

    working like a charm with index seek.

    You're welcome. Email notifications must not be working again.

    Although, I must confess that like Chris I am curious how you managed an INDEX SEEK without the computed column.


    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 10 posts - 16 through 24 (of 24 total)

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