Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase ««1234»»»

Trouble printing out long VARCHAR(MAX) strings? Expand / Collapse
Author
Message
Posted Wednesday, July 29, 2009 8:58 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Monday, September 15, 2014 3:43 PM
Points: 266, Visits: 2,593
I voted. Thanks for pointing this out.

I haven't run into this myself, but it seems like a basic need.

Thanks for sharing.
Post #761664
Posted Wednesday, July 29, 2009 9:23 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Friday, September 14, 2012 1:09 PM
Points: 3, Visits: 75
A solution I've found for this issue of SQL Server truncating the VARCHAR(MAX) value is to right click the table I want in the Object Explorer and "Open Table". This view doesn't truncate the values within each field.

If it's a small table, you're done, and you can copy the entire VARCHAR value out of the field from this view.

If it's a big table, you can stop the query, click the "Show SQL Pane" icon that shows up in your toolbar, and write or copy/paste your query in the window that appears. The editor is akin to Access's Query Editor, which means it sucks, but this is the fastest, most fool proof way I've found to quickly get the entire string in a table.
Post #761686
Posted Wednesday, July 29, 2009 9:44 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Thursday, May 31, 2012 9:13 AM
Points: 19, Visits: 128
In my project I was not using tables to hold the string...just variables. I tried building a variable with the very long string and then just doing a SELECT @VariableName but it only printed out 8,192 characters.

BTW, this is all on the 32-bit version of SQL Server.

SB
Post #761724
Posted Wednesday, July 29, 2009 10:08 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Friday, September 14, 2012 1:09 PM
Points: 3, Visits: 75
This is in the 32-bit version of SQL Server as well. In my experience, it's usually good practice to store the generated dynamic SQL in a log table for easy debugging later on. Not exactly related to this post, but something to consider.
Post #761748
Posted Wednesday, July 29, 2009 10:51 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: 2 days ago @ 10:49 PM
Points: 27, Visits: 193
We had the same issue.

We have a dynamically assigned security model that allows different levels of heirarchy in an organization to view data by creating where clauses which include or don't include data contained in our dashboard pivot grids / graphs. Basically with any field that we supply in our dashboard queries, we allow the end users to limit data that is then viewable by subordinates in an organization (a CFO can limit a regional manager's access to the exact same financial query by say division, the regional manager can then limit a branch manager's access by branch etc...). As the where clause is generated further down the list getting more and more specific, often times our where clause has exceeded 8000 characters. Our solution was pretty simple, we'd use a temp table with one text field, build our where clause into that field and then at the end of the where clause generator, simply perform a select on the text field of the temporary table... this is then added to the query inside c# code that generates the dataset.
Post #761793
Posted Wednesday, July 29, 2009 11:27 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Thursday, April 7, 2011 8:33 AM
Points: 1, Visits: 14
You can actually specify a length larger than the total string and substring will work fine, so the following will work too:

declare @str varchar(max), @strlen int, @startIndex int, @blockSize int
select @str = 'some long sql string',
@strlen = len(@str), @startIndex = 1, @blockSize = 4000

while(@startIndex <= @strlen)
begin
print substring(@str,@startIndex,@blockSize)
set @startIndex = @startIndex + @blockSize
end
Post #761830
Posted Wednesday, July 29, 2009 11:30 AM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Thursday, September 11, 2014 1:41 PM
Points: 2,278, Visits: 3,058
I too have faced this problem. The easiest method I have found is to set the string variable to an xml variable. You can select the variable and use for xml path clause to dynamical convert the string into "valid" xml text. You can then select the xml coumn and click the link to launch the code in a new window.

SET NOCOUNT ON;
GO

DECLARE @t TABLE(
ID INT,
Str1 VARCHAR(1500),
Str2 VARCHAR(1500),
Str3 VARCHAR(1500),
Str4 VARCHAR(1500)
)

INSERT INTO @t
VALUES
(
1,
REPLICATE('A',1500),
REPLICATE('B',1500),
REPLICATE('C',1500),
REPLICATE('D',1500)
);
DECLARE @sql VARCHAR(MAX),
@x XML,
@Id INT

SET @Id = 1

SET @sql =
(SELECT
'SELECT ' + CHAR(13)
+ '''' + Str1 +'''' + ',' + CHAR(13)
+ '''' + Str2 +'''' + ',' + CHAR(13)
+ '''' + Str3 +'''' + ',' + CHAR(13)
+ '''' + Str4 +'''' + CHAR(13)
+ 'FROM t' + CHAR(13)
+ '--WHERE something = something'
FROM @t
WHERE id = 1)

SET @x = (SELECT @sql AS [text()] FOR XML PATH(''))

SELECT dataLength(@sql) AS SQL_Length
SELECT @x





My blog: http://jahaines.blogspot.com
Post #761834
Posted Wednesday, July 29, 2009 1:01 PM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Thursday, May 31, 2012 9:13 AM
Points: 19, Visits: 128
Referring to the last post about the XML FOR PATH functionality, this is very interesting, but it has one issue: when you have the "<" or ">" characters in the string, it displays them as "<" and ">" respectively. Do you know how to get past this?

Thanks,

SB
Post #761912
Posted Wednesday, July 29, 2009 2:59 PM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Thursday, September 11, 2014 1:41 PM
Points: 2,278, Visits: 3,058

Referring to the last post about the XML FOR PATH functionality, this is very interesting, but it has one issue: when you have the "<" or ">" characters in the string, it displays them as "<" and ">" respectively. Do you know how to get past this?


There is probably a way to do this, but I dont know it. I have never had a need to devise a solution. Typically, I just do a search/replace, if I need to change the HTML tags. It should also be known that other characters may not come across correctly, such as &. I would be interested to hear if anyone has a work around for this problem.




My blog: http://jahaines.blogspot.com
Post #761978
Posted Wednesday, July 29, 2009 5:44 PM


Right there with Babe

Right there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with Babe

Group: General Forum Members
Last Login: Friday, April 4, 2014 4:40 PM
Points: 751, Visits: 917
A very nice article.

I ran into a similar problem a little over a year ago and posted my solution at the time to the site. It is at: http://www.sqlservercentral.com/scripts/Print/63240/

It is always interesting to see how different people solve similar problems. I also found some of the XML-based solutions mentioned in the comments very interesting.


---
Timothy A Wiseman
SQL Blog: http://timothyawiseman.wordpress.com/
Post #762048
« Prev Topic | Next Topic »

Add to briefcase ««1234»»»

Permissions Expand / Collapse