Concatenating a varchar(max) column

  • Hi, I'm having trouble concatenating multiple rows in a table into a single varchar(max) variable. I am trying to concat several other columns (date etc) with some character formatting and output the entire result. My problem is that the output always seems to get truncated; sometimes around 500 characters. Here is the code I am using;

    DECLARE @Summary varchar(MAX),

    @count int, /*create local @@fetch_status*/

    @iRow INT, /*row pointer (index)*/

    @KeyValue Varchar(20),

    @UserTitle VARCHAR(20),

    @Date VARCHAR(20),

    @details VARCHAR(MAX)

    SET @Summary = ''

    DECLARE @Reccom TABLE(

    RowID INT IDENTITY(1, 1),

    KeyValue VARCHAR(20),

    UserTitle VARCHAR(50),

    Date VARCHAR(20),

    Details VARCHAR(MAX))

    INSERT INTO @Reccom

    SELECT cd.KeyValue,

    rec.userTitle AS UserTitle,

    CONVERT(varchar(20), rec.RecommendationDate, 103) AS Date,

    rec.Details

    from t_table rec

    left outer join t_ControlData cd on rec.code= cd.KeyCode and cd.KeyName = 'name'

    where rec.id= 2508

    order by cd.KeyIndex ASC

    /*get array Upper Bound (highest ID number)*/

    SET @count = @@ROWCOUNT

    /*initialize index counter*/

    SET @iRow = 1

    --loop though the active components of the drug

    WHILE @iRow <= @count

    BEGIN

    SELECT @KeyValue = KeyValue,

    @UserTitle = UserTitle,

    @Date = Date,

    @Details = Details

    FROM @Reccom

    WHERE RowID = @iRow

    SELECT @Summary = @Summary + @KeyValue + ' Note - ' + @UserTitle + ', ' + @Date + CHAR(13)

    + @details + CHAR(13)

    --increment the counter

    SELECT @iRow = @iRow + 1

    END

    Any help would be appreciated

  • Are you just doing this in SSMS? If so the SSMS query window only output a certain number of characters. If you go into tools -> options and then go to query results -> Sql Server there are settings under Results to Grids and Results to Text for the size of data to display.

  • Hi,

    I'm not sure what else you are doing with this data - but I don't think you need to loop through all your rows and put everything into a table variable as you have.

    Try something like this (it should be roughly correct, but check the columns against your database). This concatenates all the values (make sure they are varchar) and then joins the next row on... etc

    DECLARE @var varchar(max)

    SELECT @var = COALESCE(@var + ', ', '') + cd.KeyValue + ' Note - ' + rec.userTitle + ', ' + CONVERT(varchar(20), rec.RecommendationDate, 103) + CHAR(13) + rec.Details + CHAR(13)

    FROM t_table rec LEFT OUTER JOIN t_ControlData cd on rec.code= cd.KeyCode and cd.KeyName = 'name'

    WHERE rec.id= 2508 ORDER BY cd.KeyIndex ASC

    SELECT @var

    B

  • Thanks guys, tried both those ideas however Jack, the limit is massive and checking len(@Summary) at the end of the code (not posted) shows my lengths to be tiny..

    B, I tried that solution.. in the DB, for testing, 5 rows match the record, all with the "Details" fields set to "abcdefghijklmnopqrstuvwxyZabcdefghijklmnopqrstuvwxyZabcdefghijklmnopqrstuvwxyZ"

    this is the output I get from your implementation...

    , user Note - Paul user, 28/03/2007

    abcdefghijklmnopqrstuvwxyZabcdefghijklmnopqrstuvwxyZabcdefghijklmnopqrstuvwxyZ

    Only one row! This is the same as what I found when I tried to concatenate using the select query itself:

    SELECT @Summary = @Summary + @KeyValue + ' Note - ' + @UserTitle + ', ' + @Date + CHAR(13) etc..

  • Can you post some sample data? Like suggested in the first link in my signature.

  • I tested with the code below and varchar(max) acts as expected when concatenating with the + operator when the number of rows are known.. However a programmatic solution still seems elusive...

    DECLARE @C VARCHAR(MAX)

    DECLARE @Code VARCHAR(20)

    DECLARE @Value VARCHAR(MAX)

    DECLARE @Temp TABLE(

    RowID INT IDENTITY(1, 1),

    Code VARCHAR(20),

    MaxValue VARCHAR(MAX))

    INSERT INTO @Temp (

    Code,

    MaxValue

    ) VALUES (

    /* Code - VARCHAR(20) */ 'A note',

    /* Value - VARCHAR(MAX) */ REPLICATE(CAST('A' AS VARCHAR(MAX)), 10000 ) )

    INSERT INTO @Temp (

    Code,

    MaxValue

    ) VALUES (

    /* Code - VARCHAR(20) */ 'B note',

    /* Value - VARCHAR(MAX) */ REPLICATE(CAST('B' AS VARCHAR(MAX)), 10000 ) )

    SET @C = ''

    SELECT @Code = Code, @Value=MaxValue FROM @Temp WHERE RowID = 1

    SELECT @C = @Code + @Value

    SELECT @Code = Code, @Value=MaxValue FROM @Temp WHERE RowID = 2

    SELECT @C = @C + @Code + @Value

    SELECT @C

    SELECT LEN(@C)

    len output: 20012

  • Sure thing jack just use multiples of this:

    INSERT INTO @Reccom (

    KeyValue,

    UserTitle,

    Date,

    Details

    ) VALUES (

    'Doctor Note',

    'Mr Bob Saggett',

    '23/10/1986',

    CAST('the brown fox jumped over the silky terrier' AS VARCHAR(MAX)) )

    The data itself isn't so important, but the details field can grow to be larger than 8000 chars, hence the use of max.

  • This worked for me:

    Declare @Reccom table (KeyValue varchar(20), USerTitle varchar(25), Date varchar(14), Details varchar(max))

    Declare @temp table(row_id int,KeyValue varchar(20), USerTitle varchar(25), Date varchar(14), Details varchar(max))

    Declare @count int

    Declare @data varchar(max)

    Set @count = 1

    WHile @Count <= 10

    Begin

    INSERT INTO @Reccom (

    KeyValue,

    UserTitle,

    Date,

    Details

    ) VALUES

    (

    'Doctor Note',

    'Mr Bob Saggett',

    '23/10/1986',

    CAST('the brown fox jumped over the silky terrier' AS VARCHAR(MAX))

    )

    Set @count = @count + 1

    End

    Set @count = 1

    Set @data = ''

    Insert into @temp

    Select

    row_number() Over(Order By Date) as row_id,

    *

    From

    @Reccom

    While @count <= (Select Max(row_id) From @temp)

    Begin

    Select

    @data = @data + keyvalue + ' Note - ' + usertitle + ', ' +

    date + char(13) + details + char(13)

    From

    @temp

    Set @count = @count + 1

    End

    Select Len(@data), @data

  • Thanks heaps Jack, that seems to work perfectly 🙂 Many thanks

  • what is the limitation of concatenation which is causing below issue?

    Any help?

    This query does not work:

    SET @tSprocSQL1 = @tMidSQL1+@tMidSQL2+@tMidSQL3+@tMidSQL4+@tMidSQL5+@tMidSQL6+@tMidSQL7+@tMidSQL8+@tMidSQL9+@tMidSQL10+@tEndSproc+ CHAR(13);

    Whereas query works:

    SET @tSprocSQL1 = @tMidSQL1+@tMidSQL2+@tMidSQL3+@tMidSQL4+@tMidSQL5+@tMidSQL6+@tMidSQL7+@tMidSQL8

    SET @tSprocSQL1 = @tSprocSQL1+@tMidSQL9+@tMidSQL10+@tEndSproc+ CHAR(13);

    ___________________________________________________________

    @tSprocSQL1 - is nvarchar(max)

    while all tMidSQL are navarchar(4000)

Viewing 10 posts - 1 through 9 (of 9 total)

You must be logged in to reply to this topic. Login to reply