SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Out of order


Out of order

Author
Message
Dave62
Dave62
Hall of Fame
Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)

Group: General Forum Members
Points: 3247 Visits: 2777
SanDroid (10/21/2011)

...I should have been more specific in my question.
Does using a "TOP 99999999" statement with an "order by" in a VIEW against an actual table with less than 99.9 Million rows keep the query optimizer from ignoring the Order by statement since nothing will be filtered?

I know in a basic select with a variable it will not, but Views are different. Cool


I think it does. Give this a shot.

USE [AdventureWorks];
GO

/****** Object: View [dbo].[vw_GetAllEmpoyeesByHireDate] Script Date: 10/21/2011 13:56:54 ******/
IF EXISTS (SELECT * FROM sys.views WHERE object_id = OBJECT_ID(N'[dbo].[vw_GetAllEmpoyeesByHireDate]'))
DROP VIEW [dbo].[vw_GetAllEmpoyeesByHireDate];
GO

/****** Object: View [dbo].[vw_GetAllEmpoyeesByHireDate] Script Date: 10/21/2011 13:56:55 ******/
SET ANSI_NULLS ON;
GO

SET QUOTED_IDENTIFIER ON;
GO

CREATE VIEW [dbo].[vw_GetAllEmpoyeesByHireDate]
AS

SELECT TOP ((SELECT COUNT(*) FROM HumanResources.Employee) + 100)
LoginID
, Title
, HireDate
FROM
HumanResources.Employee AS emp
ORDER BY HireDate DESC;
GO



Then run these selects and note the difference.

Select * From dbo.vw_GetAllEmpoyeesByHireDate;

Select * From dbo.vw_GetAllEmpoyeesByHireDate Order By Title;

Select * From dbo.vw_GetAllEmpoyeesByHireDate Order By HireDate;



May need more testing though.

Enjoy!
SanDroid
SanDroid
SSCommitted
SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)

Group: General Forum Members
Points: 1582 Visits: 1046
Dave62 (10/21/2011)
SanDroid (10/21/2011)

...I should have been more specific in my question.
Does using a "TOP 99999999" statement with an "order by" in a VIEW against an actual table with less than 99.9 Million rows keep the query optimizer from ignoring the Order by statement since nothing will be filtered?

I know in a basic select with a variable it will not, but Views are different. Cool


I think it does. Give this a shot.

[code="sql"]USE [AdventureWorks];
GO .......

May need more testing though.
It certainly does.
I was actually able to test this today on SQL 2008 R2. Although the first time I have done these steps was on a SQL 2005 server. If you want the short story "Index your View" it will keep you from supplying the cause of some serious performance issues.
I have a reporting project that needs two views of the same table Ordered by differant DATETIME columns in DESCENDING ORDER. Both columns are listed in the Table Indexes with other columns in the middle of the ordering of included columns. The Table Data size is over 500MB with 4+Million rows.
I created the views and used the normal "TOP(100) PERCENT" syntax and "ORDER BY DESC" syntax inserted by the View Designer in SSMS when selecting a sorted column and Descending order. When selecting from the view these statements had no affect. The data came out of the view with the same order as the indexed Table default. Then I updated both Views to use " TOP (999999999) ". Now the data came out of the table, but the performance was terible. It took 3 seconds to get the TOP 10000 rows from the view that was ordered. Then I understood what was really going on with this change. Why ruin the performance of select from a good view with an order by statement when an Index is really needed. So I removed the TOP and ORDER BY statements, Schema bound the table, and created descending indexes on the DateTime columns for each view.
Sucess! Not only was my view ordered in the right way, but to first 10000 rows came back out in less than 10ms.
Surii
Surii
Right there with Babe
Right there with Babe (719 reputation)Right there with Babe (719 reputation)Right there with Babe (719 reputation)Right there with Babe (719 reputation)Right there with Babe (719 reputation)Right there with Babe (719 reputation)Right there with Babe (719 reputation)Right there with Babe (719 reputation)

Group: General Forum Members
Points: 719 Visits: 489
Learned something new. Thanks for the question followed by a good discussion.
dogramone
dogramone
Right there with Babe
Right there with Babe (745 reputation)Right there with Babe (745 reputation)Right there with Babe (745 reputation)Right there with Babe (745 reputation)Right there with Babe (745 reputation)Right there with Babe (745 reputation)Right there with Babe (745 reputation)Right there with Babe (745 reputation)

Group: General Forum Members
Points: 745 Visits: 3742
Difficult to understand the question. The sele3ct clause itself only takes UDF, fields or constants. Q query may include and order by clause but select itself is a clause, like from is a clause, where is a clause, all within a select statement.



Koen Verbeeck
Koen Verbeeck
One Orange Chip
One Orange Chip (27K reputation)One Orange Chip (27K reputation)One Orange Chip (27K reputation)One Orange Chip (27K reputation)One Orange Chip (27K reputation)One Orange Chip (27K reputation)One Orange Chip (27K reputation)One Orange Chip (27K reputation)

Group: General Forum Members
Points: 27741 Visits: 13268
Great question, thanks!


How to post forum questions.
Need an answer? No, you need a question.
What’s the deal with Excel & SSIS?
My blog at SQLKover.

MCSE Business Intelligence - Microsoft Data Platform MVP
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search