Monday, March 19, 2012

Calling All T-SQL Gods & Goddesses

Hi

I'm having trouble with the script below that it just won't do a
correct ORDER BY for a date field.

When executing the two SELECT TOP statements on their own the records
are sorted correctly but when wrapped in the main statement, the ORDER
BY is just ignored. Tried to play around with the script but with no
luck. Script is for paging, in this case, select all records meeting
criteria, order and select Top 25 to display on first page. Any
questions, please don't hesitate contacting me.

Thanks very much to anyone who's having a look at this!

Martin

SELECT COALESCE((i2b_contact.Firstname + CHAR(32) +
i2b_contact.Lastname),i2b_company.CompanyName) AS CName,
i2b_keytransactionlog.KeyTransactionLogID, i2b_key.KeyCode,
(i2b_address.Address1) AS PropertyAddress,
A.ProgUserName AS ProgUserName,
CONVERT (varchar(10), i2b_keytransactionlog.TransactionDate, 104 ) AS
TransactionDate,
CONVERT(varchar(10),i2b_keytransactionlog.ReturnBy Date,104) AS
ReturnByDate
FROM i2b_keytransactionlog
LEFT JOIN i2b_contact ON (i2b_keytransactionlog.EntityID =
i2b_contact.ContactID AND i2b_keytransactionlog.IsContact = 1)
LEFT JOIN i2b_company ON (i2b_keytransactionlog.EntityID =
i2b_company.CompanyID AND i2b_keytransactionlog.IsContact = 0)
JOIN i2b_key ON (i2b_keytransactionlog.KeyID = i2b_key.KeyID)
JOIN i2b_property on (i2b_key.PropertyID = i2b_property.PropertyID)
JOIN i2b_address ON (i2b_property.AddressID = i2b_address.AddressID)
JOIN i2b_proguser AS A ON (i2b_keytransactionlog.ProgUserID =
A.ProgUserID)
WHERE KeyTransactionLogID IN(SELECT TOP 25 KeyTransactionLogID FROM
i2b_keytransactionlog
LEFT JOIN i2b_contact ON (i2b_keytransactionlog.EntityID =
i2b_contact.ContactID AND i2b_keytransactionlog.IsContact = 1)
LEFT JOIN i2b_company ON (i2b_keytransactionlog.EntityID =
i2b_company.CompanyID AND i2b_keytransactionlog.IsContact = 0)
JOIN i2b_key ON (i2b_keytransactionlog.KeyID = i2b_key.KeyID)
JOIN i2b_property on (i2b_key.PropertyID = i2b_property.PropertyID)
JOIN i2b_address ON (i2b_property.AddressID = i2b_address.AddressID)
JOIN i2b_proguser AS A ON (i2b_keytransactionlog.ProgUserID =
A.ProgUserID)
WHERE i2b_keytransactionlog.ProgClientID = 1 AND
i2b_keytransactionlog.ProgUserID = 3 AND KeyTransactionLogID NOT IN
(SELECT TOP 0 KeyTransactionLogID FROM i2b_keytransactionlog
LEFT JOIN i2b_contact ON (i2b_keytransactionlog.EntityID =
i2b_contact.ContactID AND i2b_keytransactionlog.IsContact = 1)
LEFT JOIN i2b_company ON (i2b_keytransactionlog.EntityID =
i2b_company.CompanyID AND i2b_keytransactionlog.IsContact = 0)
JOIN i2b_key ON (i2b_keytransactionlog.KeyID = i2b_key.KeyID)
JOIN i2b_property on (i2b_key.PropertyID = i2b_property.PropertyID)
JOIN i2b_address ON (i2b_property.AddressID = i2b_address.AddressID)
JOIN i2b_proguser AS A ON (i2b_keytransactionlog.ProgUserID =
A.ProgUserID)
WHERE i2b_keytransactionlog.ProgClientID = 1 AND
i2b_keytransactionlog.ProgUserID = 3 ORDER BY ReturnByDate DESC)
ORDER BY ReturnByDate DESC)
ORDER BY ReturnByDate DESCOn 29 May 2004 12:19:20 -0700, Martin wrote:

>Hi
>I'm having trouble with the script below that it just won't do a
>correct ORDER BY for a date field.
>When executing the two SELECT TOP statements on their own the records
>are sorted correctly but when wrapped in the main statement, the ORDER
>BY is just ignored. Tried to play around with the script but with no
>luck. Script is for paging, in this case, select all records meeting
>criteria, order and select Top 25 to display on first page. Any
>questions, please don't hesitate contacting me.
>Thanks very much to anyone who's having a look at this!
>Martin
>SELECT COALESCE((i2b_contact.Firstname + CHAR(32) +
>i2b_contact.Lastname),i2b_company.CompanyName) AS CName,
>i2b_keytransactionlog.KeyTransactionLogID, i2b_key.KeyCode,
>(i2b_address.Address1) AS PropertyAddress,
>A.ProgUserName AS ProgUserName,
>CONVERT (varchar(10), i2b_keytransactionlog.TransactionDate, 104 ) AS
>TransactionDate,
>CONVERT(varchar(10),i2b_keytransactionlog.ReturnBy Date,104) AS
>ReturnByDate
> FROM i2b_keytransactionlog
>LEFT JOIN i2b_contact ON (i2b_keytransactionlog.EntityID =
>i2b_contact.ContactID AND i2b_keytransactionlog.IsContact = 1)
>LEFT JOIN i2b_company ON (i2b_keytransactionlog.EntityID =
>i2b_company.CompanyID AND i2b_keytransactionlog.IsContact = 0)
>JOIN i2b_key ON (i2b_keytransactionlog.KeyID = i2b_key.KeyID)
>JOIN i2b_property on (i2b_key.PropertyID = i2b_property.PropertyID)
>JOIN i2b_address ON (i2b_property.AddressID = i2b_address.AddressID)
>JOIN i2b_proguser AS A ON (i2b_keytransactionlog.ProgUserID =
>A.ProgUserID)
>WHERE KeyTransactionLogID IN(SELECT TOP 25 KeyTransactionLogID FROM
>i2b_keytransactionlog
>LEFT JOIN i2b_contact ON (i2b_keytransactionlog.EntityID =
>i2b_contact.ContactID AND i2b_keytransactionlog.IsContact = 1)
>LEFT JOIN i2b_company ON (i2b_keytransactionlog.EntityID =
>i2b_company.CompanyID AND i2b_keytransactionlog.IsContact = 0)
>JOIN i2b_key ON (i2b_keytransactionlog.KeyID = i2b_key.KeyID)
>JOIN i2b_property on (i2b_key.PropertyID = i2b_property.PropertyID)
>JOIN i2b_address ON (i2b_property.AddressID = i2b_address.AddressID)
>JOIN i2b_proguser AS A ON (i2b_keytransactionlog.ProgUserID =
>A.ProgUserID)
>WHERE i2b_keytransactionlog.ProgClientID = 1 AND
>i2b_keytransactionlog.ProgUserID = 3 AND KeyTransactionLogID NOT IN
> (SELECT TOP 0 KeyTransactionLogID FROM i2b_keytransactionlog
>LEFT JOIN i2b_contact ON (i2b_keytransactionlog.EntityID =
>i2b_contact.ContactID AND i2b_keytransactionlog.IsContact = 1)
>LEFT JOIN i2b_company ON (i2b_keytransactionlog.EntityID =
>i2b_company.CompanyID AND i2b_keytransactionlog.IsContact = 0)
>JOIN i2b_key ON (i2b_keytransactionlog.KeyID = i2b_key.KeyID)
>JOIN i2b_property on (i2b_key.PropertyID = i2b_property.PropertyID)
>JOIN i2b_address ON (i2b_property.AddressID = i2b_address.AddressID)
>JOIN i2b_proguser AS A ON (i2b_keytransactionlog.ProgUserID =
>A.ProgUserID)
>WHERE i2b_keytransactionlog.ProgClientID = 1 AND
>i2b_keytransactionlog.ProgUserID = 3 ORDER BY ReturnByDate DESC)
> ORDER BY ReturnByDate DESC)
> ORDER BY ReturnByDate DESC

Hi Martin,

I'm not entirely sure why you would use TOP 0 for the NOT IN subquery, but
that's not the cause of the problem you post about.

The ANSI standard for SQL allows only columns appearing in the SELECT list
in the ORDER BY clause. The rationale being that first, the query gets
executed and the result set is determined; the sorting is a seperate,
final stage. ANSI SQL allows things as ORDER BY 3 (3 being the third
column in the SELECT LIST) or SELECT MyColumn AS ColumnAlias ... ORDER BY
ColumnAlias.

MS SQL Server expands on this standard. With MS SQL Server, you can ORDER
BY on a column not in the SELECT list. If you use a column name that is
not an alias in the column list, SQL Server will try to locate a column
with that name in one of the tables used in the query and use that for
sorting.

Before I get back to your problem, run the following script. It will
clearly show that SQL Server will first attempt to resolve names in the
ORDER BY clause following ANSI standard before looking at the columns that
make up the data.

CREATE TABLE testtab (a int, b int)
go
INSERT testtab (a, b) SELECT 1, 20
INSERT testtab (a, b) SELECT 2, 10
go
SELECT b
FROM testtab
ORDER BY a
go
SELECT b AS a
FROM testtab
ORDER BY a
go
SELECT b AS a, a AS b
FROM testtab
ORDER BY a
go
DROP TABLE testtab
go

In the first query, no column "a" is in the SELECT list, so SQL Server
will sort on the column a in the table. In the second query, the SELECT
list has a column aliased as "a", so this is used for sorting. In the
third query, the column a itself is used in the select list; aliases are
disregarded and sorting is done on the contents of a.

Now back to your real problem. I'll show you the parts that cause the
unexpected ordering:

>SELECT (...)
> (...)
>CONVERT(varchar(10),i2b_keytransactionlog.ReturnBy Date,104) AS
>ReturnByDate
> (...)
> ORDER BY ReturnByDate DESC

The column ReturnByDate is not used in the SELECT list (the results of a
function are not cosidered equal to the column itself). There is however
an alias ReturnByDate, so there's no need to get back to the data in the
table either - the aliased column in the result set is used. This column
is the output of a CONVERT function call. It's varchar(10), therefor the
sorting will be done by alphabet, descending. "23-04-2003" will go before
"06-05-2004".

The fix? Either use something else as an alias ([Return By Date], for
example) or use ORDER BY CONVERT(datetime, ReturnByDate).

Best, Hugo
--

(Remove _NO_ and _SPAM_ to get my e-mail address)

No comments:

Post a Comment