SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


MAX behavior difference with nvarchar and varchar column types


MAX behavior difference with nvarchar and varchar column types

Author
Message
ronyjohn
ronyjohn
Forum Newbie
Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)

Group: General Forum Members
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
dwain.c
dwain.c
SSCoach
SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)

Group: General Forum Members
Points: 17085 Visits: 6431
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!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
ronyjohn
ronyjohn
Forum Newbie
Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)

Group: General Forum Members
Points: 5 Visits: 20
Thanks very much for you answer.
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search