Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 

SQLStudies

My name is Kenneth Fisher and I am Senior DBA for a large (multi-national) insurance company. I have been working with databases for over 20 years starting with Clarion and Foxpro. I’ve been working with SQL Server for 12 years but have only really started “studying” the subject for the last 3. I don’t have any real "specialities" but I enjoy trouble shooting and teaching. Thus far I’ve earned by MCITP Database Administrator 2008, MCTS Database Administrator 2005, and MCTS Database Developer 2008. I’m currently studying for my MCITP Database Developer 2008 and should start in on the 2012 exams next year. My blog is at www.sqlstudies.com.

Collation: Expression

I had a recent run in with collation problems and it got me started reading. As I read I started to realize that for a seemingly simple subject there was a lot to it. So I thought I would go over some of what I found out.

Once you have installed your instance, created your database and tables you are now ready to start running queries. This is the point where you might have to change collations at an expression level. In order to make this change you use the COLLATE clause. This clause can be used after any string column or variable in a query. For example let’s say you have a table as such:

-- Create table with a column with a Case Insensative collation
CREATE TABLE Collate_Test (
	Id int NOT NULL IDENTITY(1,1),
	Name varchar(50) COLLATE SQL_Latin1_General_CP1_CI_AS NULL 
	);
-- Insert a list of the same name but different cases
INSERT INTO Collate_Test VALUES
	('kenneth'),
	('Kenneth'),
	('KENneth'),
	('KENNEth'),
	('KENNETH'),
	('fisher'),
	('Fisher'),
	('FISher'),
	('FISHer'),
	('FISHER');
GO

When you run the query

SELECT *
FROM Collate_Test
ORDER BY Name;
GO

You should get the following result. Note the order of the identity column. I put it in there to help see the sort difference.

CollationExpression1

But now you want a case sensitive sort by name.

SELECT *
FROM Collate_Test
ORDER BY Name COLLATE SQL_Latin1_General_CP1_CS_AS;
GO

Note that the order of the column has changed. Again the identity column is there to help see the sort difference.

CollationExpression2

Now let’s add a variable @Name. When we run the following query without the COLLATE clause we get all of the “kenneth” rows back.

DECLARE @Name varchar(50);
SET @Name = 'Kenneth';

SELECT *
FROM Collate_Test
WHERE Name = @Name;
GO

CollationExpression3

But if we add the collate clause to make the variable case sensitive we get rather different results.

DECLARE @Name varchar(50);
SET @Name = 'Kenneth';

SELECT *
FROM Collate_Test
WHERE Name = @Name COLLATE SQL_Latin1_General_CP1_CS_AS;
GO

CollationExpression4

You should be aware that I could have put the COLLATE clause on the column instead of the variable or on both the column and the variable and it would have worked just fine.


Over a number of different posts I’m going to discuss some of the surprisingly deep subject of collation.

As a start listen to Rob Farley’s hilarious talk on collation
Collation: Definition
Collation: Location
Collation: Correction -> Expression, Column, Database
Collation: Correction -> Instance
Collation: Temporary objects & variables: Demonstration
Collation: Confusion


Filed under: Collation, Microsoft SQL Server, SQLServerPedia Syndication, T-SQL Tagged: code language, collation, language sql, microsoft sql server, T-SQL

Comments

Leave a comment on the original post [sqlstudies.com, opens in a new window]

Loading comments...