Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase ««123»»

Find integer at end of a string. There *must* be a better solution ? Expand / Collapse
Author
Message
Posted Thursday, July 25, 2013 6:11 PM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 5:50 PM
Points: 7,923, Visits: 9,649
Thorkil Johansen (7/25/2013)

Someone said: Looks like 123.4 is not an integer, so -1 should be returned.

Yes, that's right


So if the string were xyz-1-2.3-2 what's the required answer?
2, because -2 are the last two characters? or -1 because -1-2.3-2 isn't an integer?


Tom
Post #1477812
Posted Friday, July 26, 2013 12:34 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Sunday, July 27, 2014 4:06 AM
Points: 11, Visits: 50
Hi Tom

I have the assumption that only one hyphen will be in the string, but if the case was
xyz-1-2.3-2
then 2 would be the right answer...

To sharpen a little: "The integer to the right of the last hyphen in the string"
/T
Post #1477871
Posted Friday, July 26, 2013 2:49 AM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Yesterday @ 9:53 PM
Points: 3,438, Visits: 5,390
My contribution ain't exactly pretty but might work for you:

with tmp as (
select x = 'some text-1'
union select x = 'some text-123'
union select x = 'some text-123.4'
union select x = 'some text 123'
union select x = 'some text-'
union select x = 'some text'
union select x = 'some text-xyz'
)
SELECT x,
CASE
WHEN EndStr IN (0,1) THEN -1
WHEN 0=ISNUMERIC(RIGHT(x, EndStr-1)) THEN -1
WHEN FLOOR(RIGHT(x, EndStr-1)) = RIGHT(x, EndStr-1)
THEN CAST(RIGHT(x, EndStr-1) AS INT)
ELSE -1
END
FROM tmp a
CROSS APPLY (SELECT CHARINDEX('-', REVERSE(x))) b(EndStr);





My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1477908
Posted Friday, July 26, 2013 3:30 AM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: 2 days ago @ 1:30 AM
Points: 2,386, Visits: 7,622
Forgive me for my simplistic approach

WITH tmp
AS (SELECT x = 'some text-1'
UNION ALL SELECT x = 'some text-123'
UNION ALL SELECT x = 'some text-123.4'
UNION ALL SELECT x = 'some text 123'
UNION ALL SELECT x = 'some text-'
UNION ALL SELECT x = 'some text'
UNION ALL SELECT x = 'some text-xyz'
UNION ALL SELECT x = 'xyz-1-2.3-2'
)
SELECT *,
CASE WHEN x LIKE '%-[0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN REVERSE(SUBSTRING(REVERSE(x),0,CHARINDEX('-',REVERSE(x))))
ELSE - 1 END
FROM tmp;


--EDIT--
Quick performance check. Note, I borrowed Dwain's method for grabbing the last digits as I figured it'd be quicker than the reverse reverse as SQL is not good at string manipulation.

SET NOCOUNT ON;

IF object_id('tempdb..#testEnvironment') IS NOT NULL
BEGIN
DROP TABLE #testEnvironment;
END;

--1,000,000 Random rows of data
SELECT TOP 1000000 IDENTITY(INT,1,1) AS ID,
'some text'+ CASE WHEN (ABS(CHECKSUM(NEWID())) % 100) + 1 >= 50 THEN '-' ELSE '' END +
CASE WHEN (ABS(CHECKSUM(NEWID())) % 100) + 1 >= 50 AND CHARINDEX('.',CAST(RAND(CHECKSUM(NEWID())) * 100 AS VARCHAR(MAX))) > 3
THEN SUBSTRING(CAST(RAND(CHECKSUM(NEWID())) * 100 AS VARCHAR(MAX)),0,CHARINDEX('.',CAST(RAND(CHECKSUM(NEWID())) * 100 AS VARCHAR(MAX)))-1)
ELSE CAST(RAND(CHECKSUM(NEWID())) * 100 AS VARCHAR(MAX)) END AS x
INTO #testEnvironment
FROM master.dbo.syscolumns sc1, master.dbo.syscolumns sc2, master.dbo.syscolumns sc3;

DECLARE @Loop CHAR(1) = '0', @HOLDER INT, @Duration CHAR(12), @StartTime DATETIME;

WHILE @Loop <= 5
BEGIN
RAISERROR('Loop: %s',0,1,@Loop) WITH NOWAIT;
RAISERROR('============',0,1) WITH NOWAIT;
DBCC FREEPROCCACHE WITH NO_INFOMSGS;
DBCC DROPCLEANBUFFERS WITH NO_INFOMSGS;

SELECT @StartTime = GETDATE();

SELECT @HOLDER =
CASE WHEN x LIKE '%-[0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
WHEN x LIKE '%-[0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9][0-9]' THEN RIGHT(x,CHARINDEX('-',REVERSE(x))-1)
ELSE - 1 END
FROM #testEnvironment;

SELECT @Duration = CONVERT(CHAR(12),GETDATE()-@StartTime,114);
RAISERROR('BIG CASE Duration: %s',0,1,@Duration) WITH NOWAIT;

DBCC FREEPROCCACHE WITH NO_INFOMSGS;
DBCC DROPCLEANBUFFERS WITH NO_INFOMSGS;

SELECT @StartTime = GETDATE();


SELECT @HOLDER =
CASE
WHEN EndStr IN (0,1) THEN -1
WHEN 0=ISNUMERIC(RIGHT(x, EndStr-1)) THEN -1
WHEN FLOOR(RIGHT(x, EndStr-1)) = RIGHT(x, EndStr-1)
THEN CAST(RIGHT(x, EndStr-1) AS INT)
ELSE -1
END
FROM #testEnvironment a
CROSS APPLY (SELECT CHARINDEX('-', REVERSE(x))) b(EndStr);

SELECT @Duration = CONVERT(CHAR(12),GETDATE()-@StartTime,114);
RAISERROR('COOL MATHS Duration: %s',0,1,@Duration) WITH NOWAIT;

SET @Loop = @Loop + 1;
END

Loop: 0
============
BIG CASE Duration: 00:00:51:533
COOL MATHS Duration: 00:00:12:057
Loop: 1
============
BIG CASE Duration: 00:00:52:107
COOL MATHS Duration: 00:00:11:967
Loop: 2
============
BIG CASE Duration: 00:00:53:087
COOL MATHS Duration: 00:00:12:240
Loop: 3
============
BIG CASE Duration: 00:00:52:077
COOL MATHS Duration: 00:00:12:100
Loop: 4
============
BIG CASE Duration: 00:00:51:477
COOL MATHS Duration: 00:00:11:970
Loop: 5
============
BIG CASE Duration: 00:00:52:023
COOL MATHS Duration: 00:00:12:010


Pretty consistent win for Dwain's solution over mine. The results show a similar pattern with an index (big case took around 50 seconds but the maths reduced down to around 7 seconds).



Not a DBA, just trying to learn

For better, quicker answers on T-SQL questions, click on the following...
http://www.sqlservercentral.com/articles/Best+Practices/61537/

For better, quicker answers on SQL Server performance related questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/



If you litter your database queries with nolock query hints, are you aware of the side effects?
Try reading a few of these links...

(*) Missing rows with nolock
(*) Allocation order scans with nolock
(*) Consistency issues with nolock
(*) Transient Corruption Errors in SQL Server error log caused by nolock
(*) Dirty reads, read errors, reading rows twice and missing rows with nolock


LinkedIn | Blog coming soon (for sufficiently large values of "soon" )!
Post #1477914
Posted Friday, July 26, 2013 5:32 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 2:33 PM
Points: 12,953, Visits: 32,483
Cadavre I love your new signature with the nolock pointers! just noticed it today.


Lowell

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #1477947
Posted Friday, July 26, 2013 8:19 AM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: 2 days ago @ 1:30 AM
Points: 2,386, Visits: 7,622
Lowell (7/26/2013)
Cadavre I love your new signature with the nolock pointers! just noticed it today.


I added it after the last time I had to dig them all out



Not a DBA, just trying to learn

For better, quicker answers on T-SQL questions, click on the following...
http://www.sqlservercentral.com/articles/Best+Practices/61537/

For better, quicker answers on SQL Server performance related questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/



If you litter your database queries with nolock query hints, are you aware of the side effects?
Try reading a few of these links...

(*) Missing rows with nolock
(*) Allocation order scans with nolock
(*) Consistency issues with nolock
(*) Transient Corruption Errors in SQL Server error log caused by nolock
(*) Dirty reads, read errors, reading rows twice and missing rows with nolock


LinkedIn | Blog coming soon (for sufficiently large values of "soon" )!
Post #1478029
Posted Friday, July 26, 2013 3:58 PM


SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Friday, December 12, 2014 1:02 AM
Points: 823, Visits: 753
with tmp as (
select x = 'some text-1'
union select x = 'some text-123'
union select x = 'some text-123.4'
union select x = 'some text 123'
union select x = 'some text-'
union select x = 'some text'
union select x = 'some text-xyz'
)
select * ,
coalesce( TRY_CONVERT(int,
nullif(SUBSTRING(x, 1 + nullif(CHARINDEX('-',x), 0), LEN(x)),
'')),
-1)
from tmp

LEN(x) - charindex can be reduced to LEN(x), since you want the rest of the string. I removed the outer CASE and replaced it with two NULLIF. One to capture that therte are no hyphen at all, and one to capture that there are only spaces after the hyphen.

There was a question about multiple hyphens. My assumptions from the original post is that the integer should be from the hyphen to the end of the string, so Abc-2-3 should return -1.


Erland Sommarskog, SQL Server MVP, www.sommarskog.se
Post #1478230
Posted Friday, July 26, 2013 6:51 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Yesterday @ 9:53 PM
Points: 3,438, Visits: 5,390
Cadavre - I love the name you gave mine: "COOL MATHS/"

I suspect it might have a bug though where the string ends like -$ (might show 0).



My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1478252
Posted Saturday, July 27, 2013 7:36 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Sunday, July 27, 2014 4:06 AM
Points: 11, Visits: 50
Nice one...

I have the assumption that only one hyphen will be in the string, but if the case was
xyz-1-2.3-2
then 2 would be the right answer...

To sharpen a little: "The integer to the right of the last hyphen in the string"
Post #1478282
Posted Saturday, July 27, 2013 12:20 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 8:47 PM
Points: 35,770, Visits: 32,436
The use of IsNumeric in onne of the solutions serves as a reminder that there are a whole lot of things that look like numbers to SQLServer. Here's some updated test data to see what I mean...

with tmp as 
(
SELECT x = 'some text-1'
UNION ALL SELECT x = 'some text-123'
UNION ALL SELECT x = 'some text-123.4'
UNION ALL SELECT x = 'some text 123'
UNION ALL SELECT x = 'some text-'
UNION ALL SELECT x = 'some text- ' --Added this for possible CHAR values
UNION ALL SELECT x = 'some text- 123 ' --Added "stray bullet"
UNION ALL SELECT x = 'some text-123 456' --Added "stray bullet"
UNION ALL SELECT x = 'some text-123d4' --Added "stray bullet"
UNION ALL SELECT x = 'some text-123e4' --Added "stray bullet"
UNION ALL SELECT x = 'some text-$1,234' --Added "stray bullet"
UNION ALL SELECT x = 'some text-1,234' --Added "stray bullet"
UNION ALL SELECT x = 'some text-0x1234,' --Added "stray bullet"
UNION ALL SELECT x = 'some text'
UNION ALL SELECT x = 'some text-xyz'
)
... put your code here ...



--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1478301
« Prev Topic | Next Topic »

Add to briefcase ««123»»

Permissions Expand / Collapse