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


Convert alphanumeric to BigInt


Convert alphanumeric to BigInt

Author
Message
jchandramouli
jchandramouli
SSChasing Mays
SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)

Group: General Forum Members
Points: 622 Visits: 145
Hi,

I got a table with datas that has alphanumeric values like 1230-544,15C5487,132DE78.

Now i need to extract only integers fomr these datas and convert to bigint. The other characters have no impact in my query. Is there way to produce a data like that?

Thanks in advance.

Mouli

"I Love Walking In The Rain So No One Can See Me Crying ! " ~ Charlie Chaplin
Adi Cohn
Adi Cohn
SSChampion
SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)

Group: General Forum Members
Points: 13235 Visits: 6597
Your post is not very clear. Do you want to get only the records that have only numbers or do you want to get all the records but remove the non numeric characters from your column? Also do you have a list of possible characters, or could that column have all possible characters?

Adi

--------------------------------------------------------------
To know how to ask questions and increase the chances of getting asnwers:
http://www.sqlservercentral.com/articles/Best+Practices/61537/

For better answers on performance questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/
ChiragNS
ChiragNS
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10143 Visits: 1865
Have a look at this

declare @str varchar(100)
select @str = '1230-544,15C5487,132DE78'

;With Breakdown as
(
Select
SubString(@Str,1,1)[Chr],
1[Idx]
Union All
Select
SubString(@Str,Idx+1,1),
Idx+1
from Breakdown
where (Idx+1)<=Len(@Str)
)

select chr from Breakdown where isnumeric(chr) = 1

Edit:- This will return ',' and '-'. You need to filter them out.

"Keep Trying"
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (337K reputation)SSC Guru (337K reputation)SSC Guru (337K reputation)SSC Guru (337K reputation)SSC Guru (337K reputation)SSC Guru (337K reputation)SSC Guru (337K reputation)SSC Guru (337K reputation)

Group: General Forum Members
Points: 337012 Visits: 42591
Chirag (3/23/2009)
Have a look at this

declare @str varchar(100)
select @str = '1230-544,15C5487,132DE78'

;With Breakdown as
(
Select
SubString(@Str,1,1)[Chr],
1[Idx]
Union All
Select
SubString(@Str,Idx+1,1),
Idx+1
from Breakdown
where (Idx+1)<=Len(@Str)
)

select chr from Breakdown where isnumeric(chr) = 1

Edit:- This will return ',' and '-'. You need to filter them out.


Hey there, ol' friend... you do realize that recursive CTE's are slower than even cursors, right?

--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.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (337K reputation)SSC Guru (337K reputation)SSC Guru (337K reputation)SSC Guru (337K reputation)SSC Guru (337K reputation)SSC Guru (337K reputation)SSC Guru (337K reputation)SSC Guru (337K reputation)

Group: General Forum Members
Points: 337012 Visits: 42591
Sorry... went to edit and ended up double posting, instead... please see below in my next post.

--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.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (337K reputation)SSC Guru (337K reputation)SSC Guru (337K reputation)SSC Guru (337K reputation)SSC Guru (337K reputation)SSC Guru (337K reputation)SSC Guru (337K reputation)SSC Guru (337K reputation)

Group: General Forum Members
Points: 337012 Visits: 42591
Mouli,

I believe this will solve your problem... no UDF overhead... no need for CROSS-APPLY. Just use the whole thing as another derived table. I suppose it could be a UDF or view, as well.

--===== Create and populate a test table with the data given in the post.
-- This is NOT a part of the solution
CREATE TABLE #YourTable
(
SomeString VARCHAR(20)
)
INSERT INTO #YourTable
SELECT '1230-544' UNION ALL
SELECT '15C5487' UNION ALL
SELECT '132DE78'

--===== This solves the problem.
;WITH
cteSplit AS
(--==== This not only splits out the individual characters, it only splits
-- out the digits from 0 to 9
SELECT SomeString,
ROW_NUMBER() OVER (ORDER BY yt.SomeString) AS CharacterNumber,
SUBSTRING(yt.SomeString,t.N,1) AS Character
FROM #YourTable yt
CROSS JOIN dbo.Tally t
WHERE t.N <= LEN(yt.SomeString)
AND SUBSTRING(yt.SomeString,t.N,1) LIKE '[0-9]'
)--==== This put's it all back together using a very high speed XML method
SELECT t1.SomeString,
CAST((SELECT '' + t2.Character
FROM cteSplit t2
WHERE t1.SomeString = t2.SomeString
ORDER BY t2.CharacterNumber
FOR XML PATH(''))
AS BIGINT) AS NumbersOnly
FROM cteSplit t1
GROUP BY t1.SomeString



If you don't already have a Tally table at hand, now's the time to build this incredibly useful tool. Read the article at the following link not only for how to build one, but to understand how it works, as well.

http://www.sqlservercentral.com/articles/TSQL/62867/

If, for some reason, folks won't let you build one in the database, please post back... there's more than one way to get around that.

--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.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
jchandramouli
jchandramouli
SSChasing Mays
SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)

Group: General Forum Members
Points: 622 Visits: 145
Jeff,

I have used your script both in UDF and as a query. But the problem is when the table records exceeds 10000, there is a performance issue. It takes more than two mins.

This is my table:

DECLARE @intCount INT
SET @intCount = 10000
WHILE(@intCount>=1)
BEGIN
INSERT INTO #Temp (Data) SELECT '~`!@#$%^&*()_2+-={}[]:";<>,.?/|\",.~`'
SET @intCount = @intCount - 1
END


Also, i have tried out a function that i have created that has loop

CREATE FUNCTION dbo.ufn_ExtractNumbersFromText
(
@vchInput VARCHAR(200)
)
RETURNS VARCHAR(200)
AS
BEGIN

DECLARE @vchOutput VARCHAR(200)
SET @vchInput = LTRIM(RTRIM(@vchInput))

DECLARE @i INT
DECLARE @intCount INT
DECLARE @vchTemp VARCHAR(1)
SET @i = 1
SET @vchOutput = ''

SET @intCount = LEN(@vchInput)

WHILE(@intCount >= 1)
BEGIN
SET @vchTemp = SUBSTRING(@vchInput,@i,1)
SET @vchOutput= @vchOutput + CASE WHEN @vchTemp LIKE '[0-9]'
THEN @vchTemp ELSE '' END
SET @i = @i + 1
SET @intCount = @intCount - 1
END

RETURN @vchOutput

END


And this takes nearly 6 Secs For 20000.

Anyways the script you have sent can be modified or are there any other hidden advantage compared to my function.

"I Love Walking In The Rain So No One Can See Me Crying ! " ~ Charlie Chaplin
jchandramouli
jchandramouli
SSChasing Mays
SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)SSChasing Mays (622 reputation)

Group: General Forum Members
Points: 622 Visits: 145
Oops,

Forget to add the script of how the function is used on the table to get the required data.

SELECT * FROM #Temp
UPDATE #Temp SET Output = dbo.ufn_ExtractNumbersFromText(3,Data)
SELECT * FROM #Temp


Thanks

"I Love Walking In The Rain So No One Can See Me Crying ! " ~ Charlie Chaplin
ChiragNS
ChiragNS
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10143 Visits: 1865
Jeff

I mistook this (1230-544,15C5487,132DE78) for a single value rather than 3 values that they are. I assume the op wanted to process one value.

Using a number table would be the best way of doing this.

Assuming you have a number table called number this is the query

select substring('1230-544',number,1)
from number where number <= len('1230-544')
and substring('1230-544',number,1) like '[%0-9%]'

"Keep Trying"
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (337K reputation)SSC Guru (337K reputation)SSC Guru (337K reputation)SSC Guru (337K reputation)SSC Guru (337K reputation)SSC Guru (337K reputation)SSC Guru (337K reputation)SSC Guru (337K reputation)

Group: General Forum Members
Points: 337012 Visits: 42591
Chirag (3/23/2009)
Jeff

I mistook this (1230-544,15C5487,132DE78) for a single value rather than 3 values that they are. I assume the op wanted to process one value.

Using a number table would be the best way of doing this.

Assuming you have a number table called number this is the query

select substring('1230-544',number,1)
from number where number <= len('1230-544')
and substring('1230-544',number,1) like '[%0-9%]'


Understood and thanks for the feeback, Chirag... just wanted you to know that recursion should be avoided even more than a well written cursor is.

Also, your query doesn't put it all back together like the op wanted and you don't need the % signs in the like because you're looking at a single character.

--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.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
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