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


GetDateInString


GetDateInString

Author
Message
HildaJ
HildaJ
SSC-Addicted
SSC-Addicted (489 reputation)SSC-Addicted (489 reputation)SSC-Addicted (489 reputation)SSC-Addicted (489 reputation)SSC-Addicted (489 reputation)SSC-Addicted (489 reputation)SSC-Addicted (489 reputation)SSC-Addicted (489 reputation)

Group: General Forum Members
Points: 489 Visits: 571
Comments posted to this topic are about the item GetDateInString
jayanthraj99
jayanthraj99
Forum Newbie
Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)

Group: General Forum Members
Points: 1 Visits: 18
hi

let me know below query satisfy requirement or not .
thanks
Jayanth

CREATE FUNCTION [Global].[fn_GetDateInString]
(
@InputString AS NVARCHAR(500)
)
RETURNS NVARCHAR(50)
AS
BEGIN
DECLARE @output AS nvarchar(100)
SELECT @output = Convert(varchar,convert(Date, @InputString, 107),107)
return @output
END
HildaJ
HildaJ
SSC-Addicted
SSC-Addicted (489 reputation)SSC-Addicted (489 reputation)SSC-Addicted (489 reputation)SSC-Addicted (489 reputation)SSC-Addicted (489 reputation)SSC-Addicted (489 reputation)SSC-Addicted (489 reputation)SSC-Addicted (489 reputation)

Group: General Forum Members
Points: 489 Visits: 571
That would work if all you had was the date in different formats. However, the main purpose that I had to write the scripts was because we have a database that is varchar(500) and the user enters with the narrative a data value. I'm extracting if found this value.
ChrisM@Work
ChrisM@Work
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16602 Visits: 19557
-- Convert to an inline table-valued function: more efficient.
-- minimise the work done to identify a date within a string.

DECLARE @InputString NVARCHAR(500) = 'ABC01/01/2013XYZ'

SELECT
DateString = CASE WHEN ISDATE(PatternString) = 1 THEN PatternString ELSE NULL END
FROM (
-- look for a date pattern in the string, stop if found.
SELECT PatternString = CASE
-- date format as 01/01/2012
WHEN PATINDEX('%[0-9][0-9]/[0-9][0-9]/[0-9][0-9][0-9][0-9]%',@InputString) > 0
THEN LEFT(SUBSTRING(@InputString,PATINDEX('%[0-9][0-9]/[0-9][0-9]/[0-9][0-9][0-9][0-9]%',@InputString),StringLen),10)
-- date format as 1/01/2012
WHEN PATINDEX('%[0-9]/[0-9][0-9]/[0-9][0-9][0-9][0-9]%',@InputString) > 0
THEN LEFT(SUBSTRING(@InputString,PATINDEX('%[0-9]/[0-9][0-9]/[0-9][0-9][0-9][0-9]%',@InputString),StringLen),9)
-- date format as 01/1/2012
WHEN PATINDEX('%[0-9][0-9]/[0-9]/[0-9][0-9][0-9][0-9]%',@InputString) > 0
THEN LEFT(SUBSTRING(@InputString,PATINDEX('%[0-9][0-9]/[0-9]/[0-9][0-9][0-9][0-9]%',@InputString),StringLen),9)
-- date format as 1/1/2012
WHEN PATINDEX('%[0-9]/[0-9]/[0-9][0-9][0-9][0-9]%',@InputString) > 0
THEN LEFT(SUBSTRING(@InputString,PATINDEX('%[0-9]/[0-9]/[0-9][0-9][0-9][0-9]%',@InputString),StringLen),8)
-- date format as 01/11/12
WHEN PATINDEX('%[0-9][0-9]/[0-9][0-9]/[0-9][0-9]%',@InputString) > 0
THEN LEFT(SUBSTRING(@InputString,PATINDEX('%[0-9][0-9]/[0-9][0-9]/[0-9][0-9]%',@InputString),StringLen),8)
-- date format as 01/1/12
WHEN PATINDEX('%[0-9][0-9]/[0-9]/[0-9][0-9]%',@InputString) > 0
THEN LEFT(SUBSTRING(@InputString,PATINDEX('%[0-9][0-9]/[0-9]/[0-9][0-9]%',@InputString),StringLen),8)
-- date format as 1/11/12
WHEN PATINDEX('%[0-9]/[0-9][0-9]/[0-9][0-9]%',@InputString) > 0
THEN LEFT(SUBSTRING(@InputString,PATINDEX('%[0-9]/[0-9][0-9]/[0-9][0-9]%',@InputString),StringLen),7)
-- date format as 1/1/12
WHEN PATINDEX('%[0-9]/[0-9]/[0-9][0-9]%',@InputString) > 0
THEN LEFT(SUBSTRING(@InputString,PATINDEX('%[0-9]/[0-9]/[0-9][0-9]%',@InputString),StringLen),6)

-- another 80 or so options...
ELSE NULL END
FROM (SELECT StringLen = LEN(@InputString)) s
) d



“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
bli-963763
bli-963763
Forum Newbie
Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)

Group: General Forum Members
Points: 1 Visits: 35
I would never write a so complicated script for this simple functionality. It's too hard to maintain.
ChrisM@Work
ChrisM@Work
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16602 Visits: 19557
bli-963763 (1/17/2013)
I would never write a so complicated script for this simple functionality. It's too hard to maintain.


I'd very much like to see your simpler version.

“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
HildaJ
HildaJ
SSC-Addicted
SSC-Addicted (489 reputation)SSC-Addicted (489 reputation)SSC-Addicted (489 reputation)SSC-Addicted (489 reputation)SSC-Addicted (489 reputation)SSC-Addicted (489 reputation)SSC-Addicted (489 reputation)SSC-Addicted (489 reputation)

Group: General Forum Members
Points: 489 Visits: 571
Hard to maintain it's really not an option when it comes to working with databases, you got to do what you got to do. Data entered by users can be very tricky and whether you like it or not as a DBA your job is to maintain it, easy or difficult it's part of the job.

What you have to consider is what's the simplest and better out of all the options. ChrisM's version believe it or not is easier and simpler to maintain than the version I wrote.

BTW thanks ChrisM.
ChrisM@Work
ChrisM@Work
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16602 Visits: 19557
HildaJ (1/17/2013)
Hard to maintain it's really not an option when it comes to working with databases, you got to do what you got to do. Data entered by users can be very tricky and whether you like it or not as a DBA your job is to maintain it, easy or difficult it's part of the job.

What you have to consider is what's the simplest and better out of all the options. ChrisM's version believe it or not is easier and simpler to maintain than the version I wrote.

BTW thanks ChrisM.



You're welcome HildaJ. I can easily understand why you wrote this piece of code. Finding a date within a string is trivial if it's in a fixed format.

“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Tim Lehner
Tim Lehner
SSC Rookie
SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)SSC Rookie (35 reputation)

Group: General Forum Members
Points: 35 Visits: 211
ChrisM@Work (1/17/2013)
bli-963763 (1/17/2013)
I would never write a so complicated script for this simple functionality. It's too hard to maintain.


I'd very much like to see your simpler version.


I might try something like this (trying to taking advantage of SQL Server's IsDate function):


-- Find all possible dates in a string column
;with Tally as (
-- Celko-style derived numbers table
select a.n
+ b.n * 10
+ c.n * 100
+ 1 as n
from (select 0 as n union all select 1 union all select 2 union all select 3 union all select 4 union all select 5 union all select 6 union all select 7 union all select 8 union all select 9) a
, (select 0 as n union all select 1 union all select 2 union all select 3 union all select 4 union all select 5 union all select 6 union all select 7 union all select 8 union all select 9) b
, (select 0 as n union all select 1 union all select 2 union all select 3 union all select 4 union all select 5 union all select 6 union all select 7 union all select 8 union all select 9) c
)
select i.n as SubstringIndex
, l.n as SubstringLen
, substring(t.MyColumn, i.n, l.n) as CandidateSubstring
, cast(substring(t.MyColumn, i.n, l.n) as datetime) as InterpretedDateTime
from Tally i
cross join Tally l
cross join MyTable t
where 1 = 1
and i.n + l.n - 1 <= len(t.MyColumn)
and isdate(substring(t.MyColumn, i.n, l.n)) = 1
order by l.n desc, i.n



This is close to the simplest form that I can come up with, though it could be optimized with smarter where/join clauses (what is the max len of a date, etc.). Also, using replace for month names/"st"/"th" might be smart as well, as would using Jeff Moden's Tally table instead of the CTE above. And again, we're at the mercy of IsDate, so would have to massage the data (possibly using replace and such) to fit the mold.

That said, the OP has a great function. Fun stuff. Thanks!
Tom Hamilton
Tom Hamilton
Hall of Fame
Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)

Group: General Forum Members
Points: 3269 Visits: 781
Nice work Hilda - I have fought that dragon too with embedded dates in large text fields.... I like your solution. Since I'm also a dot.net guy my approach is via a CLR. I appreciate your work, thank you :-)

Tom in Sacramento
For better, quicker answers on T-SQL questions, click on the following...
http://www.sqlservercentral.com/articles/Best+Practices/61537/
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