Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Weird Question About Querying with Dates


Weird Question About Querying with Dates

Author
Message
Eric M Russell
Eric M Russell
SSCarpal Tunnel
SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)SSCarpal Tunnel (4.7K reputation)

Group: General Forum Members
Points: 4681 Visits: 9584
Below I've setup a practical illustration of why this matters. Using the exact same SQL query, the sum of payments is 100.00 when LANGUAGE is set to US_ENGLISH, but the sum is 300.00 for ITALIAN and FRENCH.

Thanks, Lynn, for pointing out that YYYYMMDD (not YYYY-MM-DD) is the correct format to use for LANGUAGE and DATEFORMAT setting independence. We have to remember that the application or client tool can apply these settings at the connection level, so it would be best to always use YYYYMMDD format in our SQL queries.

create table #customer_payment  
( primary key( customer_id, payment_date),
customer_id int not null, payment_date datetime not null,
payment_amt smallmoney not null );

insert into #customer_payment
( customer_id, payment_date, payment_amt )
values
( 123, '20120112', 100.00 ),
( 123, '20120505', 100.00 ),
( 123, '20121207', 100.00 );



Then, run the following query under each language:

select sum(payment_amt)payment_amt
from #customer_payment
where customer_id = 123 and payment_date >= '2012-10-01';



SET LANGUAGE US_ENGLISH;
Changed language setting to us_english.

payment_amt
---------------------
100.00


SET LANGUAGE ITALIAN;
L'impostazione della lingua è stata sostituita con Italiano.

payment_amt
---------------------
300.00


Le paramètre de langue est passé à Français.
SET LANGUAGE FRENCH;

payment_amt
---------------------
300.00


However, modifying the search condition to YYYYMMDD format like below, the query returns 100.00 under all three languages.

select sum(payment_amt)payment_amt
from #customer_payment
where customer_id = 123 and payment_date >= '20121001';




"The universe is complicated and for the most part beyond your control, but your life is only as complicated as you choose it to be."
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