January 31, 2009 at 8:37 pm
Comments posted to this topic are about the item Data Length
February 1, 2009 at 4:27 pm
REPLICATE( N'A', 4000000));
what is the meaning of N in N'A'? is it the maximum length.
I executed the below statements,
INSERT #t VALUES (1, REPLICATE( N'A', 4000000));
INSERT #t VALUES (2, REPLICATE( 'A', 4000000));
SELECT DATALENGTH(LongName) FROM #t
The result of the SELECT is
8000
16000
I don't know why i got 16000. Can anyone explain me?
February 2, 2009 at 12:31 am
The N'A' means that 'A' is an Unicode string constant.
Unicode is using 2 bytes to encode each character.
The DATALENGTH function returns the number of bytes used to represent the expression.
So in this case, you have to multiply the number in the REPLICATE function by 2.
HTH,
Robbert
February 2, 2009 at 1:33 am
karthik.nallajalla (2/1/2009)
REPLICATE( N'A', 4000000));what is the meaning of N in N'A'? is it the maximum length.
I executed the below statements,
INSERT #t VALUES (1, REPLICATE( N'A', 4000000));
INSERT #t VALUES (2, REPLICATE( 'A', 4000000));
SELECT DATALENGTH(LongName) FROM #t
The result of the SELECT is
8000
16000
I don't know why i got 16000. Can anyone explain me?
Hi Karthik,
Yes, I can.
The result of REPLICATE depends on the first argument. If it's varchar(MAX) or nvarchar(MAX), the result will also be [n]varchar(MAX) and the string won't be truncated. However, a string constant will never be considered ..(MAX) - well, maybe if the string constant is more than 4000 (nvarchar) or 8000 (varchar) characters long, I never tried that. 🙂
For REPLICATE(N'A', 4000000), the input string is nvarchar(something other than max), so the result can not be longer than the longest nvarchar, which is nvarchar(4000). That's 8000 bytes, since two bytes are used for each Unicode character. The implicit cast to nvarchar(MAX) when storing the result in the table does not affect the data length.
For REPLICATE('A', 4000000), the input string is varchar(something other than max) -- note no N in front of varchar!!--. The result will be the longest varchar, which is varchar(8000). That's 8000 bytes as well, of course. But the implicit cast to nvarchar(MAX) will translate each of the 1-byte non-unicode characters to its two-byte unicode equivalent, bumping the data length to 16,000 bytes. And since nvarchar(MAX) has no problem storing an 8,000 byte unicode string, it will.
February 2, 2009 at 7:41 am
REPLICATE function is obviously broken then.
it only gives 8,000 repititions and thus must be geared to old SQL 2000 varchar max size of 8000.
Naughty MS have not updated the function to deal with the new data types.
--Shaun
Hiding under a desk from SSIS Implemenation Work :crazy:
February 2, 2009 at 8:16 am
Don't forget that the DATALENGTH function is different from the LEN function.
DATALENGTH returns the number of bytes
versus
LEN which returns the number of characters.
That is one of the tricky parts of this particular question.;)
February 2, 2009 at 8:50 am
Shaun McGuile (2/2/2009)
REPLICATE function is obviously broken then.
Hi Shaun,
No, it's not. It just adheres to the standard operating procedure of datatype in = datatype out.
CREATE TABLE #t
(ID int,
LongName nvarchar(MAX));
INSERT #t
VALUES (1, REPLICATE(CAST(N'A' AS nvarchar(MAX)), 4000000));
SELECT DATALENGTH(LongName) FROM #t WHERE ID = 1;
Returns 8000000.
February 2, 2009 at 9:29 am
Hugo: so what you are saying is that REPLICATE uses varchar sizing i.e. 8000 and not the destination size unless you explicitly instruction the function to use something else as shown in your code. 😉
Dumb function ! 😛
--Shaun
Hiding under a desk from SSIS Implemenation Work :crazy:
February 2, 2009 at 10:58 am
Thanks Robbert and Hugo for helping me out.
February 2, 2009 at 11:25 am
Shaun McGuile (2/2/2009)
Hugo: so what you are saying is that REPLICATE uses varchar sizing i.e. 8000 and not the destination size unless you explicitly instruction the function to use something else as shown in your code. 😉Dumb function ! 😛
Hi Shaun,
I'd use different words, but basically you're right.
And by the way, this is not limited to REPLICATE but applies to all expressions in SQL Server. The division below discards the fraction because the dividend of two integers is defined to be an integer, regardless of whether the result will later be assigned to a float variable.
DECLARE @i1 int, @i2 int, @f1 float;
SET @i1 = 10;
SET @i2 = 3;
SET @f1 = @i1 / @i2;
SELECT @f1;
And as far as I can remember, all other programming languages I have been involved with behave similarly.
February 10, 2009 at 7:11 am
Excellent discussion guys, really like the way it evolved. I got it wrong, because I didn't read the question properly - had same problem at school 😉 - and put 4000 doh!
Good work, thanks, covered a lot more than just the answer 🙂
Viewing 11 posts - 1 through 10 (of 10 total)
You must be logged in to reply to this topic. Login to reply