Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


allow varchar value to string and decimal parts


allow varchar value to string and decimal parts

Author
Message
yaman bas
yaman bas
Grasshopper
Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)

Group: General Forum Members
Points: 20 Visits: 56
i need a query that make
'A010' + 1 = 'A011' or
'ABC13456' + 12 = 'ABC13468'

how can i do this
saurabh.k.singh
saurabh.k.singh
Grasshopper
Grasshopper (22 reputation)Grasshopper (22 reputation)Grasshopper (22 reputation)Grasshopper (22 reputation)Grasshopper (22 reputation)Grasshopper (22 reputation)Grasshopper (22 reputation)Grasshopper (22 reputation)

Group: General Forum Members
Points: 22 Visits: 23
Dear Friend

Following procdure will help you to get your result.

Create Procedure ADD_NUMBER_TO_STRING
(
@Value varchar(20),
@AddNum int
)
AS

--===============================
--Question Is Described As below

--i need a query that make
--'A010' + 1 = 'A011' or
'ABC13456' + 12 = 'ABC13468'

--==================================


--Declare variables to be used
Declare @NumPart int
Declare @Counter int
Declare @Length int
Declare @Var as varchar(1)
Declare @NumStart int

--Create Temperory Table
Create table Tbl_Temp(AlphaBet varchar(1))

--Insert Alphabets and 0 for number start with 0
Insert Into Tbl_Temp values('0')
Insert Into Tbl_Temp values('A')
Insert Into Tbl_Temp values('B')
Insert Into Tbl_Temp values('C')
Insert Into Tbl_Temp values('D')
Insert Into Tbl_Temp values('E')
Insert Into Tbl_Temp values('F')
Insert Into Tbl_Temp values('G')
Insert Into Tbl_Temp values('H')
Insert Into Tbl_Temp values('I')
Insert Into Tbl_Temp values('J')
Insert Into Tbl_Temp values('K')
Insert Into Tbl_Temp values('L')
Insert Into Tbl_Temp values('M')
Insert Into Tbl_Temp values('N')
Insert Into Tbl_Temp values('O')
Insert Into Tbl_Temp values('P')
Insert Into Tbl_Temp values('Q')
Insert Into Tbl_Temp values('R')
Insert Into Tbl_Temp values('S')
Insert Into Tbl_Temp values('T')
Insert Into Tbl_Temp values('U')
Insert Into Tbl_Temp values('V')
Insert Into Tbl_Temp values('W')
Insert Into Tbl_Temp values('X')
Insert Into Tbl_Temp values('Y')
Insert Into Tbl_Temp values('Z')

--

Set @NumStart = 0
Set @Counter = 1


--Set @AlphaPart = substring(@Value,1,2)
--Set @NumPart = Substring(@Value,2,3)


--Seth Length of string
Set @Length = len(@Value)

while (@Counter <= @Length)
Begin

Set @Var = Substring(@Value, @Counter, @Counter + 1)

if( @Var = (Select Alphabet from Tbl_Temp where Alphabet = @Var))
Begin
Set @Counter = @Counter + 1
End
Else
Begin
Set @NumStart = @Counter
Break;
End

End

Set @NumPart = Substring(@Value, @NumStart ,@Length)
Set @Value = Substring(@Value,1,@NumStart - 1)

Set @NumPart = @NumPart + @AddNum
Set @Value = @Value + cast(@NumPart as varchar(20))

--Print Required result
Select 'Final Value : '+ @Value

--Drop Temperory Table
Drop Table Tbl_Temp

--=================
--Test : Execute Following Just Select Following Line and Execute
--Exec ADD_NUMBER_TO_STRING 'A010',1
--Exec ADD_NUMBER_TO_STRING 'ABC13456',12

Cheers,
Saurabh Singh
skyline666
skyline666
Old Hand
Old Hand (358 reputation)Old Hand (358 reputation)Old Hand (358 reputation)Old Hand (358 reputation)Old Hand (358 reputation)Old Hand (358 reputation)Old Hand (358 reputation)Old Hand (358 reputation)

Group: General Forum Members
Points: 358 Visits: 229
Thats good saurabh.k.singh.

May I suggest that if you changed the declaration @NumPart from int to float, and @AddNum from int to float, then you will be able to add decimal figures as well BigGrin.

EDIT:

Actually, that only allows one decimal place at the moment.
yaman bas
yaman bas
Grasshopper
Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)Grasshopper (20 reputation)

Group: General Forum Members
Points: 20 Visits: 56
thank's for help saurabh.k.singh
you are great
Quatrei.X
Quatrei.X
SSC Veteran
SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)SSC Veteran (209 reputation)

Group: General Forum Members
Points: 209 Visits: 466
Hi there,

I have another solution. But this one also accepts symbols or any other characters EXCEPT numbers.
I'm not saying the other post was wrong. Actally I really like the post, very helpful and you can also use that sproc to do the same as mine by inputing numbers into the tables and making it do the opposite when filtering.

Oh yeah, i forgot to make this into decimal type but if you make it decimal, I think it will work fine... except for the last IF STATEMENT. But I think you can already alter it yourself.

Hope this helps


CREATE PROC AddToCodeNumber
@code VARCHAR(50),
@number INT
AS
BEGIN
DECLARE @Length INT,
@i INT

SELECT @Length = len(@code),
@i = 0

WHILE (SELECT SUBSTRING(@code,@length-@i,1)) IN ('1','2','3','4','5','6','7','8','9','0')
BEGIN
SELECT @i=@i+1
END

SELECT @number = RIGHT(@code,@i) + @number

IF LEN(@number)=LEN(RIGHT(@code,@i))
BEGIN
SELECT LEFT(@code,@Length-@i) + CAST(@number AS VARCHAR(MAX))
END
ELSE
BEGIN
SELECT 'ERROR'
END
END
RETURN
GO

EXEC AddToCodeNumber
@code ='ABC/*-+32100',
@number =212

EXEC AddToCodeNumber
@code ='ABC/*-+32100',
@number =2122346



Tell me if this was helpful ^__^ Thanks!

_____________________________________________
Quatrei Quorizawa
SmileBigGrinTongueWinkw00tCoolHehe
MABUHAY PHILIPPINES!

"Press any key...
Where the heck is the any key?
hmmm... Let's see... there's ESC, CTRL, Page Up...
but no any key"
- Homer Simpson

Jan Van der Eecken
Jan Van der Eecken
SSCrazy
SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)

Group: General Forum Members
Points: 2273 Visits: 6492
Try this version using a Tally table. No loops, no cursors.



IF OBJECT_ID ( 'tempdb..#Tally' ) IS NOT NULL
BEGIN
DROP TABLE #Tally
END
GO


DECLARE @AlphaNumber varchar ( 20 )
DEcLARE @numtoadd decimal ( 20, 4 )
DECLARE @NumPart decimal ( 20, 4 )
DECLARE @Result varchar ( 20 )
DECLARE @strlen int
DECLARE @numpos int

SET @AlphaNumber = 'ABC12345.6789'
SET @numtoadd = 0.3211


SET @strlen = DATALENGTH ( @AlphaNumber )

SELECT TOP ( @strlen )
IDENTITY ( int, 1, 1 ) AS N
INTO #Tally
FROM master.dbo.syscolumns

ALTER TABLE #Tally
ADD C char ( 1 )

UPDATE #Tally SET C = SUBSTRING ( @AlphaNumber, N, 1 )

--SELECT * FROM #Tally

SELECT @numpos = MIN ( N ) FROM #Tally WHERE C BETWEEN '0' AND '9' OR C = '.'

--PRINT @numpos

SET @NumPart = CAST ( SUBSTRING ( @AlphaNumber, @numpos, @strlen ) AS decimal ( 20, 4 ) )

--PRINT @NumPart

SET @NumPart = @NumPart + @numtoadd

SET @Result = LEFT ( @AlphaNumber, @numpos - 1 ) + LTRIM ( STR ( @NumPart, @strlen, 4 ) )

PRINT @AlphaNumber + ' + ' + LTRIM ( STR ( @numtoadd, 10, 4 ) ) + ' = ' + @Result

DROP TABLE #Tally



I know, it breaks if there is no numeric part or there is more than one decimal point Smile

Regards,
Jan

--------------------------------------------------------------------------
A little knowledge is a dangerous thing (Alexander Pope)

In order for us to help you as efficiently as possible, please read this before posting (courtesy of Jeff Moden)
SqlUser-529296
SqlUser-529296
SSC-Addicted
SSC-Addicted (480 reputation)SSC-Addicted (480 reputation)SSC-Addicted (480 reputation)SSC-Addicted (480 reputation)SSC-Addicted (480 reputation)SSC-Addicted (480 reputation)SSC-Addicted (480 reputation)SSC-Addicted (480 reputation)

Group: General Forum Members
Points: 480 Visits: 754
Hi,

try the below one.

DECLARE @Text VARCHAR(16)
SET @Text = 'ABC222'
SELECT SUBSTRING(@Text,PATINDEX('%[0-9]%',@Text),LEN(@Text)) + 100


---
Mike Mullen
Mike Mullen
SSCrazy
SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)

Group: General Forum Members
Points: 2278 Visits: 772
Here is another solution that builds on the previous suggestions. This one handles a few more variations of the text data and the number to be added.

create table #tester
(seq tinyint null,
txt varchar(20) null,
num integer null)
set nocount on
insert #tester values (1,'ABC44',10)
insert #tester values (2,'ABC44',0)
insert #tester values (3,'',10)
insert #tester values (4,'ABC4',10)
insert #tester values (5,'ABC44',1000)
insert #tester values (6,'ABC',10)
insert #tester values (7,null,10)
insert #tester values (8,'ABC',null)
insert #tester values (9,null,null)

set nocount off
select seq,
case when isnull(txt,'') = '' then isnull(convert(varchar,num),'')
when patindex('%[0-9]%',txt) = 0 then txt + isnull(convert(varchar,num),'')
else substring(txt,1,patindex('%[0-9]%',txt) - 1) +
convert(varchar,convert(int,substring(txt, patindex('%[0-9]%',txt),len(txt)) + isnull(num,0)))
end as 'result'
from #tester
order by seq

drop table #tester
/*
seq result
---- --------------------------------------------------
1 ABC54
2 ABC44
3 10
4 ABC14
5 ABC1044
6 ABC10
7 10
8 ABC
9

(9 row(s) affected)
*/
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (52K reputation)SSC Guru (52K reputation)SSC Guru (52K reputation)SSC Guru (52K reputation)SSC Guru (52K reputation)SSC Guru (52K reputation)SSC Guru (52K reputation)SSC Guru (52K reputation)

Group: General Forum Members
Points: 52532 Visits: 40334
sqluser (8/29/2008)
Hi,

try the below one.

DECLARE @Text VARCHAR(16)
SET @Text = 'ABC222'
SELECT SUBSTRING(@Text,PATINDEX('%[0-9]%',@Text),LEN(@Text)) + 100
---

Doesn't return the "ABC" part... Smile

--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.
Although they tell us that they want it real bad, our primary goal is to ensure that we dont actually give it to them that way.
Although change is inevitable, change for the better is not.
Just because you can do something in PowerShell, doesnt mean you should. Wink

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

Group: General Forum Members
Points: 52532 Visits: 40334
Mike Mullen (8/29/2008)
Here is another solution that builds on the previous suggestions. This one handles a few more variations of the text data and the number to be added.

Yes, it does. Nicely done! Smile

--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.
Although they tell us that they want it real bad, our primary goal is to ensure that we dont actually give it to them that way.
Although change is inevitable, change for the better is not.
Just because you can do something in PowerShell, doesnt mean you should. Wink

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