469,621 Members | 1,824 Online
Bytes | Developer Community
New Post

Home Posts Topics Members FAQ

Post your question to a community of 469,621 developers. It's quick & easy.

Compile/combine the contents of several records.

I have the following table;

CREATE TABLE [x_Note] (
[x_NoteId] [int] IDENTITY (1, 1) NOT NULL ,
[Note] [varchar] (7200) COLLATE SQL_Latin1_General_Pref_CP1_CI_AS NOT
NULL ,

CONSTRAINT [PK_x_NoteId] PRIMARY KEY CLUSTERED
(
[x_NoteId],
) WITH FILLFACTOR = 90 ON [USERDATA] ,

) ON [USERDATA]
GO

My clients want me to take the contents of the Note column for each row
and combine them. In other words, they basically want:

Note = Note [accumulated from previous rows] + Char(13) [because they
want a carriage return] + Note [from current record].

What is the most efficient and relatively painless way to do this? I
think it might require a cursor, but I'm not sure if there is a more
elegant set-based method to make this happen.

Dec 5 '05 #1
14 2148
Stu
There's not a set-based method; the BEST method is to use the client
application to accomplish this. Visual Basic, C#, Java, etc, are all
desigined for munging arrays in this fashion.

If you must do this on the SQL side (for email reports, etc), then you
can use a cursor. But cursor performance will suck.

Stu

Dec 5 '05 #2
Which kind of cursor would "suck" the least? Is there a way to
construct the code to be more efficient?

Dec 5 '05 #3
Stu
SQL Server is not really designed to handle cursors; in some cases,
they are unavoidable, but they just don't perform well compared to a
set-based solution. What client are you using to present this data to
your customers? Whatever it is has to be better than a SQL cursor.

Stu

Dec 5 '05 #4
Trust me, this has to be a cursor. I'm just wondering how I can make
it happen.

Dec 5 '05 #5
im*******************@yahoo.com wrote:
I have the following table;

CREATE TABLE [x_Note] (
[x_NoteId] [int] IDENTITY (1, 1) NOT NULL ,
[Note] [varchar] (7200) COLLATE SQL_Latin1_General_Pref_CP1_CI_AS NOT
NULL ,

CONSTRAINT [PK_x_NoteId] PRIMARY KEY CLUSTERED
(
[x_NoteId],
) WITH FILLFACTOR = 90 ON [USERDATA] ,

) ON [USERDATA]
GO

My clients want me to take the contents of the Note column for each row
and combine them. In other words, they basically want:

Note = Note [accumulated from previous rows] + Char(13) [because they
want a carriage return] + Note [from current record].

What is the most efficient and relatively painless way to do this? I
think it might require a cursor, but I'm not sure if there is a more
elegant set-based method to make this happen.


This looks pretty odd. If the average size of data in the Note column
is just half of your maximum size then you'll only be able to
concatenate two rows before you break the 8000 character ceiling. This
means you will most likely have to return a result set rather than a
variable (TEXT variables not allowed). But you want each value
delimited with carriage returns and most clients will display a
multiple row result set as multiple lines anyway - so what can you hope
to gain from concatenating them?

The above comments apply to SQL Server 2000. In SQL Server 2005 you can
do some fancy stuff like the following. Please always specify what
version you are using so that we don't have to guess.

WITH X (note, row_no)
AS
(
SELECT CAST(note AS VARCHAR(MAX)),
ROW_NUMBER() OVER (ORDER BY x_noteid)
FROM x_note
)
SELECT
MAX(CASE row_no WHEN 1 THEN note+CHAR(13) ELSE '' END)+
MAX(CASE row_no WHEN 2 THEN note+CHAR(13) ELSE '' END)+
MAX(CASE row_no WHEN 3 THEN note+CHAR(13) ELSE '' END)+
MAX(CASE row_no WHEN 4 THEN note+CHAR(13) ELSE '' END)+
MAX(CASE row_no WHEN 5 THEN note+CHAR(13) ELSE '' END)+
MAX(CASE row_no WHEN 6 THEN note+CHAR(13) ELSE '' END)+
MAX(CASE row_no WHEN 7 THEN note+CHAR(13) ELSE '' END)+
MAX(CASE row_no WHEN 8 THEN note+CHAR(13) ELSE '' END)+
MAX(CASE row_no WHEN 9 THEN note+CHAR(13) ELSE '' END)
/* ... etc */
AS note
FROM X ;

SELECT REPLACE( REPLACE(
(SELECT note
FROM x_note
ORDER BY
x_noteid
FOR XML PATH (''))
, '<note>', CHAR(13)),'</note>','') AS note ;

IMO clientside is the best option though.

--
David Portas
SQL Server MVP
--

Dec 5 '05 #6
im*******************@yahoo.com (im*******************@yahoo.com) writes:
I have the following table;

CREATE TABLE [x_Note] (
[x_NoteId] [int] IDENTITY (1, 1) NOT NULL ,
[Note] [varchar] (7200) COLLATE SQL_Latin1_General_Pref_CP1_CI_AS
NOT
NULL ,

CONSTRAINT [PK_x_NoteId] PRIMARY KEY CLUSTERED
(
[x_NoteId],
) WITH FILLFACTOR = 90 ON [USERDATA] ,

) ON [USERDATA]
GO

My clients want me to take the contents of the Note column for each row
and combine them. In other words, they basically want:

Note = Note [accumulated from previous rows] + Char(13) [because they
want a carriage return] + Note [from current record].

What is the most efficient and relatively painless way to do this? I
think it might require a cursor, but I'm not sure if there is a more
elegant set-based method to make this happen.


In SQL 2000, a cursor is the only defined way to do this, but you
can only compose a string which is 8000 chars long.

In SQL 2005, you can do this painlessly, thanks to some syntax from
the XML corner of SQL 2005:

select substring(List, 1, datalength(List)/2 - 1)
-- strip the last CR from the list
from
(select Note + char(13) as [text()]
from x_Note
order by x_NoteId
for xml path('')) as Dummy(List)

A bit obscure, but it works!
--
Erland Sommarskog, SQL Server MVP, es****@sommarskog.se

Books Online for
SQL Server 2005 at
http://www.microsoft.com/technet/pro...ads/books.mspx
Books Online for SQL Server 2000 at
http://www.microsoft.com/sql/prodinf...ons/books.mspx
Dec 5 '05 #7
Okay, now I have a new variation to this problem. Let's change the DDL
slightly:

CREATE TABLE [x_Note] (
[x_NoteId] [int] IDENTITY (1, 1) NOT NULL ,
[NoteCategory] [int] NOT NULL ,
[Note] [varchar] (7200) COLLATE
SQL_Latin1_General_Pref_CP1_CI_AS NOT
NULL ,
CONSTRAINT [PK_x_NoteId] PRIMARY KEY CLUSTERED
(
[x_NoteId],
) WITH FILLFACTOR = 90 ON [USERDATA] ,
) ON [USERDATA]
GO

Instead of combining the contents of the Note column for each row, we
need to combine the Notes within each NoteCategory. In other words, I
need to combine the Notes for all rows of NoteCategory #1, all the
Notes for NoteCategory #2, and so on.

In other words, FOR EACH NoteCategory, the clients want:

Note = Note [accumulated from previous rows within the NoteCategory] +
Char(13) [because they want a carriage return] + Note [from current
record within the NoteCategory].

Now, I have NO idea how to pull this off. I was considering nested
cursors, but I'm not sure if that is the best way, or even a practical
way. Help!!!

Dec 7 '05 #8
im*******************@yahoo.com wrote:
Okay, now I have a new variation to this problem. Let's change the DDL
slightly:

CREATE TABLE [x_Note] (
[x_NoteId] [int] IDENTITY (1, 1) NOT NULL ,
[NoteCategory] [int] NOT NULL ,
[Note] [varchar] (7200) COLLATE
SQL_Latin1_General_Pref_CP1_CI_AS NOT
NULL ,
CONSTRAINT [PK_x_NoteId] PRIMARY KEY CLUSTERED
(
[x_NoteId],
) WITH FILLFACTOR = 90 ON [USERDATA] ,
) ON [USERDATA]
GO

Instead of combining the contents of the Note column for each row, we
need to combine the Notes within each NoteCategory. In other words, I
need to combine the Notes for all rows of NoteCategory #1, all the
Notes for NoteCategory #2, and so on.

In other words, FOR EACH NoteCategory, the clients want:

Note = Note [accumulated from previous rows within the NoteCategory] +
Char(13) [because they want a carriage return] + Note [from current
record within the NoteCategory].

Now, I have NO idea how to pull this off. I was considering nested
cursors, but I'm not sure if that is the best way, or even a practical
way. Help!!!


You still didn't tell us what version of SQL Server you are using. Nor
have you explained why you can't do this client side.

Try:

SELECT notecategory,
MAX(CASE seq WHEN 1 THEN note+CHAR(13) ELSE '' END)+
MAX(CASE seq WHEN 2 THEN note+CHAR(13) ELSE '' END)+
MAX(CASE seq WHEN 3 THEN note+CHAR(13) ELSE '' END)+
MAX(CASE seq WHEN 4 THEN note+CHAR(13) ELSE '' END)+
MAX(CASE seq WHEN 5 THEN note+CHAR(13) ELSE '' END)+
MAX(CASE seq WHEN 6 THEN note+CHAR(13) ELSE '' END)+
MAX(CASE seq WHEN 7 THEN note+CHAR(13) ELSE '' END)+
MAX(CASE seq WHEN 8 THEN note+CHAR(13) ELSE '' END)+
MAX(CASE seq WHEN 9 THEN note+CHAR(13) ELSE '' END)
/* ... etc */
AS note
FROM
(SELECT T1.notecategory, T1.x_noteid, T1.note, COUNT(*) seq
FROM x_note AS T1
JOIN x_note AS T2
ON T1.notecategory = T2.notecategory
AND T1.x_noteid >= T2.x_noteid
GROUP BY T1.notecategory, T1.x_noteid, T1.note) AS T
GROUP BY notecategory ;

--
David Portas
SQL Server MVP
--

Dec 7 '05 #9
Sorry. I am using SQL Server 2000, and we can't do this client side
because: 1) we are doing a data migration from an older app with a SQL
Server 2000 back end and 2) our clients won't let us take a client-side
approach to this problem.

Dec 7 '05 #10
One more problem: there could be hundreds of categories, and we dont
know in advance how many categories there will be.

Dec 7 '05 #11
im*******************@yahoo.com wrote:
One more problem: there could be hundreds of categories, and we dont
know in advance how many categories there will be.


What's the problem? With the script I posted you don't need to know the
number of categories. You do need to set some upper limit on the number
of notes for each category but given that the maximum size of a VARCHAR
is 8000 and that your note column is 7K characters that may not be a
problem either - the number of notes you can support with this or any
other SQL query is possibly quite small anyway.

If you want to concatente the notes to a TEXT / NTEXT column then I
think you really will have to use a cursor.

--
David Portas
SQL Server MVP
--

Dec 7 '05 #12
im*******************@yahoo.com (im*******************@yahoo.com) writes:
Now, I have NO idea how to pull this off. I was considering nested
cursors, but I'm not sure if that is the best way, or even a practical
way. Help!!!


Before just posting "I can't do this, I can't do that", how about doing
some research. How long will these combined texts be? Since the notes
are declared as varchar(7200), one suspects that the total length may
exceed 8000 chars. But is it really so? What does:

SELECT NoteCategory, SUM(len(Note) + 1)
FROM x_Note
ORDER BY 2 DESC

return?

If there commonly are categories where the total length is > 8000, you
will have to run a cursor, and accumlate data into a new table, where
the concatenated note is written into a text column using the WRITETEXT
command. Quite painful. You don't need nested cursors though, your loop
only needs some logic to recognize that you have entered a new NoteCategory.

By the way, within each category, in which order are you supposed to
concatenate them? By x_NoteId? Are you sure that gives a correct result?

--
Erland Sommarskog, SQL Server MVP, es****@sommarskog.se

Books Online for SQL Server 2005 at
http://www.microsoft.com/technet/pro...ads/books.mspx
Books Online for SQL Server 2000 at
http://www.microsoft.com/sql/prodinf...ons/books.mspx
Dec 7 '05 #13
That code was amazing! We are running tests now, but it looks like it
works very well with just minor adjustments. Thanks very much!!!

By the way, would books would you recommend for enhancing one's
knowledged of SQL programming in general?

Dec 8 '05 #14
im*******************@yahoo.com (im*******************@yahoo.com) writes:
By the way, would books would you recommend for enhancing one's
knowledged of SQL programming in general?


There is a book by SQL Server MVPs Tom Moreau and Itzik Ben-Gan of
which the exact title slips me now, but I think it's something like
"Advanced SQL Server Programming". But just search on the author's
names on Amazon or similar and you should find it.
--
Erland Sommarskog, SQL Server MVP, es****@sommarskog.se

Books Online for SQL Server 2005 at
http://www.microsoft.com/technet/pro...ads/books.mspx
Books Online for SQL Server 2000 at
http://www.microsoft.com/sql/prodinf...ons/books.mspx
Dec 8 '05 #15

This discussion thread is closed

Replies have been disabled for this discussion.

Similar topics

4 posts views Thread by musicloverlch | last post: by
reply views Thread by devrayhaan | last post: by
By using this site, you agree to our Privacy Policy and Terms of Use.