February 17, 2011 at 4:57 am
Hi
I need to select only the characters 'M0', 'M1' or 'M2' (or preferably just the numbers 0,1,2) from within a text field (called GRADE) as follows:
GRADE
R1 - Background, M0 - No Maculopathy
NULL
R0 - No Retinopathy, M0 - No Maculopathy
R0 - No Retinopathy, M0 - No Maculopathy
R0 - No Retinopathy, M0 - No Maculopathy
R1 - Background, M2 - No Maculopathy
R0 - No Retinopathy, M0 - No Maculopathy, P1 - Photocoagulation
R0 - No Retinopathy, M0 - No Maculopathy
R0 - No Retinopathy, M0 - No Maculopathy
R1 - Background, M1- No Maculopathy
Substring won't work as the characters occur in different positions within the strings. I was wondering if anyone had any ideas?
Any help greatly appreciated.
Cheers
-Rich
February 17, 2011 at 6:15 am
Thanks for the reply.
However, I don't actually want the position of the characters i.e. I actuallly want the output to be:
either
Grade
M0
M1
M2
etc
or
Grade
0
1
2
Reason being I need to compare the numeric values with those in a similar field to see which is highest (we can ignore null values for now).
Apologies if I've misunderstood.
Cheers
-Rich
February 17, 2011 at 6:31 am
Obviously you have to use the PATINDEX to do the SUBSTRING:
-- *** Test Data ***
CREATE TABLE #t
(
Grade varchar(8000) NULL
)
INSERT INTO #t
SELECT 'R1 - Background, M0 - No Maculopathy'
UNION ALL SELECT NULL
UNION ALL SELECT 'R0 - No Retinopathy, M0 - No Maculopathy'
UNION ALL SELECT 'R0 - No Retinopathy, M0 - No Maculopathy'
UNION ALL SELECT 'R0 - No Retinopathy, M0 - No Maculopathy'
UNION ALL SELECT 'R1 - Background, M2 - No Maculopathy'
UNION ALL SELECT 'R0 - No Retinopathy, M0 - No Maculopathy, P1 - Photocoagulation'
UNION ALL SELECT 'R0 - No Retinopathy, M0 - No Maculopathy'
UNION ALL SELECT 'R0 - No Retinopathy, M0 - No Maculopathy'
UNION ALL SELECT 'R1 - Background, M1- No Maculopathy'
-- *** End Test Data ***
SELECT *
,SUBSTRING(Grade, PATINDEX('%M[0-2]%', Grade) + 1, 1) AS MGrade
FROM #T
February 17, 2011 at 7:11 am
That works perfectly and will be very useful in future too.
Many thanks
-Rich
Viewing 5 posts - 1 through 4 (of 4 total)
You must be logged in to reply to this topic. Login to reply