Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 SQL Server 2000 Forums
 SQL Server Development (2000)
 triming leading and trailing zeros

Author  Topic 

scelamko
Constraint Violating Yak Guru

309 Posts

Posted - 2005-03-30 : 13:55:06
guys,
how do I trim leading zeros and trailing zeros from column values.
Apparently ltrim and rtrim works only with the whitespaces.
do we have any function that acheive this.

any suggestions/input will be apprecited

Thanks

JimL
SQL Slinging Yak Ranger

1537 Posts

Posted - 2005-03-30 : 14:19:17
You can trim leading by converting into INT.

How about some sample data and senarios.

Jim
Users <> Logic
Go to Top of Page

scelamko
Constraint Violating Yak Guru

309 Posts

Posted - 2005-03-30 : 14:49:02
I have a scenario of column with datatype char(9) and which has data similar to the following
000P34566
00KP43434

So since the column datatype is char and since there is inconsistency at the number leading zero
that the column value may have, this is making the things all the more diffcult for me

any suggestions/inputs/work arounds would be helpful indeed.

thanks
Go to Top of Page

JimL
SQL Slinging Yak Ranger

1537 Posts

Posted - 2005-03-30 : 15:12:16
You can use case and substring

select
mycolumn = case when Substring(mycolumn,1,4) = '0000'
Then Substring(mycolumn,5,5)
when Substring(mycolumn,1,3) = '000'
Then Substring(mycolumn,4,6)
when Substring(mycolumn,1,2) = '00'
Then Substring(mycolumn,3,7)
when Substring(mycolumn,1,1) = '0'
Then Substring(mycolumn,2,8)
else mycolumn
end
From mytable

Jim
Users <> Logic
Go to Top of Page

SwePeso
Patron Saint of Lost Yaks

30421 Posts

Posted - 2006-06-17 : 08:32:34
[code]-- prepare test data
declare @num table (i varchar(50))

insert @num
select '000P123450000' union all
select '000C342344004564123490000' union all
select '0000000000KP32100'

-- do the work
SELECT i,
patindex('%[^0]%', i),
patindex('%[^0]%', reverse(i)),
substring(i, patindex('%[^0]%', i), 2 + len(i) - patindex('%[^0]%', i) - patindex('%[^0]%', reverse(i)))
FROM @num[/code]
Peter Larsson
Helsingborg, Sweden
Go to Top of Page

Michael Valentine Jones
Yak DBA Kernel (pronounced Colonel)

7020 Posts

Posted - 2006-06-17 : 14:00:29
Trim leading and trailing zeros from strings:

elect
x,
[Trimmed X] =
left(replace(replace(rtrim(ltrim(replace(replace(
x,' ','#'),'0',' '))),' ','0'),'#',' '),15)
from
(
select x='000P34566' union all
select x='600P34500' union all
select x='000P34000' union all
select x='00KP 3434'
) a

Results:


x Trimmed X
--------- ---------------
000P34566 P34566
600P34500 600P345
000P34000 P34
00KP 3434 KP 3434

(4 row(s) affected)



CODO ERGO SUM
Go to Top of Page

madhivanan
Premature Yak Congratulator

22864 Posts

Posted - 2006-06-19 : 04:48:26
quote:
Originally posted by scelamko

I have a scenario of column with datatype char(9) and which has data similar to the following
000P34566
00KP43434

So since the column datatype is char and since there is inconsistency at the number leading zero
that the column value may have, this is making the things all the more diffcult for me

any suggestions/inputs/work arounds would be helpful indeed.

thanks



MVJ has missed S in Select
Other method. Refer this
http://www.sqlteam.com/forums/topic.asp?TOPIC_ID=56713


Madhivanan

Failing to plan is Planning to fail
Go to Top of Page
   

- Advertisement -