Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

MAX behavior difference with nvarchar and varchar column types Expand / Collapse
Author
Message
Posted Wednesday, November 21, 2012 10:29 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, November 26, 2012 3:07 AM
Points: 5, Visits: 20
Hi All,
We are getting different results for MAX function with nvarchar and varchar columns.

create table my_table(id1 nvarchar(10), id2 varchar(10);

insert into my_table('-1','-1);
insert into my_table('1','1);

select max(id1) from my_table; -> -1

but

select max(id2) from my_table; -> 1

is it the default behavior? Any way to change this?


Regards
Post #1387693
Posted Wednesday, November 21, 2012 10:41 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Today @ 12:37 AM
Points: 3,627, Visits: 5,270
Change the COLLATE for one of the columns.

Try this:

create table my_table(id1 nvarchar(10), id2 varchar(10))

SELECT TABLE_NAME, COLUMN_NAME,CHARACTER_SET_NAME, COLLATION_NAME
FROM information_schema.columns
WHERE TABLE_NAME = 'my_table'

insert into my_table VALUES ('-1','-1');
insert into my_table VALUES ('1','1');

SELECT MAX(id1 COLLATE Latin1_General_Bin2), MAX(id2)
FROM my_table

DROP table my_table


You can see from the first SELECT that these columns have the same COLLATE sequence but different character sets. Changing to a binary collation resolves the issue you inquired about. Be warned that it may also cause other undesired side effects (test, test, test!).



My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1387698
Posted Monday, November 26, 2012 3:09 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, November 26, 2012 3:07 AM
Points: 5, Visits: 20
Thanks very much for you answer.
Post #1388490
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse