June 4, 2007 at 10:58 am
I have a varchar column that contains the some of the following data:
10036
10052
100633
10068
100855
100855
101053
101090
101136
101206
101383
101416
101419
101486
101486
101579
10169
10169
i need to a add leading zeros to the data that does not have a full 6 position already in it.
eg.:
010036
010052
100633
010068
100855
100855
101053
101090
101136
And I need to update the table with these new values. Any ideas woould be great.
Thanks,
Art
June 4, 2007 at 11:23 am
Try this:
update dbo.mytable set
mycolumn = replicate('0', 6 - len(ltrim(rtrim(mycolumn)))) + mycolumn
where
len(ltrim(rtrim(mycolumn)) < 6
June 4, 2007 at 12:03 pm
When I run the following code I get this error:
Msg 170, Level 15, State 1, Line 3
Line 3: Incorrect syntax near '<'.
update
dbo.RespondentProperties set
PropertyValue
= replicate('0', 6 - len(ltrim(rtrim(PropertyValue)))) + PropertyValue
where
len(ltrim(rtrim(PropertyValue)) < 6)
I also tried running as you submitted it and recieved the same error.
Thanks
Art
June 4, 2007 at 12:28 pm
You are missing another ) before < 6
---------------------------------------------
[font="Verdana"]Nothing is impossible.
It is just a matter of time and money.[/font]
June 4, 2007 at 2:38 pm
JacekO, thanks for the catch on the missing paren.
June 4, 2007 at 5:19 pm
Just another way...
SELECT REPLACE(STR(somecol,6),' ','0')
--Jeff Moden
Change is inevitable... Change for the better is not.
June 5, 2007 at 2:38 am
Found this on our dev server:
-- Author: Igor Nikiforov, Montreal, EMail: udfs@sympatico.ca -- PADL(), PADR(), PADC() User-Defined Functions -- Returns a string from an expression, padded with spaces or characters to a specified length on the left or right sides, or both. -- PADL similar to the Oracle function PL/SQL LPAD CREATE function PADL (@cString nvarchar(4000), @nLen smallint, @cPadCharacter nvarchar(4000) = ' ' ) returns nvarchar(4000) as begin declare @length smallint, @lengthPadCharacter smallint if @cPadCharacter is NULL or datalength(@cPadCharacter) = 0 set @cPadCharacter = space(1) select @length = datalength(@cString)/(case SQL_VARIANT_PROPERTY(@cString,'BaseType') when 'nvarchar' then 2 else 1 end) -- for unicode select @lengthPadCharacter = datalength(@cPadCharacter)/(case SQL_VARIANT_PROPERTY(@cPadCharacter,'BaseType') when 'nvarchar' then 2 else 1 end) -- for unicode
if @length >= @nLen set @cString = left(@cString, @nLen) else begin declare @nLeftLen smallint set @nLeftLen = @nLen - @length -- Quantity of characters, added at the left set @cString = left(replicate(@cPadCharacter, ceiling(@nLeftLen/@lengthPadCharacter) + 2), @nLeftLen)+ @cString end
return (@cString) end
Cheers
ChrisM
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
June 5, 2007 at 8:17 am
Thanks for everybodies input. I went with Lynn original code and it worked great. Thanks you all.
June 5, 2007 at 9:16 am
Even though your done, here's on that I use.
declare @vc as varchar(6)
set @vc = '123'
select RIGHT('000000',6-LEN(@vc))+@vc
Tom
June 5, 2007 at 10:53 am
or
declare
@vc as varchar(6)
set
@vc = '123'
select
RIGHT('000000' + @vc,6)
June 5, 2007 at 11:13 pm
try this
use northwind
select substring(cast((1000+productid)as varchar(4)),2,3) from products
June 6, 2007 at 7:55 am
Nice Joe.
August 5, 2008 at 10:23 am
I just joined this site last week and I love it. π
This solution:
SELECT REPLACE(STR(somecol,6),' ','0')
by Jeff Moden
is just what I was looking for to (simply) export a column (adding leading zeros) from a DTS package to a text file.
Thanks Jeff (and all)
August 5, 2008 at 5:47 pm
You bet. Welcome aboard and thank you for the feedback. π
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 14 posts - 1 through 13 (of 13 total)
You must be logged in to reply to this topic. Login to reply