MVSFORUMS.com Forum Index MVSFORUMS.com
A Community of and for MVS Professionals
 
 FAQFAQ   SearchSearch   Quick Manuals   RegisterRegister 
 ProfileProfile   Log in to check your private messagesLog in to check your private messages   Log inLog in 

How to concatenate text from multiple rows

 
Post new topic   Reply to topic   printer-friendly view    MVSFORUMS.com Forum Index -> Database
View previous topic :: View next topic  
Author Message
bauer
Intermediate


Joined: 10 Oct 2003
Posts: 315
Topics: 49
Location: Germany

PostPosted: Wed Jun 06, 2018 11:40 am    Post subject: How to concatenate text from multiple rows Reply with quote

Dear *,

I have a table something like this:

Code:



TextNumber    Line      Content

1                    1          ABC
1                    2          DEF
1                    3          GHI
2                    1          123
2                    2          456




The required output should look like this

Code:


TextNumber         CompleteText
1                         ABCDEFGHI
2                         123456





Current solution uses recursive SQL.

Are there any better solutions (Aggregate functions?) possible using DB2 V11 , zOS?

Kind regards,
bauer
Back to top
View user's profile Send private message
NASCAR9
Intermediate


Joined: 08 Oct 2004
Posts: 274
Topics: 52
Location: California

PostPosted: Wed Jun 06, 2018 6:01 pm    Post subject: Reply with quote

Code:

SELECT
 STRIP(TRIM(CAST(SUBSTR(XMLSERIALIZE(XMLAGG(XMLTEXT(CONTENT|| ', ') ORDER BY TEXTNUMBER, LINE) AS CLOB (1K))
    , 1, 100) AS VARCHAR (100))),BOTH, ',')   AS ALL_CONTENT
  FROM YOUR TABLE   
WHERE X=y;


This should point you in the right direction. It's good start, I think the guts are there.
_________________
Thanks,
NASCAR9
Back to top
View user's profile Send private message
kolusu
Site Admin
Site Admin


Joined: 26 Nov 2002
Posts: 12375
Topics: 75
Location: San Jose

PostPosted: Wed Jun 06, 2018 6:52 pm    Post subject: Reply with quote

bauer,

I think CONTENT is reserved variable that you cannot use a column name. I assumed it as CON_TEXT and here is a SQL ( quite similar to Nascar9's) that will give you the results

Code:

SELECT TEXTNUMBER                                                 
      ,RTRIM(REPLACE(REPLACE(CAST(XMLSERIALIZE(XMLAGG(           
             XMLELEMENT(NAME "ABC",A.CON_TEXT)) AS CLOB(4000))   
              AS VARCHAR(4000)),'<ABC>',''), '</ABC>',''))         
        AS COMPLETE_TEXT                                           
 FROM Your_table A
 GROUP BY TEXTNUMBER
 ;             


The results are
Code:

---------+---------+---------
 TEXTNUMBER  COMPLETE_TEXT   
---------+---------+---------
          1  ABCDEFGHI       
          2  123456         

_________________
Kolusu
www.linkedin.com/in/kolusu
Back to top
View user's profile Send private message Send e-mail Visit poster's website
bauer
Intermediate


Joined: 10 Oct 2003
Posts: 315
Topics: 49
Location: Germany

PostPosted: Thu Jun 07, 2018 2:17 am    Post subject: Reply with quote

Dear NASCAR9,
dear kolusu,

yes, this solution with the XMLAGG function works perfect. Much better than the recursive version.

Have a nice day,
thank you,
bauer
Back to top
View user's profile Send private message
NASCAR9
Intermediate


Joined: 08 Oct 2004
Posts: 274
Topics: 52
Location: California

PostPosted: Thu Jun 07, 2018 12:59 pm    Post subject: Reply with quote

Kolusu,
I see where I omitted TEXTNUMBER from my results. Embarassed

I used your model and added an Order BY(just to show another option) and removed REPLACE(REPLACE
I tested with know data in our system and the result were accurate. Can you explain why the "ABC" Replace logic? Always trying to learn.

Code:

  SELECT TEXTNUMBER                                                 
       ,RTRIM(CAST(XMLSERIALIZE(XMLAGG(           
              XMLTEXT(A.CON_TEXT)ORDER BY A.CON_TEXT) AS CLOB(4000))   
               AS VARCHAR(4000)))         
         AS COMPLETE_TEXT                                           
  FROM Your_table A
  GROUP BY TEXTNUMBER
    ; 
  ;

_________________
Thanks,
NASCAR9
Back to top
View user's profile Send private message
bauer
Intermediate


Joined: 10 Oct 2003
Posts: 315
Topics: 49
Location: Germany

PostPosted: Thu Jun 07, 2018 2:04 pm    Post subject: Reply with quote

Dear *,

according the replace(replace ( .....:

My understanding:

XMLELEMENT(NAME "ABC",A.CON_TEXT) creates something like this:

<ABC>.....</ABC>

This XML brackets of course must be removed after the aggregate function XMLAGG and serializing with XMLSERIALIZE.

I added an additional replace (<ABC/>,'') just in case A.CON_TEXT is empty.

The solution with XMLTEXT instead of XMLELEMENT and avoiding the replace is very interesting. Background: The SQL REPLACE works only for CHARACTER data, not for CLOB data. Just in case the concatenated text is greater than 32K the solution without REPLACE might avoid overflow problems.

I will test this solution the next days and give feedback. (I'm without mainframe access at the moment).


[11.06.2018]: Ok, test done. XMLTEXT ist better than XMLELEMENT. Some REPLACE operations can be avoided. Thanks again.



Kind regards,
Bauer


Last edited by bauer on Mon Jun 11, 2018 9:31 am; edited 1 time in total
Back to top
View user's profile Send private message
kolusu
Site Admin
Site Admin


Joined: 26 Nov 2002
Posts: 12375
Topics: 75
Location: San Jose

PostPosted: Fri Jun 08, 2018 10:55 am    Post subject: Reply with quote

Thanks Bauer,

You did a great job in explaining the query. Smile
_________________
Kolusu
www.linkedin.com/in/kolusu
Back to top
View user's profile Send private message Send e-mail Visit poster's website
Display posts from previous:   
Post new topic   Reply to topic   printer-friendly view    MVSFORUMS.com Forum Index -> Database All times are GMT - 5 Hours
Page 1 of 1

 
Jump to:  
You cannot post new topics in this forum
You cannot reply to topics in this forum
You cannot edit your posts in this forum
You cannot delete your posts in this forum
You cannot vote in polls in this forum


MVSFORUMS
Powered by phpBB © 2001, 2005 phpBB Group