CONVERT_TO_DATE function

Often I see people asking this question “Sometimes clients give date values as integers, float or formatted string values. How should we handle this and store them properly and query on it?”

For example October 04, 2010 can be expressed one of the following ways (the number format is dmy)

04102010
04102010.0
041010
4102010
04-oct-2010
04/10/2010
04.10.2010
Oct 4, 2010

In this case the correct way is to convert all of these into proper DATE value and store/use them. You can use the following function

Create function convert_to_date (@date_val varchar(25))
returns datetime
as Begin

Select @date_val=
case when @date_val like '%.0%' then substring(@date_val,1,charindex('.',@date_val)-1)
else @date_val
      
end
return
cast(
      case when @date_val like '%[a-zA-Z-/]%' then
            
case when ISDATE(@date_val)=1 then @date_val else NULL end
      
when len(@date_val)=8 then
            right(@date_val,4)+'-'+substring(@date_val,3,2)+'-'+left(@date_val,2)
      
when len(@date_val)=7 then
            right(@date_val,4)+'-'+substring(@date_val,2,2)+'-0'+left(@date_val,1)
      
when len(@date_val)=6 then
            case when right(@date_val,2)<50 then '20' else '19' end
            
+right(@date_val,2)+'-'+substring(@date_val,3,2)+'-'+left(@date_val,2)
     
when len(@date_val)=5 then
            
case when right(@date_val,2)<50 then '20' else '19' end
            
+right(@date_val,2)+'-'+substring(@date_val,2,2)+'-0'+left(@date_val,1)
else
            
case when ISDATE(@date_val)=1 then @date_val else NULL end
end
as datetime
)
END


Now execute and see how these are converted to proper date values

select
dbo.convert_to_date('04102010'),
dbo.convert_to_date('04102010.0'),
dbo.convert_to_date('041010'),
dbo.convert_to_date('4102010'),
dbo.convert_to_date('04-oct-2010'),
dbo.convert_to_date('10/04/2010'),
dbo.convert_to_date('10-04-2010'),
dbo.convert_to_date('Oct 4,2010'),
dbo.convert_to_date('04 oct ,2010'),
dbo.convert_to_date('October 04 2010')

 
All the above give the output 2010-10-04 00:00:00.000

So you can make use of this function to convert the string values into proper DATETIME value

Advertisements

One thought on “CONVERT_TO_DATE function

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s