There are loads of new features in Sql Server 2005 code named Yukon. Out of which in this article let me explain briefly the enhancements made to TOP keyword in this version of the product.
Let us first create a sample table and populate some dummy records into it.
Create table TestTopOptionYukon
(
YearOfSales Int,
SalesQuarter Int,
Amount money
)
go
Insert into TestTopOptionYukon (YearOfSales, SalesQuarter, Amount) Values (2003, 1, 100)
Insert into TestTopOptionYukon (YearOfSales, SalesQuarter, Amount) Values (2003, 2, 200)
Insert into TestTopOptionYukon (YearOfSales, SalesQuarter, Amount) Values (2003, 3, 300)
Insert into TestTopOptionYukon (YearOfSales, SalesQuarter, Amount) Values (2003, 4, 400)
go
Insert into TestTopOptionYukon (YearOfSales, SalesQuarter, Amount) Values (2004, 1, 500)
Insert into TestTopOptionYukon (YearOfSales, SalesQuarter, Amount) Values (2004, 2, 600)
Insert into TestTopOptionYukon (YearOfSales, SalesQuarter, Amount) Values (2004, 3, 700)
Insert into TestTopOptionYukon (YearOfSales, SalesQuarter, Amount) Values (2004, 4, 800)
go
Insert into TestTopOptionYukon (YearOfSales, SalesQuarter, Amount) Values (2005, 1, 900)
Insert into TestTopOptionYukon (YearOfSales, SalesQuarter, Amount) Values (2005, 2, 1000)
Insert into TestTopOptionYukon (YearOfSales, SalesQuarter, Amount) Values (2005, 3, 1100)
Insert into TestTopOptionYukon (YearOfSales, SalesQuarter, Amount) Values (2005, 4, 1200)
go
The below code snippet would work in both SQL Server 2000 and SQL Server 2005
/*
TSQL stops proceessing when they have been affected by the specified no of rows
*/
Set RowCount 2
-- First two records salesquarter would be set as 999
Begin Tran
Update TestTopOptionYukon SET SalesQuarter = 999
If @@RowCount = 0
Begin
Print 'No Record found'
Set RowCount 0
End
Commit Tran
To list all the records again we need to set the RowCount as 0.
Set RowCount 0
Select * from TestTopOptionYukon
The below code snippet would work only in SQL Server 2005.
As you could see Set Rowcount statement is not used at all. Instead we have made use of TOP keyword.
Begin Tran
Update TOP (2) TestTopOptionYukon SET SalesQuarter = 999
If @@RowCount = 0
Begin
Print 'No Record found'
Set RowCount 0
End
Commit Tran
Passing parameters to the TOP keyword
One of the feature which was missing in Sql Server 2000 was passing parameters to the TOP keyword. That is now possible in Yukon.
Declare @topValue Int
Set @topValue = 2
Select Top (@topValue) * from TestTopOptionYukon
Even if you give decimal Values it takes only the integer part and ignores the decimal part. The below query would list the Top 2 records.
Declare @topValue Int
Set @topValue = 2.9
Select Top (@topValue) * from TestTopOptionYukon
Listing Top n percentage of records from a table
Declare @topValue Int
Set @topValue = 25
Select TOP (@topValue) Percent * from TestTopOptionYukon
Out of all the coolest enhancement is we could now pass a query as a parameter to TOP keyword.
The below code snippet helps us in finding out the top half of the exisitng records.
--It would list 50% of the records i.e, in our case top 6 records
Select TOP (Select cast((Select Count(*)/2 from TestTopOptionYukon) as int)) * from TestTopOptionYukon
Let us first create a sample table and populate some dummy records into it.
Create table TestTopOptionYukon
(
YearOfSales Int,
SalesQuarter Int,
Amount money
)
go
Insert into TestTopOptionYukon (YearOfSales, SalesQuarter, Amount) Values (2003, 1, 100)
Insert into TestTopOptionYukon (YearOfSales, SalesQuarter, Amount) Values (2003, 2, 200)
Insert into TestTopOptionYukon (YearOfSales, SalesQuarter, Amount) Values (2003, 3, 300)
Insert into TestTopOptionYukon (YearOfSales, SalesQuarter, Amount) Values (2003, 4, 400)
go
Insert into TestTopOptionYukon (YearOfSales, SalesQuarter, Amount) Values (2004, 1, 500)
Insert into TestTopOptionYukon (YearOfSales, SalesQuarter, Amount) Values (2004, 2, 600)
Insert into TestTopOptionYukon (YearOfSales, SalesQuarter, Amount) Values (2004, 3, 700)
Insert into TestTopOptionYukon (YearOfSales, SalesQuarter, Amount) Values (2004, 4, 800)
go
Insert into TestTopOptionYukon (YearOfSales, SalesQuarter, Amount) Values (2005, 1, 900)
Insert into TestTopOptionYukon (YearOfSales, SalesQuarter, Amount) Values (2005, 2, 1000)
Insert into TestTopOptionYukon (YearOfSales, SalesQuarter, Amount) Values (2005, 3, 1100)
Insert into TestTopOptionYukon (YearOfSales, SalesQuarter, Amount) Values (2005, 4, 1200)
go
The below code snippet would work in both SQL Server 2000 and SQL Server 2005
/*
TSQL stops proceessing when they have been affected by the specified no of rows
*/
Set RowCount 2
-- First two records salesquarter would be set as 999
Begin Tran
Update TestTopOptionYukon SET SalesQuarter = 999
If @@RowCount = 0
Begin
Print 'No Record found'
Set RowCount 0
End
Commit Tran
To list all the records again we need to set the RowCount as 0.
Set RowCount 0
Select * from TestTopOptionYukon
The below code snippet would work only in SQL Server 2005.
As you could see Set Rowcount statement is not used at all. Instead we have made use of TOP keyword.
Begin Tran
Update TOP (2) TestTopOptionYukon SET SalesQuarter = 999
If @@RowCount = 0
Begin
Print 'No Record found'
Set RowCount 0
End
Commit Tran
Passing parameters to the TOP keyword
One of the feature which was missing in Sql Server 2000 was passing parameters to the TOP keyword. That is now possible in Yukon.
Declare @topValue Int
Set @topValue = 2
Select Top (@topValue) * from TestTopOptionYukon
Even if you give decimal Values it takes only the integer part and ignores the decimal part. The below query would list the Top 2 records.
Declare @topValue Int
Set @topValue = 2.9
Select Top (@topValue) * from TestTopOptionYukon
Listing Top n percentage of records from a table
Declare @topValue Int
Set @topValue = 25
Select TOP (@topValue) Percent * from TestTopOptionYukon
Out of all the coolest enhancement is we could now pass a query as a parameter to TOP keyword.
The below code snippet helps us in finding out the top half of the exisitng records.
--It would list 50% of the records i.e, in our case top 6 records
Select TOP (Select cast((Select Count(*)/2 from TestTopOptionYukon) as int)) * from TestTopOptionYukon
Comments