December 12, 2013 at 5:46 am
Hi,
i am using sql server 2008 R2,
My requirement is as follows,
I had a string ABCRD1234E
I want to write query to check following things,
1) The length of the string should be minimum 10 digits.
2) First 5 characters must be letters.
3) Next 4 character must be numbers.
4) Next 1 Character must be letter.
5)The fourth letter must be either P,F,R,C,A,H,B,J or L.
First one will achived using Len function,
can any one help me ,for other points.
Thanks in Advance!
December 12, 2013 at 5:54 am
there is some support for patterns/regular expressions in SQL
this does what you are asking, i think. one expression tests exactly ten characters, the other test the first ten characters
WITH mySampleData(val)
AS
(
SELECT 'ABCRD1234E' UNION ALL
SELECT 'ABCRD1234EOTHERDATA' UNION ALL
select RIGHT(NEWID(),10) UNION ALL
select RIGHT(NEWID(),10)
)
SELECT *,
CASE WHEN val LIKE'[A-Z][A-Z][A-Z][PFRCAHBJL][A-Z][0-9][0-9][0-9][0-9][A-Z]' THEN 1 ELSE 0 END AS Match,
CASE WHEN val LIKE'[A-Z][A-Z][A-Z][PFRCAHBJL][A-Z][0-9][0-9][0-9][0-9][A-Z]%' THEN 1 ELSE 0 END AS Match
FROM mySampleData
Lowell
December 12, 2013 at 6:06 am
Lowell (12/12/2013)
there is some support for patterns/regular expressions in SQLthis does what you are asking, i think. one expression tests exactly ten characters, the other test the first ten characters
WITH mySampleData(val)
AS
(
SELECT 'ABCRD1234E' UNION ALL
SELECT 'ABCRD1234EOTHERDATA' UNION ALL
select RIGHT(NEWID(),10) UNION ALL
select RIGHT(NEWID(),10)
)
SELECT *,
CASE WHEN val LIKE'[A-Z][A-Z][A-Z][PFRCAHBJL][A-Z][0-9][0-9][0-9][0-9][A-Z]' THEN 1 ELSE 0 END AS Match,
CASE WHEN val LIKE'[A-Z][A-Z][A-Z][PFRCAHBJL][A-Z][0-9][0-9][0-9][0-9][A-Z]%' THEN 1 ELSE 0 END AS Match
FROM mySampleData
The second CASE statement will fit the requirements
And could be used to find non complient data by
SELECT *
FROM mySampleData
WHERE val NOT LIKE'[A-Z][A-Z][A-Z][PFRCAHBJL][A-Z][0-9][0-9][0-9][0-9][A-Z]%'
Far away is close at hand in the images of elsewhere.
Anon.
Viewing 3 posts - 1 through 2 (of 2 total)
You must be logged in to reply to this topic. Login to reply