Case Sensitive Search on a Case Insensitive SQL Server

By:   |   Updated: 2006-08-03   |   Comments (19)   |   Related: 1 | 2 | 3 | 4 | 5 | 6 | 7 | 8 | 9 | > Query Optimization


Problem

Most SQL Server installations are installed with the default collation which is case insensitive.  This means that SQL Server ignores the case of the characters and treats the string '1 Summer Way' equal to the string '1 summer way'.  If you need to differentiate these values and are unable to change the collation at the server, database or column level, how can you differentiate these values?

Solution

One option is to specify the collation for the query to use a case sensitive configuration.  Let's show an example of a case sensitive search on a case insensitive SQL Server.

What is the collation?

As you can see, this SQL Server has a case insensitive collation i.e. CI.

SELECT SERVERPROPERTY ('Collation')
GO
Result Set
SQL_Latin1_General_CP1_CI_AS

Create sample database and data

-- Select database to create these objects
USE [YourDatabaseName]
GO

-- Create the table
CREATE TABLE [dbo].[CaseSensitiveTest] (
        [UID] [int] NOT NULL ,
        [Value1] [varchar] (50) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL ,
        [DescValue1] [varchar] (50) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL
) ON [PRIMARY]
GO

-- Add primary key
ALTER TABLE [dbo].[CaseSensitiveTest] WITH NOCHECK ADD
        CONSTRAINT [PK_CaseSensitiveTest] PRIMARY KEY  CLUSTERED
        (
                [UID]
        )  ON [PRIMARY]
GO

-- Select server collation and sort information
SELECT SERVERPROPERTY('Collation'),
SERVERPROPERTY('SqlSortOrder')
GO

-- Insert test records
INSERT INTO CaseSensitiveTest VALUES (1, 'TEST', 'All Upper Case')
INSERT INTO CaseSensitiveTest VALUES (2, 'test', 'All Lower Case')
INSERT INTO CaseSensitiveTest VALUES (3, 'Test', 'Mixed Case')
INSERT INTO CaseSensitiveTest VALUES (4, 'TEST1', 'All Upper Case')
INSERT INTO CaseSensitiveTest VALUES (5, 'test1', 'All Lower Case')
INSERT INTO CaseSensitiveTest VALUES (6, 'Test1', 'Mixed Case')
INSERT INTO CaseSensitiveTest VALUES (7, '123Test', 'Mixed Case')

What does the sample data look like?

The sample data has a mix of upper case, lower case and mixed case data as the 7 records show below.

-- Select all records where value like Test
SELECT *
FROM dbo.CaseSensitiveTest
WHERE Value1 LIKE '%Test%'
GO
Result Set
UID Value1 DescValue1
1 TEST All Upper Case
2 test All Lower Case
3 Test Mixed Case
4 TEST1 All Upper Case
5 test1 All Lower Case
6 Test1 Mixed Case
7 123Test Mixed Case

How can I just capture the rows with the mixed case test values i.e. 'Test'?

Check out this query where a case sensitive collation is used:

-- Select all records where value like Test
SELECT *
FROM dbo.CaseSensitiveTest
WHERE Value1 LIKE '%Test%' COLLATE SQL_Latin1_General_Cp1_CS_AS
GO
Result Set
UID Value1 DescValue1
3 Test Mixed Case
6 Test1 Mixed Case
7 123Test Mixed Case

As you can see, only the 3 records where the 'Test' string is in mixed case are returned.

Next Steps


sql server categories

sql server webinars

subscribe to mssqltips

sql server tutorials

sql server white papers

next tip



About the author
MSSQLTips author Jeremy Kadlec Jeremy Kadlec is a Co-Founder, Editor and Author at MSSQLTips.com with more than 300 contributions. He is also the CTO @ Edgewood Solutions and a six-time SQL Server MVP. Jeremy brings 20+ years of SQL Server DBA and Developer experience to the community after earning a bachelor's degree from SSU and master's from UMBC.

This author pledges the content of this article is based on professional experience and not AI generated.

View all my tips


Article Last Updated: 2006-08-03

Comments For This Article




Thursday, November 19, 2020 - 6:34:42 PM - Jeremy Kadlec Back To Top (87812)
Ozair,

Can you please post the code and error message you received to determine the issue?

Thank you,
Jeremy Kadlec

Thursday, November 19, 2020 - 7:22:12 AM - Ozair Kafray Back To Top (87809)
This did not work for me on SQL Server version 15.0.2000.5

Thursday, June 14, 2018 - 3:14:49 AM - vishwas Back To Top (76216)

 Thanks a lot ....It's working fine

 


Friday, July 22, 2016 - 2:29:10 PM - Ron Clarke Back To Top (41954)

 Jeremy,

I finally got this to work for me after I figured out that specifying ranges overrides the COLLATE, i.e. when I specified LIKE '[a-c]' COLLATE SQL_Latin1_General_CP1_CS_AS, it is not case sensitive. If instead I specify LIKE '[abc]' COLLATE SQL_Latin1_General_CP1_CS_AS, then it does a case sensitive match.

Have Fun!

Ron

 


Wednesday, May 25, 2016 - 1:54:05 PM - Beverley Back To Top (41559)

Thanks!  We have a case-insensitive server but a case-sensitive application that gets whiny if a particular field isn't in full uppercase.  Until we can fix the application to deal with it properly, I occasionally need to find any entries that have the wrong capitalization.  This helped me find them much more quickly than manual inspection!


Wednesday, September 17, 2014 - 4:55:02 PM - Michelle Back To Top (34567)

This was just what I needed. We have a database that we generally want to be case insensitive, but if the case on names doesn’t match a comparison table from another system we need to do an update For instance if a name was entered as Mcpherson, then gets corrected to McPherson in the other system, we want to “see” that in our system and correct it there too. That will be the only time case matters.This was just what I needed. We have a database that we generally want to be case insensitive, but if the case on names doesn’t match a comparison table from another system we need to do an update For instance if a name was entered as Mcpherson, then gets corrected to McPherson in the other system, we want to “see” that in our system and correct it there too. That will be the only time case matters.

Thanks!

 

-- I did something like this as proof of concept. Gender is always
-- all caps in the database. The database is case insensitive If I use 
-- lower case, for my comparison value it will not return any results.

SELECT Gender
FROM MyDatabase
WHERE Gender Collate SQL_Latin1_General_CP1_CS_AS = 'm';


Wednesday, June 4, 2014 - 2:32:14 PM - David Back To Top (32083)

You totally ROCK!!!


Thursday, May 9, 2013 - 1:52:04 PM - Kiran Back To Top (23844)

Sorry Neema,

Your tip doesn't works in my case i.e., SQL_Latin1_General_CP1_CI_AS

It works works with Jeremy's tip i.e., SQL_Latin1_General_CP1_CS_AS

Neema I am not sure you are correct

 


Tuesday, May 7, 2013 - 3:29:44 AM - Irfan Kumte Back To Top (23756)

 

 

 

Extremely helpful. Thanx.


Sunday, May 5, 2013 - 12:56:48 AM - Sumit Back To Top (23724)

Great! It is working for me. Thank you very much.


Sunday, March 24, 2013 - 1:40:22 PM - Max Back To Top (22990)

Thanks it helped allot 

thnku so much


Friday, January 11, 2013 - 6:13:27 PM - Jeremy Kadlec Back To Top (21414)

Stortman,

Great!  I am happy to hear it!

Thank you,
Jeremy Kadlec
Community Co-Leader


Wednesday, January 9, 2013 - 6:45:21 PM - Stortman Back To Top (21356)

Thanks for publishing this. I am developing using a desktop PC running SQL Server 2008 Management Studio and VWD 2010 Express under Win XP PRO SP3. The default installation is for case insensitive matching. I need case sensitive matching  in a stored procedure for valdating SQL Server user passwords stored in the database. This worked a treat. A localised fix.

SELECT @ImpId = ImpId

FROM dbo.Imp

WHERE ImpUserName = @ImpUserName

AND ImpPassword = @ImpPassword Collate SQL_Latin1_General_CP1_CS_AS

AND ...........

 

 


Tuesday, April 10, 2012 - 2:56:48 PM - Jeremy Kadlec Back To Top (16839)

Tom,

I am happy to hear it!

Thank you,
Jeremy Kadlec


Tuesday, April 10, 2012 - 11:56:24 AM - Tom Holden Back To Top (16837)

 

Of course that works like a charm.  Thank you.

Tom Holden


Friday, November 19, 2010 - 3:52:54 PM - Jeremy Kadlec Back To Top (10381)

Vipul,

Good afternoon.  Can you please post your code (or a sample) so we have something to work with?

When you work through the examples in the tip, do they work for you?

What version of SQL Server are you using?

Thank you,
Jeremy Kadlec


Friday, November 19, 2010 - 6:16:00 AM - Vipul patel Back To Top (10377)

when i use collate in my sql statement it's not working.. so tell me what's the problem in my sql server...


Friday, June 25, 2010 - 8:53:43 AM - nosnetrom Back To Top (5749)
Another good one--and thanks to Neema for the correction/clarification!

Wednesday, May 28, 2008 - 4:07:05 PM - Neema Back To Top (1052)

Thanks, this is a great tip!

I think you probably meant to use the collation _CS_ in the example you gave on the WHERE clause. You have a SQL statement that uses _CI.

Here's what I'm talking about: 

Check out this query where a case sensitive collation is used:

T-SQL Command

SELECT *
FROM dbo.CaseSensitiveTest
WHERE Value1 LIKE '%Test%' Collate
SQL_Latin1_General_CP1_CI_AS
GO

Result Set

UID Value1 DescValue1
3 Test Mixed Case
6 Test1 Mixed Case
7 123Test Mixed Case
 

As you can see, only the 3 records where the 'Test' string is in mixed case are returned.

Anyway, I did know what you were talking about so it is not a problem. Thanks once again for the tip.















get free sql tips
agree to terms