INF: How to Obtain Case-Sensitive Query Results with a Case-Insensitive Sort OrderID: Q171299
|
A sort order is a set of rules that determines how SQL Server collates and
presents data in response to database queries. The sort order determines
the order in which data is presented in response to SQL Server statements
involving GROUP BY, ORDER BY, and DISTINCT clauses. The sort order also
determines how certain queries are resolved, such as queries involving
WHERE and DISTINCT clauses.
During installation, SQL Server allows you to select a character set and a
sort order that the server will use. Several sort orders and character sets
are available. The default character set is ANSI (ISO 8859-1), and the
default sort order is dictionary order, case-insensitive.
If a case-insensitive sort order is chosen, SQL Server considers character
values that differ only in case as equal in value. That is, 'John' =
'john'. With a case-insensitive sort order, it may often be necessary to
obtain query results with case-sensitivity considered. This article
explains techniques to accomplish this.
To examine the ramifications of a case-insensitive sort order on query
results, consider the following scenario:
create table T1(col1 char(5) NOT NULL, col2 int NOT NULL)
go
insert T1 values('John',1)
insert T1 values('John',1)
insert T1 values('JOhn',1)
insert T1 values('JOhn',1)
insert T1 values('JoHn',1)
insert T1 values('JoHn',1)
insert T1 values('John',1)
insert T1 values('JohN',1)
insert T1 values('JohN',1)
insert T1 values('john',1)
insert T1 values('john',1)
insert T1 values('john',1)
go
select DISTINCT(col1) from T1
go
col1
-----
John
(1 row(s) affected)
col1
-----
John
JOhn
JoHn
JohN
john
(5 row(s) affected)
SELECT sum(col2)'col2 Group Totals' from T1 group by col1
go
col2 Group Totals
-----------------
12
(1 row(s) affected)
SELECT * from T1 order by col1
go
col1 col2
----- -----------
John 1
John 1
JOhn 1
JOhn 1
JoHn 1
JoHn 1
John 1
JohN 1
JohN 1
john 1
john 1
john 1
(12 row(s) affected)
SELECT * from T1 where col1='john'
go
col1 col2
----- -----------
John 1
John 1
JOhn 1
JOhn 1
JoHn 1
JoHn 1
John 1
JohN 1
JohN 1
john 1
john 1
john 1
(12 row(s) affected)
select col1,'=',CONVERT(binary(5),col1)'hex values' from T1
col1 hex values
----- - ------------
John = 0x4a6f686e20
John = 0x4a6f686e20
JOhn = 0x4a4f686e20
John = 0x4a4f686e20
JoHn = 0x4a6f486e20
JoHn = 0x4a6f486e20
John = 0x4a6f686e20
JohN = 0x4a6f684e20
JohN = 0x4a6f684e20
john = 0x6a6f686e20
john = 0x6a6f686e20
john = 0x6a6f686e20
(12 row(s) affected)
select DISTINCT(CONVERT(binary(5),col1))'col1'
into #t1
from T1
go
select CONVERT(char(5),col1)'distinct character results' from #t1
go
(5 row(s) affected)
-----
JOhn
JoHn
JohN
John
john
(5 row(s) affected)
select DISTINCT(CONVERT(binary(5),col1))'col1',sum(col2)'col2'
into #t1
from T1
group by CONVERT(binary(5),col1)
go
select CONVERT(char(5),col1)'distinct character results',col2'Group
Totals'
from #t1
go
(5 row(s) affected)
distinct character results Group Totals
-------------------------- ------------
JOhn 2
JoHn 2
JohN 2
John 3
john 3
(5 row(s) affected)
SELECT *
from T1
order by CONVERT(binary(5),col1)
go
col1 col2
----- -----------
JOhn 1
JOhn 1
JoHn 1
JoHn 1
JohN 1
JohN 1
John 1
John 1
John 1
john 1
john 1
john 1
(12 row(s) affected)
SELECT *
from T1
where CONVERT(binary(5),col1)=CONVERT(binary(5),'john ')
go
col1 col2
----- -----------
john 1
john 1
john 1
(3 row(s) affected)
Additional query words: hex
Keywords : kbusage SSrvGen
Version : WINDOWS NT:6.0 6.5
Platform : winnt
Issue type : kbhowto kbinfo
Last Reviewed: April 16, 1999