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 «««123

Prev and Next Row Without RowNumber Expand / Collapse
Author
Message
Posted Tuesday, July 16, 2013 7:29 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: 2 days ago @ 8:30 PM
Points: 3,627, Visits: 5,273
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!

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 #1474349
Posted Tuesday, July 16, 2013 9:42 PM
SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Yesterday @ 12:28 PM
Points: 411, Visits: 2,408
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.
Post #1474359
Posted Thursday, July 18, 2013 4:39 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Wednesday, December 11, 2013 10:09 AM
Points: 10, Visits: 50
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.
Post #1474966
Posted Thursday, July 18, 2013 5:52 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 9:46 AM
Points: 7,224, Visits: 13,696
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
Exploring Recursive CTEs by Example Dwain Camps
Post #1474987
Posted Thursday, July 18, 2013 6:40 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: 2 days ago @ 8:30 PM
Points: 3,627, Visits: 5,273
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!

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 #1475243
« Prev Topic | Next Topic »

Add to briefcase «««123

Permissions Expand / Collapse